@@ -4,7 +4,7 @@ For all newer compatibility levels, use get-sqldb-tips.sql at https://aka.ms/sql
44
55Returns a set of tips to improve database design, health, and performance in Azure SQL Database.
66For the latest version of the script, see https://aka.ms/sqldbtips
7- For detailed description, see https://aka.ms/sqldbtipswiki
7+ For a detailed description, see https://aka.ms/sqldbtipswiki
88*/
99
1010-- Set to 1 to output tips as a JSON value
@@ -179,7 +179,10 @@ DECLARE
179179@QueryCompilationRequestCountThreshold smallint = 100 ,
180180
181181-- 1430: The minimum ratio of query compilations (optimizations) to the number of requests to be considered significant
182- @QueryCompilationRequestThresholdRatio decimal (3 ,2 ) = 0 .15
182+ @QueryCompilationRequestThresholdRatio decimal (3 ,2 ) = 0 .15 ,
183+
184+ -- 1450: The minimum local storage usage ratio to be considered significant
185+ @MinLocalStorageQuotaUsageRatio decimal (3 ,2 ) = 0 .85
183186;
184187
185188DECLARE @ExecStartTime datetimeoffset = SYSDATETIMEOFFSET ();
@@ -250,53 +253,54 @@ IF EXISTS (
250253-- Define all tips
251254INSERT INTO @TipDefinition (execute_indicator, tip_id, tip_name, confidence_percent, tip_url, required_permission)
252255VALUES
253- (1 , 1000 , ' Reduce MAXDOP on all replicas' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1000' , ' VIEW DATABASE STATE' ),
254- (1 , 1010 , ' Reduce MAXDOP on primary' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1010' , ' VIEW DATABASE STATE' ),
255- (1 , 1020 , ' Reduce MAXDOP on secondaries' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1020' , ' VIEW DATABASE STATE' ),
256- (1 , 1030 , ' Use the latest database compatibility level' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1030' , ' VIEW DATABASE STATE' ),
257- (1 , 1040 , ' Enable auto-create statistics' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1040' , ' VIEW DATABASE STATE' ),
258- (1 , 1050 , ' Enable auto-update statistics' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1050' , ' VIEW DATABASE STATE' ),
259- (1 , 1060 , ' Enable Read Committed Snapshot Isolation (RCSI)' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1060' , ' VIEW DATABASE STATE' ),
260- (1 , 1070 , ' Enable Query Store' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1070' , ' VIEW DATABASE STATE' ),
261- (1 , 1071 , ' Change Query Store operation mode to read-write' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1071' , ' VIEW DATABASE STATE' ),
262- (1 , 1072 , ' Change Query Store capture mode from NONE to AUTO/ALL' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1072' , ' VIEW DATABASE STATE' ),
263- (1 , 1080 , ' Disable AUTO_SHRINK' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1080' , ' VIEW DATABASE STATE' ),
264- (1 , 1100 , ' Avoid GUID leading columns in btree indexes' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1100' , ' VIEW DATABASE STATE' ),
265- (1 , 1110 , ' Enable FLGP auto-tuning' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1110' , ' VIEW DATABASE STATE' ),
266- (1 , 1120 , ' Used data size is close to MAXSIZE' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1120' , ' VIEW DATABASE STATE' ),
267- (1 , 1130 , ' Allocated data size is close to MAXSIZE' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1130' , ' VIEW DATABASE STATE' ),
268- (1 , 1140 , ' Allocated data size is much larger than used data size' , 50 , ' https://aka.ms/sqldbtipswiki#tip_id-1140' , ' VIEW DATABASE STATE' ),
269- (1 , 1150 , ' Recent CPU throttling found' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1150' , ' VIEW SERVER STATE' ),
270- (1 , 1160 , ' Recent out of memory errors found' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1160' , ' VIEW SERVER STATE' ),
271- (1 , 1165 , ' Recent memory grant waits and timeouts found' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1165' , ' VIEW SERVER STATE' ),
272- (1 , 1170 , ' Nonclustered indexes with low reads found' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1170' , ' VIEW SERVER STATE' ),
273- (1 , 1180 , ' ROW or PAGE compression opportunities may exist' , 65 , ' https://aka.ms/sqldbtipswiki#tip_id-1180' , ' VIEW SERVER STATE' ),
274- (1 , 1190 , ' Transaction log IO is close to limit' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1190' , ' VIEW DATABASE STATE' ),
275- (1 , 1200 , ' Plan cache is bloated by single-use plans' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1200' , ' VIEW DATABASE STATE' ),
276- (1 , 1210 , ' Missing indexes may be impacting performance' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1210' , ' VIEW SERVER STATE' ),
277- (1 , 1220 , ' Redo queue on a secondary replica is large' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1220' , ' VIEW DATABASE STATE' ),
278- (1 , 1230 , ' Data IOPS are close to workload group limit' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1230' , ' VIEW SERVER STATE' ),
279- (1 , 1240 , ' Workload group IO governance impact is significant' , 40 , ' https://aka.ms/sqldbtipswiki#tip_id-1240' , ' VIEW SERVER STATE' ),
280- (1 , 1250 , ' Data IOPS are close to resource pool limit' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1250' , ' VIEW SERVER STATE' ),
281- (1 , 1260 , ' Resouce pool IO governance impact is significant' , 40 , ' https://aka.ms/sqldbtipswiki#tip_id-1260' , ' VIEW SERVER STATE' ),
282- (1 , 1270 , ' Persistent Version Store size is large' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1270' , ' VIEW SERVER STATE' ),
283- (1 , 1280 , ' Paused resumable index operations found' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1280' , ' VIEW DATABASE STATE' ),
284- (1 , 1290 , ' Clustered columnstore candidates found' , 50 , ' https://aka.ms/sqldbtipswiki#tip_id-1290' , ' VIEW SERVER STATE' ),
285- (1 , 1300 , ' Geo-replication state may be unhealthy' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1300' , ' VIEW DATABASE STATE' ),
286- (1 , 1310 , ' Last partitions are not empty' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1310' , ' VIEW DATABASE STATE' ),
287- (1 , 1320 , ' Top queries should be investigated and tuned' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1320' , ' VIEW DATABASE STATE' ),
288- (1 , 1330 , ' Tempdb data allocated size is close to MAXSIZE' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1330' , ' tempdb.VIEW DATABASE STATE' ),
289- (1 , 1340 , ' Tempdb data used size is close to MAXSIZE' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1340' , ' tempdb.VIEW DATABASE STATE' ),
290- (1 , 1350 , ' Tempdb log allocated size is close to MAXSIZE' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1350' , ' tempdb.VIEW DATABASE STATE' ),
291- (1 , 1360 , ' Worker utilization is close to workload group limit' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1360' , ' VIEW SERVER STATE' ),
292- (1 , 1370 , ' Worker utilization is close to resource pool limit' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1370' , ' VIEW SERVER STATE' ),
293- (1 , 1380 , ' Notable network connectivity events found' , 30 , ' https://aka.ms/sqldbtipswiki#tip_id-1380' , ' VIEW SERVER STATE' ),
294- (1 , 1390 , ' Instance CPU utilization is high' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1390' , ' VIEW DATABASE STATE' ),
295- (1 , 1400 , ' Some statistics may be out of date' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1400' , ' VIEW DATABASE STATE' ),
296- (1 , 1410 , ' Many tables do not have any indexes' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1410' , ' VIEW DATABASE STATE' ),
297- (1 , 1420 , ' Significant lock blocking has recently occurred' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1420' , ' VIEW SERVER STATE' ),
298- (1 , 1430 , ' The number of recent query compilations is high' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1430' , ' VIEW SERVER STATE' ),
299- (1 , 1440 , ' Row locks or page locks are disabled for some indexes' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1440' , ' VIEW DATABASE STATE' )
256+ (1 , 1000 , ' Reduce MAXDOP on all replicas' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1000' , ' VIEW DATABASE STATE' ),
257+ (1 , 1010 , ' Reduce MAXDOP on primary' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1010' , ' VIEW DATABASE STATE' ),
258+ (1 , 1020 , ' Reduce MAXDOP on secondaries' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1020' , ' VIEW DATABASE STATE' ),
259+ (1 , 1030 , ' Use the latest database compatibility level' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1030' , ' VIEW DATABASE STATE' ),
260+ (1 , 1040 , ' Enable auto-create statistics' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1040' , ' VIEW DATABASE STATE' ),
261+ (1 , 1050 , ' Enable auto-update statistics' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1050' , ' VIEW DATABASE STATE' ),
262+ (1 , 1060 , ' Enable Read Committed Snapshot Isolation (RCSI)' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1060' , ' VIEW DATABASE STATE' ),
263+ (1 , 1070 , ' Enable Query Store' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1070' , ' VIEW DATABASE STATE' ),
264+ (1 , 1071 , ' Change Query Store operation mode to read-write' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1071' , ' VIEW DATABASE STATE' ),
265+ (1 , 1072 , ' Change Query Store capture mode from NONE to AUTO/ALL' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1072' , ' VIEW DATABASE STATE' ),
266+ (1 , 1080 , ' Disable AUTO_SHRINK' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1080' , ' VIEW DATABASE STATE' ),
267+ (1 , 1100 , ' Avoid GUID leading columns in btree indexes' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1100' , ' VIEW DATABASE STATE' ),
268+ (1 , 1110 , ' Enable FLGP auto-tuning' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1110' , ' VIEW DATABASE STATE' ),
269+ (1 , 1120 , ' Used data size is close to MAXSIZE' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1120' , ' VIEW DATABASE STATE' ),
270+ (1 , 1130 , ' Allocated data size is close to MAXSIZE' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1130' , ' VIEW DATABASE STATE' ),
271+ (1 , 1140 , ' Allocated data size is much larger than used data size' , 50 , ' https://aka.ms/sqldbtipswiki#tip_id-1140' , ' VIEW DATABASE STATE' ),
272+ (1 , 1150 , ' Recent CPU throttling found' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1150' , ' VIEW SERVER STATE' ),
273+ (1 , 1160 , ' Recent out of memory errors found' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1160' , ' VIEW SERVER STATE' ),
274+ (1 , 1165 , ' Recent memory grant waits and timeouts found' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1165' , ' VIEW SERVER STATE' ),
275+ (1 , 1170 , ' Nonclustered indexes with low reads found' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1170' , ' VIEW SERVER STATE' ),
276+ (1 , 1180 , ' ROW or PAGE compression opportunities may exist' , 65 , ' https://aka.ms/sqldbtipswiki#tip_id-1180' , ' VIEW SERVER STATE' ),
277+ (1 , 1190 , ' Transaction log IO is close to limit' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1190' , ' VIEW DATABASE STATE' ),
278+ (1 , 1200 , ' Plan cache is bloated by single-use plans' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1200' , ' VIEW DATABASE STATE' ),
279+ (1 , 1210 , ' Missing indexes may be impacting performance' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1210' , ' VIEW SERVER STATE' ),
280+ (1 , 1220 , ' Redo queue on a secondary replica is large' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1220' , ' VIEW DATABASE STATE' ),
281+ (1 , 1230 , ' Data IOPS are close to workload group limit' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1230' , ' VIEW SERVER STATE' ),
282+ (1 , 1240 , ' Workload group IO governance impact is significant' , 40 , ' https://aka.ms/sqldbtipswiki#tip_id-1240' , ' VIEW SERVER STATE' ),
283+ (1 , 1250 , ' Data IOPS are close to resource pool limit' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1250' , ' VIEW SERVER STATE' ),
284+ (1 , 1260 , ' Resouce pool IO governance impact is significant' , 40 , ' https://aka.ms/sqldbtipswiki#tip_id-1260' , ' VIEW SERVER STATE' ),
285+ (1 , 1270 , ' Persistent Version Store size is large' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1270' , ' VIEW SERVER STATE' ),
286+ (1 , 1280 , ' Paused resumable index operations found' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1280' , ' VIEW DATABASE STATE' ),
287+ (1 , 1290 , ' Clustered columnstore candidates found' , 50 , ' https://aka.ms/sqldbtipswiki#tip_id-1290' , ' VIEW SERVER STATE' ),
288+ (1 , 1300 , ' Geo-replication state may be unhealthy' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1300' , ' VIEW DATABASE STATE' ),
289+ (1 , 1310 , ' Last partitions are not empty' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1310' , ' VIEW DATABASE STATE' ),
290+ (1 , 1320 , ' Top queries should be investigated and tuned' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1320' , ' VIEW DATABASE STATE' ),
291+ (1 , 1330 , ' Tempdb data allocated size is close to MAXSIZE' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1330' , ' tempdb.VIEW DATABASE STATE' ),
292+ (1 , 1340 , ' Tempdb data used size is close to MAXSIZE' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1340' , ' tempdb.VIEW DATABASE STATE' ),
293+ (1 , 1350 , ' Tempdb log allocated size is close to MAXSIZE' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1350' , ' tempdb.VIEW DATABASE STATE' ),
294+ (1 , 1360 , ' Worker utilization is close to workload group limit' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1360' , ' VIEW SERVER STATE' ),
295+ (1 , 1370 , ' Worker utilization is close to resource pool limit' , 80 , ' https://aka.ms/sqldbtipswiki#tip_id-1370' , ' VIEW SERVER STATE' ),
296+ (1 , 1380 , ' Notable network connectivity events found' , 30 , ' https://aka.ms/sqldbtipswiki#tip_id-1380' , ' VIEW SERVER STATE' ),
297+ (1 , 1390 , ' Instance CPU utilization is high' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1390' , ' VIEW DATABASE STATE' ),
298+ (1 , 1400 , ' Some statistics may be out of date' , 70 , ' https://aka.ms/sqldbtipswiki#tip_id-1400' , ' VIEW DATABASE STATE' ),
299+ (1 , 1410 , ' Many tables do not have any indexes' , 60 , ' https://aka.ms/sqldbtipswiki#tip_id-1410' , ' VIEW DATABASE STATE' ),
300+ (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' ),
302+ (1 , 1440 , ' Row locks or page locks are disabled for some indexes' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1440' , ' VIEW DATABASE STATE' ),
303+ (1 , 1450 , ' Allocated local storage is close to maximum local storage' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1450' , ' VIEW SERVER STATE' )
300304;
301305
302306-- Top queries
@@ -3293,6 +3297,59 @@ FROM packed_high_compilation_snapshot
32933297HAVING COUNT (1 ) > 0
32943298;
32953299
3300+ -- Local storage quota
3301+ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1450 ) AND execute_indicator = 1 )
3302+
3303+ WITH
3304+ local_storage AS
3305+ (
3306+ SELECT database_id,
3307+ DB_NAME (database_id) AS database_name ,
3308+ SUM (IIF (file_id <> 2 , size_on_disk_bytes, 0 )) / 1024 . / 1024 AS data_size_on_disk_mb,
3309+ SUM (IIF (file_id = 2 , size_on_disk_bytes, 0 )) / 1024 . / 1024 AS log_size_on_disk_mb
3310+ FROM sys .dm_io_virtual_file_stats (default , default )
3311+ GROUP BY database_id
3312+ ),
3313+ local_storage_agg AS
3314+ (
3315+ SELECT STRING_AGG (
3316+ CAST (CONCAT (
3317+ ' database (id: ' , database_id,
3318+ ' , name: ' + QUOTENAME (database_name ), -- database name is only available for current database and system databases, include for usability if available
3319+ ' ), DATA: ' , FORMAT (data_size_on_disk_mb, ' #,0.00' ),
3320+ ' , LOG: ' , FORMAT (log_size_on_disk_mb, ' #,0.00' )
3321+ ) AS nvarchar (max )), @CRLF
3322+ )
3323+ AS storage_summary
3324+ FROM local_storage
3325+ ),
3326+ local_storage_quota AS
3327+ (
3328+ SELECT rg .user_data_directory_space_quota_mb ,
3329+ rg .user_data_directory_space_usage_mb ,
3330+ rg .user_data_directory_space_usage_mb * 1 . / rg .user_data_directory_space_quota_mb AS quota_usage,
3331+ lsa .storage_summary
3332+ FROM local_storage_agg AS lsa
3333+ CROSS JOIN sys .dm_user_db_resource_governance AS rg
3334+ WHERE rg .database_id = DB_ID ()
3335+ AND
3336+ DATABASEPROPERTYEX (DB_NAME (), ' Edition' ) IN (' Premium' ,' BusinessCritical' ) -- not relevant for remote storage SLOs
3337+ )
3338+ INSERT INTO @DetectedTip (tip_id, details)
3339+ SELECT 1450 AS tip_id,
3340+ CONCAT (
3341+ @NbspCRLF,
3342+ ' Maximum local storage (MB): ' , FORMAT (user_data_directory_space_quota_mb, ' #,0.00' ), @CRLF,
3343+ ' Allocated local storage (MB): ' , FORMAT (user_data_directory_space_usage_mb, ' #,0.00' ), @CRLF,
3344+ ' Local storage usage (%): ' , FORMAT (quota_usage, ' P' ),
3345+ @CRLF, @CRLF,
3346+ ' Allocated local storage per database (MB):' , @CRLF,
3347+ storage_summary, @CRLF
3348+ )
3349+ AS details
3350+ FROM local_storage_quota
3351+ WHERE quota_usage > @MinLocalStorageQuotaUsageRatio;
3352+
32963353END ; -- end tips requiring VIEW SERVER STATE
32973354
32983355-- Return detected tips
0 commit comments