@@ -182,6 +182,19 @@ CREATE TABLE ##bou_BlitzCacheProcs (
182
182
is_sort_expensive BIT ,
183
183
sort_cost FLOAT ,
184
184
is_computed_filter BIT ,
185
+ op_name VARCHAR (100 ) NULL ,
186
+ index_insert_count INT NULL ,
187
+ index_update_count INT NULL ,
188
+ index_delete_count INT NULL ,
189
+ cx_insert_count INT NULL ,
190
+ cx_update_count INT NULL ,
191
+ cx_delete_count INT NULL ,
192
+ table_insert_count INT NULL ,
193
+ table_update_count INT NULL ,
194
+ table_delete_count INT NULL ,
195
+ index_ops AS (index_insert_count + index_update_count + index_delete_count +
196
+ cx_insert_count + cx_update_count + cx_delete_count +
197
+ table_insert_count + table_update_count + table_delete_count),
185
198
SetOptions VARCHAR (MAX ),
186
199
Warnings VARCHAR (MAX )
187
200
);
@@ -804,6 +817,19 @@ BEGIN
804
817
is_sort_expensive BIT ,
805
818
sort_cost FLOAT ,
806
819
is_computed_filter BIT ,
820
+ op_name VARCHAR (100 ) NULL ,
821
+ index_insert_count INT NULL ,
822
+ index_update_count INT NULL ,
823
+ index_delete_count INT NULL ,
824
+ cx_insert_count INT NULL ,
825
+ cx_update_count INT NULL ,
826
+ cx_delete_count INT NULL ,
827
+ table_insert_count INT NULL ,
828
+ table_update_count INT NULL ,
829
+ table_delete_count INT NULL ,
830
+ index_ops AS (index_insert_count + index_update_count + index_delete_count +
831
+ cx_insert_count + cx_update_count + cx_delete_count +
832
+ table_insert_count + table_update_count + table_delete_count),
807
833
SetOptions VARCHAR (MAX ),
808
834
Warnings VARCHAR (MAX )
809
835
);
@@ -2103,7 +2129,7 @@ WHERE ##bou_BlitzCacheProcs.SqlHandle = x.SqlHandle
2103
2129
OPTION (RECOMPILE )
2104
2130
2105
2131
2106
- RAISERROR (N ' Checking for computed columns that reference scalar UDFs' , 0 , 1 ) WITH NOWAIT ;
2132
+ RAISERROR (N ' Checking for filters that reference scalar UDFs' , 0 , 1 ) WITH NOWAIT ;
2107
2133
WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p)
2108
2134
UPDATE ##bou_BlitzCacheProcs
2109
2135
SET is_computed_filter = x .filter_function
@@ -2117,6 +2143,57 @@ CROSS APPLY r.relop.nodes('/p:RelOp/p:Filter/p:Predicate/p:ScalarOperator/p:Comp
2117
2143
WHERE ##bou_BlitzCacheProcs .SqlHandle = x .SqlHandle
2118
2144
OPTION (RECOMPILE )
2119
2145
2146
+ RAISERROR (N ' Checking modification queries that hit lots of indexes' , 0 , 1 ) WITH NOWAIT ;
2147
+ WITH XMLNAMESPACES(' http://schemas.microsoft.com/sqlserver/2004/07/showplan' AS p),
2148
+ IndexOps AS
2149
+ (
2150
+ SELECT
2151
+ r .SqlHandle ,
2152
+ c .n .value (' @PhysicalOp' , ' VARCHAR(100)' ) AS op_name,
2153
+ c .n .exist(' @PhysicalOp[.="Index Insert"]' ) AS ii,
2154
+ c .n .exist(' @PhysicalOp[.="Index Update"]' ) AS iu,
2155
+ c .n .exist(' @PhysicalOp[.="Index Delete"]' ) AS id,
2156
+ c .n .exist(' @PhysicalOp[.="Clustered Index Insert"]' ) AS cii,
2157
+ c .n .exist(' @PhysicalOp[.="Clustered Index Update"]' ) AS ciu,
2158
+ c .n .exist(' @PhysicalOp[.="Clustered Index Delete"]' ) AS cid,
2159
+ c .n .exist(' @PhysicalOp[.="Table Insert"]' ) AS ti,
2160
+ c .n .exist(' @PhysicalOp[.="Table Update"]' ) AS tu,
2161
+ c .n .exist(' @PhysicalOp[.="Table Delete"]' ) AS td
2162
+ FROM #relop AS r
2163
+ CROSS APPLY r .relop .nodes (' /p:RelOp' ) c(n)
2164
+ OUTER APPLY r .relop .nodes (' /p:RelOp/p:ScalarInsert/p:Object' ) q(n)
2165
+ OUTER APPLY r .relop .nodes (' /p:RelOp/p:Update/p:Object' ) o2(n)
2166
+ OUTER APPLY r .relop .nodes (' /p:RelOp/p:SimpleUpdate/p:Object' ) o3(n)
2167
+ ), iops AS
2168
+ (
2169
+ SELECT ios .SqlHandle ,
2170
+ SUM (CONVERT (TINYINT , ios .ii )) AS index_insert_count,
2171
+ SUM (CONVERT (TINYINT , ios .iu )) AS index_update_count,
2172
+ SUM (CONVERT (TINYINT , ios .id )) AS index_delete_count,
2173
+ SUM (CONVERT (TINYINT , ios .cii )) AS cx_insert_count,
2174
+ SUM (CONVERT (TINYINT , ios .ciu )) AS cx_update_count,
2175
+ SUM (CONVERT (TINYINT , ios .cid )) AS cx_delete_count,
2176
+ SUM (CONVERT (TINYINT , ios .ti )) AS table_insert_count,
2177
+ SUM (CONVERT (TINYINT , ios .tu )) AS table_update_count,
2178
+ SUM (CONVERT (TINYINT , ios .td )) AS table_delete_count
2179
+ FROM IndexOps AS ios
2180
+ WHERE ios .op_name IN (' Index Insert' , ' Index Delete' , ' Index Update' ,
2181
+ ' Clustered Index Insert' , ' Clustered Index Delete' , ' Clustered Index Update' ,
2182
+ ' Table Insert' , ' Table Delete' , ' Table Update' )
2183
+ GROUP BY ios .SqlHandle )
2184
+ UPDATE b
2185
+ SET b .index_insert_count = iops .index_insert_count ,
2186
+ b .index_update_count = iops .index_update_count ,
2187
+ b .index_delete_count = iops .index_delete_count ,
2188
+ b .cx_insert_count = iops .cx_insert_count ,
2189
+ b .cx_update_count = iops .cx_update_count ,
2190
+ b .cx_delete_count = iops .cx_delete_count ,
2191
+ b .table_insert_count = iops .table_insert_count ,
2192
+ b .table_update_count = iops .table_update_count ,
2193
+ b .table_delete_count = iops .table_delete_count
2194
+ FROM ##bou_BlitzCacheProcs AS b
2195
+ JOIN iops ON iops .SqlHandle = b .SqlHandle
2196
+ OPTION (RECOMPILE );
2120
2197
2121
2198
IF @v >= 12
2122
2199
BEGIN
@@ -2410,7 +2487,8 @@ SET Warnings = CASE WHEN QueryPlan IS NULL THEN 'We couldn''t find a plan for
2410
2487
CASE WHEN columnstore_row_mode = 1 THEN ' , ColumnStore Row Mode ' ELSE ' ' END +
2411
2488
CASE WHEN is_computed_scalar = 1 THEN ' , Computed Column UDF ' ELSE ' ' END +
2412
2489
CASE WHEN is_sort_expensive = 1 THEN ' , Expensive Sort' ELSE ' ' END +
2413
- CASE WHEN is_computed_filter = 1 THEN ' , Filter UDF' ELSE ' ' END
2490
+ CASE WHEN is_computed_filter = 1 THEN ' , Filter UDF' ELSE ' ' END +
2491
+ CASE WHEN index_ops >= 5 THEN ' , ' + CONVERT (VARCHAR (10 ), index_ops) + ' Indexes Modified' ELSE ' ' END
2414
2492
, 2 , 200000 )
2415
2493
END
2416
2494
OPTION (RECOMPILE ) ;
@@ -2734,7 +2812,8 @@ BEGIN
2734
2812
CASE WHEN columnstore_row_mode = 1 THEN '' , 41 '' ELSE '' END +
2735
2813
CASE WHEN is_computed_scalar = 1 THEN '' , 42 '' ELSE '' END +
2736
2814
CASE WHEN is_sort_expensive = 1 THEN '' , 43'' ELSE '' '' END +
2737
- CASE WHEN is_computed_filter = 1 THEN '' , 44'' ELSE '' '' END
2815
+ CASE WHEN is_computed_filter = 1 THEN '' , 44'' ELSE '' '' END +
2816
+ CASE WHEN index_ops >= 5 THEN '' , 45'' ELSE '' '' END
2738
2817
, 2, 200000) END AS opserver_warning , ' + @nl ;
2739
2818
END
2740
2819
@@ -3367,6 +3446,19 @@ BEGIN
3367
3446
' https://www.brentozar.com/blitzcache/compute-scalar-functions/' ,
3368
3447
' Someone put a Scalar UDF in the WHERE clause!' ) ;
3369
3448
3449
+ IF EXISTS (SELECT 1 / 0
3450
+ FROM ##bou_BlitzCacheProcs p
3451
+ WHERE p .index_ops >= 5
3452
+ AND SPID = @@SPID )
3453
+ INSERT INTO ##bou_BlitzCacheResults (SPID, CheckID, Priority, FindingsGroup, Finding, URL , Details)
3454
+ VALUES (@@SPID ,
3455
+ 45 ,
3456
+ 100 ,
3457
+ ' Many Indexes Modified' ,
3458
+ ' Write Queries Are Hitting >= 5 Indexes' ,
3459
+ ' No URL yet' ,
3460
+ ' This can cause lots of hidden I/O -- Run sp_BLitzIndex for more information.' ) ;
3461
+
3370
3462
IF EXISTS (SELECT 1 / 0
3371
3463
FROM #plan_creation p
3372
3464
WHERE (p .percent_24 > 0 OR p .percent_4 > 0 )
0 commit comments