sys.dm_exec_cached_plans (Transact-SQL)
TOC
Collapse the table of content
Expand the table of content

sys.dm_exec_cached_plans (Transact-SQL)

 

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008)yesAzure SQL DatabaseyesAzure SQL Data Warehouse yesParallel Data Warehouse

Returns a row for each query plan that is cached by SQL Server for faster query execution. You can use this dynamic management view to find cached query plans, cached query text, the amount of memory taken by cached plans, and the reuse count of the cached plans.

In Azure SQL Database, dynamic management views cannot expose information that would impact database containment or expose information about other databases the user has access to. To avoid exposing this information, every row that contains data that doesn’t belong to the connected tenant is filtered out. In addition, the values in the columns memory_object_address and pool_id are filtered; the column value is set to NULL.

System_CAPS_ICON_note.jpg Note


To call this from Azure SQL Data Warehouse or Parallel Data Warehouse, use the name sys.dm_pdw_nodes_exec_cached_plans.

Column nameData typeDescription
bucketidintID of the hash bucket in which the entry is cached. The value indicates a range from 0 through the hash table size for the type of cache.

For the SQL Plans and Object Plans caches, the hash table size can be up to 10007 on 32-bit systems and up to 40009 on 64-bit systems. For the Bound Trees cache, the hash table size can be up to 1009 on 32-bit systems and up to 4001 on 64-bit systems. For the Extended Stored Procedures cache the hash table size can be up to 127 on 32-bit and 64-bit systems.
refcountsintNumber of cache objects that are referencing this cache object. Refcounts must be at least 1 for an entry to be in the cache.
usecountsintNumber of times the cache object has been looked up. Not incremented when parameterized queries find a plan in the cache. Can be incremented multiple times when using showplan.
size_in_bytesintNumber of bytes consumed by the cache object.
memory_object_addressvarbinary(8)Memory address of the cached entry. This value can be used with sys.dm_os_memory_objects to get the memory breakdown of the cached plan and with sys.dm_os_memory_cache_entries_entries to obtain the cost of caching the entry.
cacheobjtypenvarchar(34)Type of object in the cache. The value can be one of the following:

Compiled Plan

Compiled Plan Stub

Parse Tree

Extended Proc

CLR Compiled Func

CLR Compiled Proc
objtypenvarchar(16)Type of object. Below are the possible values and their corresponding descriptions.

Proc: Stored procedure
Prepared: Prepared statement
Adhoc: Ad hoc query. Refers to Transact-SQL submitted as language events by using osql or sqlcmd instead of as remote procedure calls.
ReplProc: Replication-filter-procedure
Trigger: Trigger
View: View
Default: Default
UsrTab: User table
SysTab: System table
Check: CHECK constraint
Rule: Rule
plan_handlevarbinary(64)Identifier for the in-memory plan. This identifier is transient and remains constant only while the plan remains in the cache. This value may be used with the following dynamic management functions:

 sys.dm_exec_sql_text

 sys.dm_exec_query_plan

 sys.dm_exec_plan_attributes
pool_idintThe ID of the resource pool against which this plan memory usage is accounted for.
pdw_node_idintApplies to: Azure SQL Data Warehouse, Parallel Data Warehouse

The identifier for the node that this distribution is on.

1

On SQL Server requires VIEW SERVER STATE permission on the server.

On SQL Database Premium Tiers requires the VIEW DATABASE STATE permission in the database. On SQL Database Standard and Basic Tiers requires the SQL Database admin account.

A. Returning the batch text of cached entries that are reused

The following example returns the SQL text of all cached entries that have been used more than once.

SELECT usecounts, cacheobjtype, objtype, text   
FROM sys.dm_exec_cached_plans   
CROSS APPLY sys.dm_exec_sql_text(plan_handle)   
WHERE usecounts > 1   
ORDER BY usecounts DESC;  
GO  

B. Returning query plans for all cached triggers

The following example returns the query plans of all cached triggers.

SELECT plan_handle, query_plan, objtype   
FROM sys.dm_exec_cached_plans   
CROSS APPLY sys.dm_exec_query_plan(plan_handle)   
WHERE objtype ='Trigger';  
GO  

C. Returning the SET options with which the plan was compiled

The following example returns the SET options with which the plan was compiled. The sql_handle for the plan is also returned. The PIVOT operator is used to output the set_options and sql_handle attributes as columns rather than as rows. For more information about the value returned in set_options, see sys.dm_exec_plan_attributes (Transact-SQL).

SELECT plan_handle, pvt.set_options, pvt.sql_handle  
FROM (  
      SELECT plan_handle, epa.attribute, epa.value   
      FROM sys.dm_exec_cached_plans   
      OUTER APPLY sys.dm_exec_plan_attributes(plan_handle) AS epa  
      WHERE cacheobjtype = 'Compiled Plan'  
      ) AS ecpa   
PIVOT (MAX(ecpa.value) FOR ecpa.attribute IN ("set_options", "sql_handle")) AS pvt;  
GO  

D. Returning the memory breakdown of all cached compiled plans

The following example returns a breakdown of the memory used by all compiled plans in the cache.

SELECT plan_handle, ecp.memory_object_address AS CompiledPlan_MemoryObject,   
    omo.memory_object_address, pages_allocated_count, type, page_size_in_bytes   
FROM sys.dm_exec_cached_plans AS ecp   
JOIN sys.dm_os_memory_objects AS omo   
    ON ecp.memory_object_address = omo.memory_object_address   
    OR ecp.memory_object_address = omo.parent_address  
WHERE cacheobjtype = 'Compiled Plan';  
GO  

Dynamic Management Views and Functions (Transact-SQL)
Execution Related Dynamic Management Views and Functions (Transact-SQL)
sys.dm_exec_query_plan (Transact-SQL)
sys.dm_exec_plan_attributes (Transact-SQL)
sys.dm_exec_sql_text (Transact-SQL)
sys.dm_os_memory_objects (Transact-SQL)
sys.dm_os_memory_cache_entries (Transact-SQL)
FROM (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft