Query against sys.schemas and sys.synonyms runs very slow for one user
You may want to re-write your query as follows (I'm using dbo
rather than XXXX
so that I do find some synonyms on my testing database). This is similar to the re-write you found to be more efficient, but avoids the need to declare a variable and use two queries.
SELECT name, base_object_name
FROM sys.synonyms
WHERE schema_id = SCHEMA_ID(N'dbo')
ORDER BY name
This yields a plan like the following:
One very interesting thing about the Filter
operator in this plan is that it has a predicate that performs an internal has_access()
check. This filter removes any objects that the current account does not have sufficient permissions to see. However, this check is short-circuited (i.e., completes much more quickly) if you are a member of the db_owner
role, which may explain the performance differences you are seeing.
Here is the query plan for your original query. Notice that all synonyms on the database (1,126
in my case, but likely many more in your case) pass through the very expensive has_access()
filter, even though only 2
synonyms match the schema. By using the simplified query above, we can ensure that has_access()
is only invoked for the synonyms that match your query rather than for all synonyms in the database.
Using sys.dm_exec_query_profiles to explore further
As Martin suggests, we can confirm that the has_access() check is a significant bottleneck by using sys.dm_exec_query_profiles
on SQL Server 2014+. If I run the following query using a db_owner
account on a database with ~700K objects, the query takes ~500ms
:
SELECT COUNT(*)
FROM sys.objects
When run with an account that is not a db_owner
, this same query takes about eight minutes! Running with actual plan on and using a p_queryProgress procedure that I wrote to help parse sys.dm_exec_query_profiles
output more easily, we can see that almost all of the processing time is spent on the Filter
operator that is performing the has_access()
check: