1
- https:// www .sqlskills .com/ blogs/ kimberly/ plan- cache- adhoc- workloads- and - clearing- the- single- use- plan- cache- bloat/
1
+ -- https://www.sqlskills.com/blogs/kimberly/plan-cache-adhoc-workloads-and-clearing-the-single-use-plan-cache-bloat/
2
+ -- https://www.sqlskills.com/blogs/kimberly/plan-cache-and-optimizing-for-adhoc-workloads/
3
+ -- https://www.sqlshack.com/searching-the-sql-server-query-plan-cache/
4
+ -- https://sqlperformance.com/2014/10/t-sql-queries/performance-tuning-whole-plan
2
5
3
- https:// www .sqlskills .com/ blogs/ kimberly/ plan- cache- and - optimizing- for- adhoc- workloads/
4
6
7
+ /* Query plans with Warnings */
8
+ ;WITH XMLNAMESPACES
9
+ (DEFAULT ' http://schemas.microsoft.com/sqlserver/2004/07/showplan' )
10
+ SELECT TOP 20
11
+ dm_exec_sql_text .text AS sql_text,
12
+ CAST(CAST(dm_exec_query_stats .execution_count AS DECIMAL ) / CAST((CASE WHEN DATEDIFF(HOUR, dm_exec_query_stats .creation_time , CURRENT_TIMESTAMP ) = 0 THEN 1 ELSE DATEDIFF(HOUR, dm_exec_query_stats .creation_time , CURRENT_TIMESTAMP ) END) AS DECIMAL ) AS INT ) AS executions_per_hour,
13
+ dm_exec_query_stats .creation_time ,
14
+ dm_exec_query_stats .execution_count ,
15
+ CAST(CAST(dm_exec_query_stats .total_worker_time AS DECIMAL )/ CAST(dm_exec_query_stats .execution_count AS DECIMAL ) AS INT ) as cpu_per_execution,
16
+ CAST(CAST(dm_exec_query_stats .total_logical_reads AS DECIMAL )/ CAST(dm_exec_query_stats .execution_count AS DECIMAL ) AS INT ) as logical_reads_per_execution,
17
+ CAST(CAST(dm_exec_query_stats .total_elapsed_time AS DECIMAL )/ CAST(dm_exec_query_stats .execution_count AS DECIMAL ) AS INT ) as elapsed_time_per_execution,
18
+ dm_exec_query_stats .total_worker_time AS total_cpu_time,
19
+ dm_exec_query_stats .max_worker_time AS max_cpu_time,
20
+ dm_exec_query_stats .total_elapsed_time ,
21
+ dm_exec_query_stats .max_elapsed_time ,
22
+ dm_exec_query_stats .total_logical_reads ,
23
+ dm_exec_query_stats .max_logical_reads ,
24
+ dm_exec_query_stats .total_physical_reads ,
25
+ dm_exec_query_stats .max_physical_reads ,
26
+ dm_exec_query_plan .query_plan
27
+ FROM sys .dm_exec_query_stats
28
+ CROSS APPLY sys .dm_exec_sql_text (dm_exec_query_stats .sql_handle )
29
+ CROSS APPLY sys .dm_exec_query_plan (dm_exec_query_stats .plan_handle )
30
+ WHERE query_plan .exist (' //Warnings' ) = 1
31
+ AND query_plan .exist (' //ColumnReference[@Database = "[AMGMusic]"]' ) = 1
32
+ ORDER BY dm_exec_query_stats .total_worker_time DESC ;
33
+
34
+ /* Plans with Table/Clustered Index Scan */
35
+ ;WITH XMLNAMESPACES
36
+ (DEFAULT ' http://schemas.microsoft.com/sqlserver/2004/07/showplan' )
37
+ SELECT
38
+ dm_exec_sql_text .text AS sql_text,
39
+ CAST(CAST(dm_exec_query_stats .execution_count AS DECIMAL ) / CAST((CASE WHEN DATEDIFF(HOUR, dm_exec_query_stats .creation_time , CURRENT_TIMESTAMP ) = 0 THEN 1 ELSE DATEDIFF(HOUR, dm_exec_query_stats .creation_time , CURRENT_TIMESTAMP ) END) AS DECIMAL ) AS INT ) AS executions_per_hour,
40
+ dm_exec_query_stats .creation_time ,
41
+ dm_exec_query_stats .execution_count ,
42
+ CAST(CAST(dm_exec_query_stats .total_worker_time AS DECIMAL )/ CAST(dm_exec_query_stats .execution_count AS DECIMAL ) AS INT ) as cpu_per_execution,
43
+ CAST(CAST(dm_exec_query_stats .total_logical_reads AS DECIMAL )/ CAST(dm_exec_query_stats .execution_count AS DECIMAL ) AS INT ) as logical_reads_per_execution,
44
+ CAST(CAST(dm_exec_query_stats .total_elapsed_time AS DECIMAL )/ CAST(dm_exec_query_stats .execution_count AS DECIMAL ) AS INT ) as elapsed_time_per_execution,
45
+ dm_exec_query_stats .total_worker_time AS total_cpu_time,
46
+ dm_exec_query_stats .max_worker_time AS max_cpu_time,
47
+ dm_exec_query_stats .total_elapsed_time ,
48
+ dm_exec_query_stats .max_elapsed_time ,
49
+ dm_exec_query_stats .total_logical_reads ,
50
+ dm_exec_query_stats .max_logical_reads ,
51
+ dm_exec_query_stats .total_physical_reads ,
52
+ dm_exec_query_stats .max_physical_reads ,
53
+ dm_exec_query_plan .query_plan
54
+ FROM sys .dm_exec_query_stats
55
+ CROSS APPLY sys .dm_exec_sql_text (dm_exec_query_stats .sql_handle )
56
+ CROSS APPLY sys .dm_exec_query_plan (dm_exec_query_stats .plan_handle )
57
+ WHERE (query_plan .exist (' //RelOp[@PhysicalOp = "Index Scan"]' ) = 1
58
+ OR query_plan .exist (' //RelOp[@PhysicalOp = "Clustered Index Scan"]' ) = 1 )
59
+ AND query_plan .exist (' //ColumnReference[@Database = "[AdventureWorks2014]"]' ) = 1
60
+ ORDER BY dm_exec_query_stats .total_worker_time DESC ;
61
+
0 commit comments