Today, I would like to share a script to identify the usage of index from cached plan in SQL Server. This would help us to identify the places (procs/functions etc) where the index is being used. One interesting use-case is to identify the index usage that has been introduced recently during the performance optimization.
;WITH XMLNAMESPACES(DEFAULT N'http://schemas.microsoft.com/sqlserver/2004/07/showplan'),
CachedPlansCTE
(
DatabaseName,SchemaName,TableName,IndexName,
QueryText,QueryPlan,CacheObjectType,ObjectType
)
AS
(
SELECT
RelOp1.op.value(N'@Database', N'varchar(128)') AS DatabaseName,
RelOp1.op.value(N'@Schema', N'varchar(128)') AS SchemaName,
RelOp1.op.value(N'@Table', N'varchar(128)') AS TableName,
RelOp1.op.value(N'@Index', N'varchar(128)') AS IndexName,
cp.TEXT AS QueryText,cp.query_plan AS QueryPlan,
cp.cacheobjtype AS CacheObjectType,cp.objtype AS ObjectType
FROM (SELECT usecounts,cacheobjtype,objtype,query.text
,executionplan.query_plan
FROM sys.dm_exec_cached_plans
OUTER APPLY sys.dm_exec_sql_text(plan_handle) as query
OUTER APPLY sys.dm_exec_query_plan(plan_handle) as executionplan
WHERE [text] NOT LIKE '%sys%'
AND cacheobjtype ='compiled plan' ) cp
CROSS APPLY cp.query_plan.nodes(N'//Object') RelOp1 (op)
)
SELECT QueryPlan,QueryText,CacheObjectType, ObjectType,
DatabaseName, SchemaName,TableName, IndexName
FROM CachedPlansCTE
WHERE CacheObjectType = N'Compiled Plan'
/*
*********************************************************
SEARCH SCENARIOS
****************
/* if you need to search for a particular index*/
and (IndexName like '%Indexname%')
/* if you need to search ONLY for SELECT queries*/
and (QueryText not like '%insert%')
and (QueryText not like '%update%')
*********************************************************
*/
OPTION (MAXDOP 1)
See Also:
How to identify Missing Index from Cached Plan in SQL Server
How do you find cached plan for a procedure in SQL Server