Skip to content

Commit b59bbab

Browse files
Added a tip to detect recent blocking
1 parent 24f3143 commit b59bbab

File tree

2 files changed

+173
-8
lines changed

2 files changed

+173
-8
lines changed

sqldb-tips/get-sqldb-tips-compat-level-100-only.sql

Lines changed: 86 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -167,7 +167,13 @@ DECLARE
167167
@NoIndexTablesMinRowCountThreshold int = 500,
168168

169169
-- 1410: The minimum ratio of the number of no-index tables to the total number of tables to be considered significant
170-
@NoIndexMinTableCountRatio decimal(3,2) = 0.2
170+
@NoIndexMinTableCountRatio decimal(3,2) = 0.2,
171+
172+
-- 1420: The minimum ratio of total time spend waiting on locks during the interval to the interval duration to be considered significant
173+
@LockBlockingTimeThresholdRatio decimal(3,2) = 0.1,
174+
175+
-- 1420: The minumum number of blocked tasks observed at the time of each 20-second snapshot to be considered significant
176+
@LockBlockingBlockedTaskThreshold int = 1
171177
;
172178

173179
DECLARE @ExecStartTime datetimeoffset = SYSDATETIMEOFFSET();
@@ -281,7 +287,8 @@ VALUES
281287
(1, 1380, 'Notable network connectivity events found', 30, 'https://aka.ms/sqldbtipswiki#tip_id-1380', 'VIEW SERVER STATE'),
282288
(1, 1390, 'Instance CPU utilization is high', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1390', 'VIEW DATABASE STATE'),
283289
(1, 1400, 'Some statistics may be out of date', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1400', 'VIEW DATABASE STATE'),
284-
(1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE')
290+
(1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE'),
291+
(1, 1420, 'Significant lock blocking has recently occurred', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1420', 'VIEW SERVER STATE')
285292
;
286293

287294
-- Top queries
@@ -769,7 +776,8 @@ WITH
769776
object_size AS
770777
(
771778
SELECT object_id,
772-
SUM(used_page_count) * 8 / 1024. AS object_size_mb
779+
SUM(used_page_count) * 8 / 1024. AS object_size_mb,
780+
SUM(row_count) AS object_row_count
773781
FROM sys.dm_db_partition_stats
774782
WHERE index_id IN (0,1) -- clustered index or heap
775783
GROUP BY object_id
@@ -781,7 +789,9 @@ SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS sc
781789
QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name,
782790
i.type_desc COLLATE DATABASE_DEFAULT AS index_type,
783791
o.object_id,
784-
i.index_id
792+
i.index_id,
793+
os.object_size_mb,
794+
os.object_row_count
785795
FROM sys.objects AS o
786796
INNER JOIN sys.indexes AS i
787797
ON o.object_id = i.object_id
@@ -832,6 +842,8 @@ SELECT 1100 AS tip_id,
832842
CAST(CONCAT(
833843
'schema: ', schema_name,
834844
', object: ', object_name,
845+
', object size (MB): ', FORMAT(object_size_mb, '#,0.00'),
846+
', object row count: ', FORMAT(object_row_count, '#,0'),
835847
', index: ', index_name,
836848
', type: ', index_type,
837849
', object_id: ', CAST(object_id AS varchar(11)),
@@ -2979,6 +2991,76 @@ END CATCH;
29792991

29802992
END;
29812993

2994+
-- Significant recent blocking
2995+
IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1420) AND execute_indicator = 1)
2996+
2997+
WITH
2998+
blocking_snapshot AS
2999+
(
3000+
SELECT snapshot_time,
3001+
duration_ms,
3002+
blocked_task_count,
3003+
delta_lock_wait_count,
3004+
delta_lock_wait_time_ms,
3005+
IIF(delta_lock_wait_time_ms > @LockBlockingTimeThresholdRatio * duration_ms OR blocked_task_count >= @LockBlockingBlockedTaskThreshold, 1, 0) AS blocking_indicator
3006+
FROM sys.dm_resource_governor_workload_groups_history_ex
3007+
WHERE @EngineEdition = 5
3008+
AND
3009+
name like 'UserPrimaryGroup.DB%'
3010+
AND
3011+
TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID()
3012+
),
3013+
pre_packed_blocking_snapshot AS
3014+
(
3015+
SELECT snapshot_time,
3016+
duration_ms,
3017+
blocked_task_count,
3018+
delta_lock_wait_count,
3019+
delta_lock_wait_time_ms,
3020+
blocking_indicator,
3021+
ROW_NUMBER() OVER (ORDER BY snapshot_time)
3022+
-
3023+
SUM(blocking_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING)
3024+
AS grouping_helper
3025+
FROM blocking_snapshot
3026+
),
3027+
packed_blocking_snapshot AS
3028+
(
3029+
SELECT MIN(snapshot_time) AS min_snapshot_time,
3030+
MAX(snapshot_time) AS max_snapshot_time,
3031+
AVG(duration_ms) AS avg_snapshot_interval_duration_ms,
3032+
MIN(blocked_task_count) AS min_blocked_task_count,
3033+
MAX(blocked_task_count) AS max_blocked_task_count,
3034+
SUM(delta_lock_wait_count) AS total_lock_waits,
3035+
SUM(delta_lock_wait_time_ms) / 1000 AS total_lock_wait_time_seconds
3036+
FROM pre_packed_blocking_snapshot
3037+
WHERE blocking_indicator = 1
3038+
GROUP BY grouping_helper
3039+
)
3040+
INSERT INTO @DetectedTip (tip_id, details)
3041+
SELECT 1420 AS tip_id,
3042+
CONCAT(
3043+
@NbspCRLF,
3044+
'Significant lock blocking has occurred during the following time intervals (most recent first):',
3045+
@CRLF, @CRLF,
3046+
STRING_AGG(
3047+
CAST(CONCAT(
3048+
'Interval start time: ', FORMAT(DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), 's'),
3049+
', end time: ', FORMAT(max_snapshot_time, 's'),
3050+
', duration: ', DATEADD(second, DATEDIFF(second, DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), max_snapshot_time), CAST('00:00:00' AS time(0))),
3051+
', total lock wait time: ', DATEADD(second, total_lock_wait_time_seconds, CAST('00:00:00' AS time(0))),
3052+
', minimum observed blocked tasks: ', FORMAT(min_blocked_task_count, '#,0'),
3053+
', maximum observed blocked tasks: ', FORMAT(max_blocked_task_count, '#,0'),
3054+
', total lock waits: ', FORMAT(total_lock_waits, '#,0')
3055+
) AS nvarchar(max)), @CRLF
3056+
),
3057+
@CRLF
3058+
)
3059+
AS details
3060+
FROM packed_blocking_snapshot
3061+
HAVING COUNT(1) > 0
3062+
;
3063+
29823064
END; -- end tips requiring VIEW SERVER STATE
29833065

29843066
-- Return detected tips

sqldb-tips/get-sqldb-tips.sql

Lines changed: 87 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -164,7 +164,13 @@ DECLARE
164164
@NoIndexTablesMinRowCountThreshold int = 500,
165165

166166
-- 1410: The minimum ratio of the number of no-index tables to the total number of tables to be considered significant
167-
@NoIndexMinTableCountRatio decimal(3,2) = 0.2
167+
@NoIndexMinTableCountRatio decimal(3,2) = 0.2,
168+
169+
-- 1420: The minimum ratio of total time spend waiting on locks during the interval to the interval duration to be considered significant
170+
@LockBlockingTimeThresholdRatio decimal(3,2) = 0.1,
171+
172+
-- 1420: The minumum number of blocked tasks observed at the time of each 20-second snapshot to be considered significant
173+
@LockBlockingBlockedTaskThreshold int = 1
168174
;
169175

170176
DECLARE @ExecStartTime datetimeoffset = SYSDATETIMEOFFSET();
@@ -269,7 +275,8 @@ VALUES
269275
(1, 1380, 'Notable network connectivity events found', 30, 'https://aka.ms/sqldbtipswiki#tip_id-1380', 'VIEW SERVER STATE'),
270276
(1, 1390, 'Instance CPU utilization is high', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1390', 'VIEW DATABASE STATE'),
271277
(1, 1400, 'Some statistics may be out of date', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1400', 'VIEW DATABASE STATE'),
272-
(1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE')
278+
(1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE'),
279+
(1, 1420, 'Significant lock blocking has recently occurred', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1420', 'VIEW SERVER STATE')
273280
;
274281

275282
-- Top queries
@@ -759,7 +766,8 @@ WITH
759766
object_size AS
760767
(
761768
SELECT object_id,
762-
SUM(used_page_count) * 8 / 1024. AS object_size_mb
769+
SUM(used_page_count) * 8 / 1024. AS object_size_mb,
770+
SUM(row_count) AS object_row_count
763771
FROM sys.dm_db_partition_stats
764772
WHERE index_id IN (0,1) -- clustered index or heap
765773
GROUP BY object_id
@@ -771,7 +779,9 @@ SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS sc
771779
QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name,
772780
i.type_desc COLLATE DATABASE_DEFAULT AS index_type,
773781
o.object_id,
774-
i.index_id
782+
i.index_id,
783+
os.object_size_mb,
784+
os.object_row_count
775785
FROM sys.objects AS o
776786
INNER JOIN sys.indexes AS i
777787
ON o.object_id = i.object_id
@@ -822,6 +832,8 @@ SELECT 1100 AS tip_id,
822832
CAST(CONCAT(
823833
'schema: ', schema_name,
824834
', object: ', object_name,
835+
', object size (MB): ', FORMAT(object_size_mb, '#,0.00'),
836+
', object row count: ', FORMAT(object_row_count, '#,0'),
825837
', index: ', index_name,
826838
', type: ', index_type,
827839
', object_id: ', CAST(object_id AS varchar(11)),
@@ -2977,6 +2989,77 @@ END CATCH;
29772989

29782990
END;
29792991

2992+
-- Significant recent blocking
2993+
IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1420) AND execute_indicator = 1)
2994+
2995+
WITH
2996+
blocking_snapshot AS
2997+
(
2998+
SELECT snapshot_time,
2999+
duration_ms,
3000+
blocked_task_count,
3001+
delta_lock_wait_count,
3002+
delta_lock_wait_time_ms,
3003+
IIF(delta_lock_wait_time_ms > @LockBlockingTimeThresholdRatio * duration_ms OR blocked_task_count >= @LockBlockingBlockedTaskThreshold, 1, 0) AS blocking_indicator
3004+
FROM sys.dm_resource_governor_workload_groups_history_ex
3005+
WHERE @EngineEdition = 5
3006+
AND
3007+
name like 'UserPrimaryGroup.DB%'
3008+
AND
3009+
TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID()
3010+
),
3011+
pre_packed_blocking_snapshot AS
3012+
(
3013+
SELECT snapshot_time,
3014+
duration_ms,
3015+
blocked_task_count,
3016+
delta_lock_wait_count,
3017+
delta_lock_wait_time_ms,
3018+
blocking_indicator,
3019+
ROW_NUMBER() OVER (ORDER BY snapshot_time)
3020+
-
3021+
SUM(blocking_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING)
3022+
AS grouping_helper
3023+
FROM blocking_snapshot
3024+
),
3025+
packed_blocking_snapshot AS
3026+
(
3027+
SELECT MIN(snapshot_time) AS min_snapshot_time,
3028+
MAX(snapshot_time) AS max_snapshot_time,
3029+
AVG(duration_ms) AS avg_snapshot_interval_duration_ms,
3030+
MIN(blocked_task_count) AS min_blocked_task_count,
3031+
MAX(blocked_task_count) AS max_blocked_task_count,
3032+
SUM(delta_lock_wait_count) AS total_lock_waits,
3033+
SUM(delta_lock_wait_time_ms) / 1000 AS total_lock_wait_time_seconds
3034+
FROM pre_packed_blocking_snapshot
3035+
WHERE blocking_indicator = 1
3036+
GROUP BY grouping_helper
3037+
)
3038+
INSERT INTO @DetectedTip (tip_id, details)
3039+
SELECT 1420 AS tip_id,
3040+
CONCAT(
3041+
@NbspCRLF,
3042+
'Significant lock blocking has occurred during the following time intervals (most recent first):',
3043+
@CRLF, @CRLF,
3044+
STRING_AGG(
3045+
CAST(CONCAT(
3046+
'Interval start time: ', FORMAT(DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), 's'),
3047+
', end time: ', FORMAT(max_snapshot_time, 's'),
3048+
', duration: ', DATEADD(second, DATEDIFF(second, DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), max_snapshot_time), CAST('00:00:00' AS time(0))),
3049+
', total lock wait time: ', DATEADD(second, total_lock_wait_time_seconds, CAST('00:00:00' AS time(0))),
3050+
', minimum observed blocked tasks: ', FORMAT(min_blocked_task_count, '#,0'),
3051+
', maximum observed blocked tasks: ', FORMAT(max_blocked_task_count, '#,0'),
3052+
', total lock waits: ', FORMAT(total_lock_waits, '#,0')
3053+
) AS nvarchar(max)), @CRLF
3054+
)
3055+
WITHIN GROUP (ORDER BY min_snapshot_time DESC),
3056+
@CRLF
3057+
)
3058+
AS details
3059+
FROM packed_blocking_snapshot
3060+
HAVING COUNT(1) > 0
3061+
;
3062+
29803063
END; -- end tips requiring VIEW SERVER STATE
29813064

29823065
-- Return detected tips

0 commit comments

Comments
 (0)