@@ -48,6 +48,7 @@ CREATE TABLE ##bou_BlitzCacheProcs (
4848 PercentWritesByType MONEY ,
4949 WritesPerMinute MONEY ,
5050 PlanCreationTime DATETIME ,
51+ PlanCreationTimeHours AS DATEDIFF (HOUR, PlanCreationTime, SYSDATETIME ()),
5152 LastExecutionTime DATETIME ,
5253 PlanHandle VARBINARY (64 ),
5354 [Remove Plan Handle From Cache] AS
@@ -108,6 +109,8 @@ CREATE TABLE ##bou_BlitzCacheProcs (
108109 is_forced_plan BIT ,
109110 is_forced_parameterized BIT ,
110111 is_cursor BIT ,
112+ is_optimistic_cursor BIT ,
113+ is_forward_only_cursor BIT ,
111114 is_parallel BIT ,
112115 is_forced_serial BIT ,
113116 is_key_lookup_expensive BIT ,
@@ -139,6 +142,9 @@ CREATE TABLE ##bou_BlitzCacheProcs (
139142 is_trivial BIT ,
140143 trace_flags_session VARCHAR (1000 ),
141144 is_unused_grant BIT ,
145+ function_count INT ,
146+ clr_function_count INT ,
147+ is_table_variable BIT ,
142148 SetOptions VARCHAR (MAX ),
143149 Warnings VARCHAR (MAX )
144150 );
@@ -166,6 +172,7 @@ ALTER PROCEDURE dbo.sp_BlitzCache
166172 @OnlySqlHandles VARCHAR (MAX ) = NULL ,
167173 @QueryFilter VARCHAR (10 ) = ' ALL' ,
168174 @DatabaseName NVARCHAR (128 ) = NULL ,
175+ @StoredProcName NVARCHAR (128 ) = NULL ,
169176 @Reanalyze BIT = 0 ,
170177 @SkipAnalysis BIT = 0 ,
171178 @BringThePain BIT = 0 /* This will forcibly set @Top to 2,147,483,647 */
@@ -197,7 +204,7 @@ Unknown limitations of this version:
197204 - May or may not be vulnerable to the wick effect.
198205
199206Changes - for the full list of improvements and fixes in this version, see:
200- https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/milestone/4?closed=1
207+ https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/
201208
202209
203210
@@ -631,6 +638,7 @@ BEGIN
631638 PercentWritesByType MONEY ,
632639 WritesPerMinute MONEY ,
633640 PlanCreationTime DATETIME ,
641+ PlanCreationTimeHours AS DATEDIFF (HOUR, PlanCreationTime, SYSDATETIME ()),
634642 LastExecutionTime DATETIME ,
635643 PlanHandle VARBINARY (64 ),
636644 [Remove Plan Handle From Cache] AS
@@ -688,6 +696,8 @@ BEGIN
688696 is_forced_plan BIT ,
689697 is_forced_parameterized BIT ,
690698 is_cursor BIT ,
699+ is_optimistic_cursor BIT ,
700+ is_forward_only_cursor BIT ,
691701 is_parallel BIT ,
692702 is_forced_serial BIT ,
693703 is_key_lookup_expensive BIT ,
@@ -719,6 +729,9 @@ BEGIN
719729 is_trivial BIT ,
720730 trace_flags_session VARCHAR (1000 ),
721731 is_unused_grant BIT ,
732+ function_count INT ,
733+ clr_function_count INT ,
734+ is_table_variable BIT ,
722735 SetOptions VARCHAR (MAX ),
723736 Warnings VARCHAR (MAX )
724737 );
@@ -834,6 +847,17 @@ CREATE TABLE #configuration (
834847 value DECIMAL (38 ,0 )
835848);
836849
850+ WITH x AS (
851+ SELECT SUM (CASE WHEN DATEDIFF (HOUR, deqs .creation_time , SYSDATETIME ()) < 24 THEN 1 ELSE 0 END ) AS [plans_24],
852+ SUM (CASE WHEN DATEDIFF (HOUR, deqs .creation_time , SYSDATETIME ()) < 4 THEN 1 ELSE 0 END ) AS [plans_4],
853+ COUNT (deqs .creation_time ) AS [total_plans]
854+ FROM sys .dm_exec_query_stats AS deqs
855+ )
856+ SELECT CONVERT (DECIMAL (3 ,2 ), x .plans_24 / (1 . * NULLIF (x .total_plans , 0 ))) * 100 AS [percent_24],
857+ CONVERT (DECIMAL (3 ,2 ), x .plans_4 / (1 . * NULLIF (x .total_plans , 0 ))) * 100 AS [percent_4],
858+ @@SPID AS SPID
859+ INTO #plan_creation
860+ FROM x
837861
838862
839863SET @OnlySqlHandles = LTRIM (RTRIM (@OnlySqlHandles)) ;
@@ -875,6 +899,20 @@ BEGIN
875899 END
876900END
877901
902+ IF @StoredProcName IS NOT NULL AND @StoredProcName <> N ' '
903+
904+ BEGIN
905+
906+ INSERT #only_sql_handles
907+ ( sql_handle )
908+ SELECT ISNULL (deps .sql_handle , ' ' )
909+ FROM sys .dm_exec_procedure_stats AS deps
910+ WHERE OBJECT_NAME (deps .object_id , deps .database_id ) = @StoredProcName
911+
912+ END
913+
914+
915+
878916IF ((@OnlyQueryHashes IS NOT NULL AND LEN (@OnlyQueryHashes) > 0 )
879917 OR (@IgnoreQueryHashes IS NOT NULL AND LEN (@IgnoreQueryHashes) > 0 ))
880918 AND LEFT (@QueryFilter, 3 ) = ' pro'
@@ -1287,7 +1325,7 @@ BEGIN
12871325 t.t_TotalExecs,
12881326 t.t_TotalWrites,
12891327 qs.sql_handle AS SqlHandle,
1290- NULL AS PlanHandle,
1328+ qs.plan_handle AS PlanHandle,
12911329 qs.query_hash AS QueryHash,
12921330 qs.query_plan_hash AS QueryPlanHash,
12931331 qs.min_worker_time / 1000.0,
@@ -1626,6 +1664,16 @@ FROM ##bou_BlitzCacheProcs p
16261664 CROSS APPLY p .QueryPlan .nodes (' //p:StmtSimple' ) AS q(n)
16271665OPTION (RECOMPILE ) ;
16281666
1667+ WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p)
1668+ INSERT #statements
1669+ SELECT QueryHash ,
1670+ SqlHandle ,
1671+ PlanHandle,
1672+ q .n .query(' .' ) AS statement
1673+ FROM ##bou_BlitzCacheProcs p
1674+ CROSS APPLY p .QueryPlan .nodes (' //p:StmtCursor' ) AS q(n)
1675+ OPTION (RECOMPILE ) ;
1676+
16291677WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p)
16301678SELECT QueryHash ,
16311679 SqlHandle ,
@@ -1735,18 +1783,35 @@ WITH XMLNAMESPACES('http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS
17351783UPDATE p
17361784SET busy_loops = CASE WHEN (x .estimated_executions / 100 .0 ) > x .estimated_rows THEN 1 END ,
17371785 tvf_join = CASE WHEN x .tvf_join = 1 THEN 1 END ,
1738- warning_no_join_predicate = CASE WHEN x .no_join_warning = 1 THEN 1 END
1786+ warning_no_join_predicate = CASE WHEN x .no_join_warning = 1 THEN 1 END ,
1787+ p .is_table_variable = CASE WHEN x .is_table_variable = 1 THEN 1 END
17391788FROM ##bou_BlitzCacheProcs p
17401789 JOIN (
17411790 SELECT qs .SqlHandle ,
17421791 relop .value (' sum(/p:RelOp/@EstimateRows)' , ' float' ) AS estimated_rows ,
17431792 relop .value (' sum(/p:RelOp/@EstimateRewinds)' , ' float' ) + relop .value (' sum(/p:RelOp/@EstimateRebinds)' , ' float' ) + 1 .0 AS estimated_executions ,
17441793 relop .exist (' /p:RelOp[contains(@LogicalOp, "Join")]/*/p:RelOp[(@LogicalOp[.="Table-valued function"])]' ) AS tvf_join,
1745- relop .exist (' /p:RelOp/p:Warnings[(@NoJoinPredicate[.="1"])]' ) AS no_join_warning
1794+ relop .exist (' /p:RelOp/p:Warnings[(@NoJoinPredicate[.="1"])]' ) AS no_join_warning,
1795+ relop .exist (' /p:RelOp//*[local-name() = "Object"]/@Table[contains(., "@")]' ) AS is_table_variable
17461796 FROM #relop qs
17471797 ) AS x ON p .SqlHandle = x .SqlHandle
17481798OPTION (RECOMPILE );
17491799
1800+ WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p)
1801+ , x AS (
1802+ SELECT qs .QueryHash ,
1803+ n .fn .value (' count(distinct-values(//p:UserDefinedFunction[not(@IsClrFunction)]))' , ' INT' ) AS function_count,
1804+ n .fn .value (' count(distinct-values(//p:UserDefinedFunction[@IsClrFunction = "1"]))' , ' INT' ) AS clr_function_count
1805+ FROM #relop qs
1806+ CROSS APPLY relop .nodes (' /p:RelOp/p:ComputeScalar/p:DefinedValues/p:DefinedValue/p:ScalarOperator' ) n(fn)
1807+ )
1808+ UPDATE p
1809+ SET p .function_count = x .function_count ,
1810+ p .clr_function_count = x .clr_function_count
1811+ FROM ##bou_BlitzCacheProcs AS p
1812+ JOIN x ON x .QueryHash = p .QueryHash
1813+ OPTION (RECOMPILE );
1814+
17501815
17511816WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p)
17521817UPDATE ##bou_BlitzCacheProcs
@@ -1775,6 +1840,18 @@ WHERE [relop].exist('/p:RelOp[(@PhysicalOp[.="Remote Query"])]') = 1
17751840WHERE ##bou_BlitzCacheProcs .SqlHandle = x .SqlHandle
17761841OPTION (RECOMPILE ) ;
17771842
1843+
1844+ WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p)
1845+ UPDATE b
1846+ SET b .is_optimistic_cursor = CASE WHEN n1 .fn .exist(' //p:CursorPlan/@CursorConcurrency[.="Optimistic"]' ) = 1 THEN 1 END ,
1847+ b .is_forward_only_cursor = CASE WHEN n1 .fn .exist(' //p:CursorPlan/@ForwardOnly[.="true"]' ) = 1 THEN 1 ELSE 0 END
1848+ FROM ##bou_BlitzCacheProcs b
1849+ JOIN #statements AS qs
1850+ ON b .QueryHash = qs .QueryHash
1851+ CROSS APPLY qs .statement .nodes (' /p:StmtCursor' ) AS n1(fn)
1852+ OPTION (RECOMPILE ) ;
1853+
1854+
17781855IF @v >= 12
17791856BEGIN
17801857 RAISERROR (' Checking for downlevel cardinality estimators being used on SQL Server 2014.' , 0 , 1 ) WITH NOWAIT ;
@@ -2026,7 +2103,10 @@ SET Warnings = SUBSTRING(
20262103 CASE WHEN unparameterized_query = 1 THEN ' , Unparameterized Query' ELSE ' ' END +
20272104 CASE WHEN missing_index_count > 0 THEN ' , Missing Indexes (' + CAST (missing_index_count AS VARCHAR (3 )) + ' )' ELSE ' ' END +
20282105 CASE WHEN unmatched_index_count > 0 THEN ' , Unmatched Indexes (' + CAST (unmatched_index_count AS VARCHAR (3 )) + ' )' ELSE ' ' END +
2029- CASE WHEN is_cursor = 1 THEN ' , Cursor' ELSE ' ' END +
2106+ CASE WHEN is_cursor = 1 THEN ' , Cursor'
2107+ + CASE WHEN is_optimistic_cursor = 1 THEN ' with optimistic' ELSE ' ' END
2108+ + CASE WHEN is_forward_only_cursor = 0 THEN ' with forward only' ELSE ' ' END
2109+ ELSE ' ' END +
20302110 CASE WHEN is_parallel = 1 THEN ' , Parallel' ELSE ' ' END +
20312111 CASE WHEN near_parallel = 1 THEN ' , Nearly Parallel' ELSE ' ' END +
20322112 CASE WHEN frequent_execution = 1 THEN ' , Frequent Execution' ELSE ' ' END +
@@ -2042,8 +2122,11 @@ SET Warnings = SUBSTRING(
20422122 CASE WHEN is_key_lookup_expensive = 1 THEN ' , Expensive Key Lookup' ELSE ' ' END +
20432123 CASE WHEN is_remote_query_expensive = 1 THEN ' , Expensive Remote Query' ELSE ' ' END +
20442124 CASE WHEN trace_flags_session IS NOT NULL THEN ' , Session Level Trace Flag(s) Enabled: ' + trace_flags_session ELSE ' ' END +
2045- CASE WHEN is_remote_query_expensive = 1 THEN ' , Expensive Remote Query' ELSE ' ' END +
2046- CASE WHEN is_unused_grant = 1 THEN ' , Unused Memory Grant' ELSE ' ' END
2125+ CASE WHEN is_unused_grant = 1 THEN ' , Unused Memory Grant' ELSE ' ' END +
2126+ CASE WHEN function_count > 0 THEN ' , Calls ' + CONVERT (VARCHAR (10 ), function_count) + ' function(s)' ELSE ' ' END +
2127+ CASE WHEN clr_function_count > 0 THEN ' , Calls ' + CONVERT (VARCHAR (10 ), clr_function_count) + ' CLR function(s)' ELSE ' ' END +
2128+ CASE WHEN PlanCreationTimeHours <= 4 THEN ' , Plan created last 4hrs' ELSE ' ' END +
2129+ CASE WHEN is_table_variable = 1 THEN ' , Table Variables' ELSE ' ' END
20472130 , 2 , 200000 )
20482131 OPTION (RECOMPILE ) ;
20492132
@@ -2111,6 +2194,7 @@ BEGIN
21112194 PercentExecutionsByType money,' + N'
21122195 ExecutionsPerMinute money,
21132196 PlanCreationTime datetime,
2197+ PlanCreationTimeHours AS DATEDIFF(HOUR, PlanCreationTime, SYSDATETIME()),
21142198 LastExecutionTime datetime,
21152199 PlanHandle varbinary(64),
21162200 [Remove Plan Handle From Cache] AS
@@ -2352,7 +2436,11 @@ BEGIN
23522436 CASE WHEN is_key_lookup_expensive = 1 THEN '' , 26'' ELSE '' '' END +
23532437 CASE WHEN is_remote_query_expensive = 1 THEN '' , 28'' ELSE '' '' END +
23542438 CASE WHEN trace_flags_session IS NOT NULL THEN '' , 29'' ELSE '' '' END +
2355- CASE WHEN is_unused_grant = 1 THEN '' , 30'' ELSE '' '' END
2439+ CASE WHEN is_unused_grant = 1 THEN '' , 30'' ELSE '' '' END +
2440+ CASE WHEN function_count > 0 IS NOT NULL THEN '' , 31'' ELSE '' '' END +
2441+ CASE WHEN clr_function_count > 0 THEN '' , 32'' ELSE '' '' END +
2442+ CASE WHEN PlanCreationTimeHours <= 4 THEN '' , 33'' ELSE '' '' END +
2443+ CASE WHEN is_table_variable = 1 then '' , 34'' ELSE '' '' END
23562444 , 2, 200000) AS opserver_warning , ' + @nl ;
23572445 END
23582446
@@ -2499,6 +2587,35 @@ BEGIN
24992587 ' http://brentozar.com/blitzcache/cursors-found-slow-queries/' ,
25002588 ' There are cursors in the plan cache. This is neither good nor bad, but it is a thing. Cursors are weird in SQL Server.' );
25012589
2590+ IF EXISTS (SELECT 1 / 0
2591+ FROM ##bou_BlitzCacheProcs
2592+ WHERE is_cursor = 1
2593+ AND is_optimistic_cursor = 1
2594+ AND SPID = @@SPID )
2595+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
2596+ VALUES (@@SPID ,
2597+ 4 ,
2598+ 200 ,
2599+ ' Cursors' ,
2600+ ' Optimistic Cursors' ,
2601+ ' http://brentozar.com/blitzcache/cursors-found-slow-queries/' ,
2602+ ' There are optimistic cursors in the plan cache, which can harm performance.' );
2603+
2604+ IF EXISTS (SELECT 1 / 0
2605+ FROM ##bou_BlitzCacheProcs
2606+ WHERE is_cursor = 1
2607+ AND is_forward_only_cursor = 0
2608+ AND SPID = @@SPID )
2609+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
2610+ VALUES (@@SPID ,
2611+ 4 ,
2612+ 200 ,
2613+ ' Cursors' ,
2614+ ' Non-forward Only Cursors' ,
2615+ ' http://brentozar.com/blitzcache/cursors-found-slow-queries/' ,
2616+ ' There are non-forward only cursors in the plan cache, which can harm performance.' );
2617+
2618+
25022619 IF EXISTS (SELECT 1 / 0
25032620 FROM ##bou_BlitzCacheProcs
25042621 WHERE is_forced_parameterized = 1
@@ -2788,6 +2905,62 @@ BEGIN
27882905 ' No URL yet.' ,
27892906 ' Queries have large unused memory grants. This can cause concurrency issues, if queries are waiting a long time to get memory to run.' ) ;
27902907
2908+ IF EXISTS (SELECT 1 / 0
2909+ FROM ##bou_BlitzCacheProcs p
2910+ WHERE p .function_count > 0
2911+ AND SPID = @@SPID )
2912+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
2913+ VALUES (@@SPID ,
2914+ 31 ,
2915+ 100 ,
2916+ ' Compute Scalar That References A Function' ,
2917+ ' This could be trouble if you'' re using Scalar Functions or MSTVFs' ,
2918+ ' No URL yet.' ,
2919+ ' Both of these will force queries to run serially, run at least once per row, and may result in poor cardinality estimates' ) ;
2920+
2921+ IF EXISTS (SELECT 1 / 0
2922+ FROM ##bou_BlitzCacheProcs p
2923+ WHERE p .clr_function_count > 0
2924+ AND SPID = @@SPID )
2925+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
2926+ VALUES (@@SPID ,
2927+ 32 ,
2928+ 100 ,
2929+ ' Compute Scalar That References A CLR Function' ,
2930+ ' This could be trouble if your CLR functions perform data access' ,
2931+ ' No URL yet.' ,
2932+ ' May force queries to run serially, run at least once per row, and may result in poor cardinlity estimates' ) ;
2933+
2934+
2935+ IF EXISTS (SELECT 1 / 0
2936+ FROM ##bou_BlitzCacheProcs p
2937+ WHERE p .is_table_variable = 1
2938+ AND SPID = @@SPID )
2939+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
2940+ VALUES (@@SPID ,
2941+ 33 ,
2942+ 100 ,
2943+ ' Table Variables detected' ,
2944+ ' Beware nasty side effects' ,
2945+ ' No URL yet.' ,
2946+ ' All modifications are single threaded, and selects have really low row estimates.' ) ;
2947+
2948+ IF EXISTS (SELECT 1 / 0
2949+ FROM #plan_creation p
2950+ WHERE p .percent_24 > 0
2951+ OR p .percent_4 > 0
2952+ AND SPID = @@SPID )
2953+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
2954+ SELECT SPID,
2955+ 999 ,
2956+ 254 ,
2957+ ' Plan Cache Information' ,
2958+ ' You have ' + CONVERT (NVARCHAR (10 ), p .percent_24 ) + ' % plans created in the past 24 hours, and ' + CONVERT (NVARCHAR (10 ), p .percent_4 ) + ' % created in the past 4 hours.' ,
2959+ ' No URL yet.' ,
2960+ ' If these percentages are high, it may be a sign of memory pressure or plan cache instability.'
2961+ FROM #plan_creation p ;
2962+
2963+
27912964 IF EXISTS (SELECT 1 / 0
27922965 FROM #trace_flags AS tf
27932966 WHERE tf .global_trace_flags IS NOT NULL
@@ -2800,7 +2973,6 @@ BEGIN
28002973 ' You have Global Trace Flags enabled on your server' ,
28012974 ' https://www.brentozar.com/blitz/trace-flags-enabled-globally/' ,
28022975 ' You have the following Global Trace Flags enabled: ' + (SELECT TOP 1 tf .global_trace_flags FROM #trace_flags AS tf WHERE tf .global_trace_flags IS NOT NULL )) ;
2803-
28042976
28052977 END
28062978
0 commit comments