Skip to content

Commit d0dfd44

Browse files
Merge pull request #69 from microsoft/dev
Fix 1520 to consider remaining contiguous sequence range, not full sequence range
2 parents c0596c3 + d9bb118 commit d0dfd44

File tree

2 files changed

+52
-48
lines changed

2 files changed

+52
-48
lines changed

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

Lines changed: 26 additions & 24 deletions
Original file line numberDiff line numberDiff line change
@@ -175,11 +175,11 @@ DECLARE
175175
-- 1420: The minumum number of blocked tasks observed at the time of each 20-second snapshot to be considered significant
176176
@LockBlockingBlockedTaskThreshold int = 1,
177177

178-
-- 1430: The minimum number of requests in an interval to start considering if query compilations are high
179-
@QueryCompilationRequestCountThreshold smallint = 100,
178+
-- 1430: The minimum number of requests in an interval to start considering if query optimizations are high
179+
@QueryOptimizationRequestCountThreshold smallint = 100,
180180

181-
-- 1430: The minimum ratio of query compilations (optimizations) to the number of requests to be considered significant
182-
@QueryCompilationRequestThresholdRatio decimal(3,2) = 0.15,
181+
-- 1430: The minimum ratio of query optimizations to the number of requests to be considered significant
182+
@QueryOptimizationRequestThresholdRatio decimal(3,2) = 0.15,
183183

184184
-- 1450: The minimum local storage usage ratio to be considered significant
185185
@MinLocalStorageQuotaUsageRatio decimal(3,2) = 0.85,
@@ -310,7 +310,7 @@ VALUES
310310
(1, 1400, 'Some statistics may be out of date', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1400', 'VIEW DATABASE STATE'),
311311
(1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE'),
312312
(1, 1420, 'Significant lock blocking has recently occurred', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1420', 'VIEW SERVER STATE'),
313-
(1, 1430, 'The number of recent query compilations is high', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1430', 'VIEW SERVER STATE'),
313+
(1, 1430, 'The number of recent query optimizations is high', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1430', 'VIEW SERVER STATE'),
314314
(1, 1440, 'Row locks or page locks are disabled for some indexes', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1440', 'VIEW DATABASE STATE'),
315315
(1, 1450, 'Allocated local storage is close to maximum local storage', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1450', 'VIEW SERVER STATE'),
316316
(1, 1460, 'Column collation does not match database collation', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1460', 'VIEW DATABASE STATE'),
@@ -1939,7 +1939,8 @@ SELECT 1510 AS tip_id,
19391939
', initial identity value: ', FORMAT(identity_seed, '#,0'),
19401940
', current identity value: ', FORMAT(current_identity_value, '#,0'),
19411941
', identity increment: ', FORMAT(identity_increment, '#,0'),
1942-
', data type range: ', FORMAT(range_min, '#,0'), ' to ', FORMAT(range_max, '#,0')
1942+
', data type range: ', FORMAT(range_min, '#,0'), ' to ', FORMAT(range_max, '#,0'),
1943+
', remaining contiguous range: ', FORMAT(IIF(identity_increment > 0, range_max_float - current_identity_value, range_min_float - current_identity_value), '#,0')
19431944
)
19441945
AS nvarchar(max)
19451946
),
@@ -1999,7 +2000,8 @@ SELECT 1520 AS tip_id,
19992000
', start value: ', FORMAT(start_value, '#,0'),
20002001
', current value: ', FORMAT(current_value, '#,0'),
20012002
', increment: ', FORMAT(increment, '#,0'),
2002-
', range: ', FORMAT(minimum_value, '#,0'), ' to ', FORMAT(maximum_value, '#,0'),
2003+
', full range: ', FORMAT(minimum_value, '#,0'), ' to ', FORMAT(maximum_value, '#,0'),
2004+
', remaining contiguous range: ', FORMAT(IIF(increment > 0, maximum_value - current_value, minimum_value - current_value), '#,0'),
20032005
', exhausted: ', IIF(is_exhausted = 1, 'Yes', 'No')
20042006
)
20052007
AS nvarchar(max)
@@ -2011,8 +2013,8 @@ SELECT 1520 AS tip_id,
20112013
AS details
20122014
FROM sequence_object
20132015
WHERE -- less than x% of the maximum sequence range remains
2014-
CASE WHEN increment > 0 THEN (maximum_value - current_value) / (maximum_value - minimum_value)
2015-
WHEN increment < 0 THEN (minimum_value - current_value) / (minimum_value - maximum_value)
2016+
CASE WHEN increment > 0 THEN (maximum_value - current_value) / (maximum_value - start_value)
2017+
WHEN increment < 0 THEN (minimum_value - current_value) / (minimum_value - start_value)
20162018
END < @IdentitySequenceRangeExhaustionThresholdRatio
20172019
HAVING COUNT(1) > 0;
20182020

@@ -3872,68 +3874,68 @@ FROM packed_blocking_snapshot
38723874
HAVING COUNT(1) > 0
38733875
;
38743876

3875-
-- High query compilations
3877+
-- High query optimizations
38763878
IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1430) AND execute_indicator = 1)
38773879

38783880
WITH
3879-
high_compilation_snapshot AS
3881+
high_optimizations_snapshot AS
38803882
(
38813883
SELECT snapshot_time,
38823884
duration_ms,
38833885
delta_request_count,
38843886
delta_query_optimizations,
3885-
IIF(delta_query_optimizations > @QueryCompilationRequestThresholdRatio * delta_request_count AND delta_request_count >= @QueryCompilationRequestCountThreshold, 1, 0) AS high_compilation_indicator
3887+
IIF(delta_query_optimizations > @QueryOptimizationRequestThresholdRatio * delta_request_count AND delta_request_count >= @QueryOptimizationRequestCountThreshold, 1, 0) AS high_optimizations_indicator
38863888
FROM sys.dm_resource_governor_workload_groups_history_ex
38873889
WHERE @EngineEdition = 5
38883890
AND
38893891
name like 'UserPrimaryGroup.DB%'
38903892
AND
38913893
TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID()
38923894
),
3893-
pre_packed_high_compilation_snapshot AS
3895+
pre_packed_high_optimizations_snapshot AS
38943896
(
38953897
SELECT snapshot_time,
38963898
duration_ms,
38973899
delta_request_count,
38983900
delta_query_optimizations,
3899-
high_compilation_indicator,
3901+
high_optimizations_indicator,
39003902
ROW_NUMBER() OVER (ORDER BY snapshot_time)
39013903
-
3902-
SUM(high_compilation_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING)
3904+
SUM(high_optimizations_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING)
39033905
AS grouping_helper
3904-
FROM high_compilation_snapshot
3906+
FROM high_optimizations_snapshot
39053907
),
3906-
packed_high_compilation_snapshot AS
3908+
packed_high_optimization_snapshot AS
39073909
(
39083910
SELECT MIN(snapshot_time) AS min_snapshot_time,
39093911
MAX(snapshot_time) AS max_snapshot_time,
39103912
AVG(duration_ms) AS avg_snapshot_interval_duration_ms,
39113913
SUM(delta_request_count) AS total_requests,
3912-
SUM(delta_query_optimizations) AS total_compilations
3913-
FROM pre_packed_high_compilation_snapshot
3914-
WHERE high_compilation_indicator = 1
3914+
SUM(delta_query_optimizations) AS total_optimizations
3915+
FROM pre_packed_high_optimizations_snapshot
3916+
WHERE high_optimizations_indicator = 1
39153917
GROUP BY grouping_helper
39163918
)
39173919
INSERT INTO @DetectedTip (tip_id, details)
39183920
SELECT 1430 AS tip_id,
39193921
CONCAT(
39203922
@NbspCRLF,
3921-
'Time intervals with a high number of query compilations (UTC):',
3923+
'Time intervals with a high number of query optimizations (UTC):',
39223924
@CRLF, @CRLF,
39233925
STRING_AGG(
39243926
CAST(CONCAT(
39253927
'Interval start time: ', FORMAT(DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), 's'),
39263928
', end time: ', FORMAT(max_snapshot_time, 's'),
39273929
', 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))),
39283930
', total requests: ', FORMAT(total_requests, '#,0'),
3929-
', total compilations: ', FORMAT(total_compilations, '#,0'),
3930-
', query compilation rate: ', FORMAT(LEAST(total_compilations * 1.0 / total_requests, 1), 'P')
3931+
', total optimizations: ', FORMAT(total_optimizations, '#,0'),
3932+
', query optimization rate: ', FORMAT(LEAST(total_optimizations * 1.0 / total_requests, 1), 'P')
39313933
) AS nvarchar(max)), @CRLF
39323934
),
39333935
@CRLF
39343936
)
39353937
AS details
3936-
FROM packed_high_compilation_snapshot
3938+
FROM packed_high_optimization_snapshot
39373939
HAVING COUNT(1) > 0
39383940
;
39393941

sqldb-tips/get-sqldb-tips.sql

Lines changed: 26 additions & 24 deletions
Original file line numberDiff line numberDiff line change
@@ -172,11 +172,11 @@ DECLARE
172172
-- 1420: The minumum number of blocked tasks observed at the time of each 20-second snapshot to be considered significant
173173
@LockBlockingBlockedTaskThreshold int = 1,
174174

175-
-- 1430: The minimum number of requests in an interval to start considering if query compilations are high
176-
@QueryCompilationRequestCountThreshold smallint = 100,
175+
-- 1430: The minimum number of requests in an interval to start considering if query optimizations are high
176+
@QueryOptimizationRequestCountThreshold smallint = 100,
177177

178-
-- 1430: The minimum ratio of query compilations (optimizations) to the number of requests to be considered significant
179-
@QueryCompilationRequestThresholdRatio decimal(3,2) = 0.15,
178+
-- 1430: The minimum ratio of query optimizations to the number of requests to be considered significant
179+
@QueryOptimizationRequestThresholdRatio decimal(3,2) = 0.15,
180180

181181
-- 1450: The minimum local storage usage ratio to be considered significant
182182
@MinLocalStorageQuotaUsageRatio decimal(3,2) = 0.85,
@@ -298,7 +298,7 @@ VALUES
298298
(1, 1400, 'Some statistics may be out of date', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1400', 'VIEW DATABASE STATE'),
299299
(1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE'),
300300
(1, 1420, 'Significant lock blocking has recently occurred', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1420', 'VIEW SERVER STATE'),
301-
(1, 1430, 'The number of recent query compilations is high', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1430', 'VIEW SERVER STATE'),
301+
(1, 1430, 'The number of recent query optimizations is high', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1430', 'VIEW SERVER STATE'),
302302
(1, 1440, 'Row locks or page locks are disabled for some indexes', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1440', 'VIEW DATABASE STATE'),
303303
(1, 1450, 'Allocated local storage is close to maximum local storage', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1450', 'VIEW SERVER STATE'),
304304
(1, 1460, 'Column collation does not match database collation', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1460', 'VIEW DATABASE STATE'),
@@ -1934,7 +1934,8 @@ SELECT 1510 AS tip_id,
19341934
', initial identity value: ', FORMAT(identity_seed, '#,0'),
19351935
', current identity value: ', FORMAT(current_identity_value, '#,0'),
19361936
', identity increment: ', FORMAT(identity_increment, '#,0'),
1937-
', data type range: ', FORMAT(range_min, '#,0'), ' to ', FORMAT(range_max, '#,0')
1937+
', data type range: ', FORMAT(range_min, '#,0'), ' to ', FORMAT(range_max, '#,0'),
1938+
', remaining contiguous range: ', FORMAT(IIF(identity_increment > 0, range_max_float - current_identity_value, range_min_float - current_identity_value), '#,0')
19381939
)
19391940
AS nvarchar(max)
19401941
),
@@ -1994,7 +1995,8 @@ SELECT 1520 AS tip_id,
19941995
', start value: ', FORMAT(start_value, '#,0'),
19951996
', current value: ', FORMAT(current_value, '#,0'),
19961997
', increment: ', FORMAT(increment, '#,0'),
1997-
', range: ', FORMAT(minimum_value, '#,0'), ' to ', FORMAT(maximum_value, '#,0'),
1998+
', full range: ', FORMAT(minimum_value, '#,0'), ' to ', FORMAT(maximum_value, '#,0'),
1999+
', remaining contiguous range: ', FORMAT(IIF(increment > 0, maximum_value - current_value, minimum_value - current_value), '#,0'),
19982000
', exhausted: ', IIF(is_exhausted = 1, 'Yes', 'No')
19992001
)
20002002
AS nvarchar(max)
@@ -2006,8 +2008,8 @@ SELECT 1520 AS tip_id,
20062008
AS details
20072009
FROM sequence_object
20082010
WHERE -- less than x% of the maximum sequence range remains
2009-
CASE WHEN increment > 0 THEN (maximum_value - current_value) / (maximum_value - minimum_value)
2010-
WHEN increment < 0 THEN (minimum_value - current_value) / (minimum_value - maximum_value)
2011+
CASE WHEN increment > 0 THEN (maximum_value - current_value) / (maximum_value - start_value)
2012+
WHEN increment < 0 THEN (minimum_value - current_value) / (minimum_value - start_value)
20112013
END < @IdentitySequenceRangeExhaustionThresholdRatio
20122014
HAVING COUNT(1) > 0;
20132015

@@ -3872,69 +3874,69 @@ FROM packed_blocking_snapshot
38723874
HAVING COUNT(1) > 0
38733875
;
38743876

3875-
-- High query compilations
3877+
-- High query optimizations
38763878
IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1430) AND execute_indicator = 1)
38773879

38783880
WITH
3879-
high_compilation_snapshot AS
3881+
high_optimizations_snapshot AS
38803882
(
38813883
SELECT snapshot_time,
38823884
duration_ms,
38833885
delta_request_count,
38843886
delta_query_optimizations,
3885-
IIF(delta_query_optimizations > @QueryCompilationRequestThresholdRatio * delta_request_count AND delta_request_count >= @QueryCompilationRequestCountThreshold, 1, 0) AS high_compilation_indicator
3887+
IIF(delta_query_optimizations > @QueryOptimizationRequestThresholdRatio * delta_request_count AND delta_request_count >= @QueryOptimizationRequestCountThreshold, 1, 0) AS high_optimizations_indicator
38863888
FROM sys.dm_resource_governor_workload_groups_history_ex
38873889
WHERE @EngineEdition = 5
38883890
AND
38893891
name like 'UserPrimaryGroup.DB%'
38903892
AND
38913893
TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID()
38923894
),
3893-
pre_packed_high_compilation_snapshot AS
3895+
pre_packed_high_optimizations_snapshot AS
38943896
(
38953897
SELECT snapshot_time,
38963898
duration_ms,
38973899
delta_request_count,
38983900
delta_query_optimizations,
3899-
high_compilation_indicator,
3901+
high_optimizations_indicator,
39003902
ROW_NUMBER() OVER (ORDER BY snapshot_time)
39013903
-
3902-
SUM(high_compilation_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING)
3904+
SUM(high_optimizations_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING)
39033905
AS grouping_helper
3904-
FROM high_compilation_snapshot
3906+
FROM high_optimizations_snapshot
39053907
),
3906-
packed_high_compilation_snapshot AS
3908+
packed_high_optimization_snapshot AS
39073909
(
39083910
SELECT MIN(snapshot_time) AS min_snapshot_time,
39093911
MAX(snapshot_time) AS max_snapshot_time,
39103912
AVG(duration_ms) AS avg_snapshot_interval_duration_ms,
39113913
SUM(delta_request_count) AS total_requests,
3912-
SUM(delta_query_optimizations) AS total_compilations
3913-
FROM pre_packed_high_compilation_snapshot
3914-
WHERE high_compilation_indicator = 1
3914+
SUM(delta_query_optimizations) AS total_optimizations
3915+
FROM pre_packed_high_optimizations_snapshot
3916+
WHERE high_optimizations_indicator = 1
39153917
GROUP BY grouping_helper
39163918
)
39173919
INSERT INTO @DetectedTip (tip_id, details)
39183920
SELECT 1430 AS tip_id,
39193921
CONCAT(
39203922
@NbspCRLF,
3921-
'Time intervals with a high number of query compilations (UTC):',
3923+
'Time intervals with a high number of query optimizations (UTC):',
39223924
@CRLF, @CRLF,
39233925
STRING_AGG(
39243926
CAST(CONCAT(
39253927
'Interval start time: ', FORMAT(DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), 's'),
39263928
', end time: ', FORMAT(max_snapshot_time, 's'),
39273929
', 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))),
39283930
', total requests: ', FORMAT(total_requests, '#,0'),
3929-
', total compilations: ', FORMAT(total_compilations, '#,0'),
3930-
', query compilation rate: ', FORMAT(LEAST(total_compilations * 1.0 / total_requests, 1), 'P')
3931+
', total optimizations: ', FORMAT(total_optimizations, '#,0'),
3932+
', query optimization rate: ', FORMAT(LEAST(total_optimizations * 1.0 / total_requests, 1), 'P')
39313933
) AS nvarchar(max)), @CRLF
39323934
)
39333935
WITHIN GROUP (ORDER BY min_snapshot_time DESC),
39343936
@CRLF
39353937
)
39363938
AS details
3937-
FROM packed_high_compilation_snapshot
3939+
FROM packed_high_optimization_snapshot
39383940
HAVING COUNT(1) > 0
39393941
;
39403942

0 commit comments

Comments
 (0)