From 2f77ec03ea9e597dddc4751d2c14b9f6daa18dcb Mon Sep 17 00:00:00 2001 From: Dimitri Furman Date: Thu, 10 Feb 2022 13:02:27 -0500 Subject: [PATCH 1/3] Added index rebuild statement to output for 1180 --- sqldb-tips/get-sqldb-tips-compat-level-100-only.sql | 8 +++++++- sqldb-tips/get-sqldb-tips.sql | 8 +++++++- 2 files changed, 14 insertions(+), 2 deletions(-) diff --git a/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql b/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql index c1aad35..35fcf5d 100644 --- a/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql +++ b/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql @@ -2620,7 +2620,13 @@ SELECT STRING_AGG( ', row overflow: ', FORMAT(partition_range_row_overflow_size_mb, 'N'), ', LOB: ', FORMAT(partition_range_lob_size_mb, 'N'), '), present compression type: ', present_compression_type, - ', suggested compression type: ', new_compression_type + ', suggested compression type: ', new_compression_type, + ', index rebuild statement: ', CONCAT( + 'ALTER INDEX ', index_name, ' ON ', schema_name, '.', object_name, + ' REBUILD', IIF(partition_range = '1-1', '', CONCAT(' PARTITION = <', partition_range, '>')), + ' WITH (', 'DATA_COMPRESSION = ', new_compression_type, ',', + ' ONLINE = ON (WAIT_AT_LOW_PRIORITY (MAX_DURATION = 15 MINUTES, ABORT_AFTER_WAIT = SELF)), RESUMABLE = ON);' + ) ) AS nvarchar(max)), @CRLF ) AS details diff --git a/sqldb-tips/get-sqldb-tips.sql b/sqldb-tips/get-sqldb-tips.sql index 7e6e2b5..b8bba0d 100644 --- a/sqldb-tips/get-sqldb-tips.sql +++ b/sqldb-tips/get-sqldb-tips.sql @@ -2615,7 +2615,13 @@ SELECT STRING_AGG( ', row overflow: ', FORMAT(partition_range_row_overflow_size_mb, 'N'), ', LOB: ', FORMAT(partition_range_lob_size_mb, 'N'), '), present compression type: ', present_compression_type, - ', suggested compression type: ', new_compression_type + ', suggested compression type: ', new_compression_type, + ', index rebuild statement: ', CONCAT( + 'ALTER INDEX ', index_name, ' ON ', schema_name, '.', object_name, + ' REBUILD', IIF(partition_range = '1-1', '', CONCAT(' PARTITION = <', partition_range, '>')), + ' WITH (', 'DATA_COMPRESSION = ', new_compression_type, ',', + ' ONLINE = ON (WAIT_AT_LOW_PRIORITY (MAX_DURATION = 15 MINUTES, ABORT_AFTER_WAIT = SELF)), RESUMABLE = ON);' + ) ) AS nvarchar(max)), @CRLF ) WITHIN GROUP (ORDER BY object_size_mb DESC, object_name, index_name, partition_range, partition_range_total_size_mb, new_compression_type) From 030ddaf6023368a7cd43d2f46d1bb982a8928d70 Mon Sep 17 00:00:00 2001 From: Dimitri Furman Date: Fri, 25 Mar 2022 18:34:58 -0400 Subject: [PATCH 2/3] Added execution timestamp to 1320 --- sqldb-tips/get-sqldb-tips-compat-level-100-only.sql | 1 + sqldb-tips/get-sqldb-tips.sql | 1 + 2 files changed, 2 insertions(+) diff --git a/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql b/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql index 35fcf5d..c47060f 100644 --- a/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql +++ b/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql @@ -580,6 +580,7 @@ SELECT 1320 AS tip_id, ', updateability: ', CAST(DATABASEPROPERTYEX(DB_NAME(), 'Updateability') AS nvarchar(10)), ', logical database GUID: ', rg.logical_database_guid, ', physical database GUID: ', rg.physical_database_guid, + ', script execution timestamp (UTC): ', CONVERT(varchar(20), SYSUTCDATETIME(), 120), @CRLF, @CRLF, STRING_AGG( CAST(CONCAT( diff --git a/sqldb-tips/get-sqldb-tips.sql b/sqldb-tips/get-sqldb-tips.sql index b8bba0d..803b7c4 100644 --- a/sqldb-tips/get-sqldb-tips.sql +++ b/sqldb-tips/get-sqldb-tips.sql @@ -569,6 +569,7 @@ SELECT 1320 AS tip_id, ', updateability: ', CAST(DATABASEPROPERTYEX(DB_NAME(), 'Updateability') AS nvarchar(10)), ', logical database GUID: ', rg.logical_database_guid, ', physical database GUID: ', rg.physical_database_guid, + ', script execution timestamp (UTC): ', CONVERT(varchar(20), SYSUTCDATETIME(), 120), @CRLF, @CRLF, STRING_AGG( CAST(CONCAT( From 588d02dcb427700a74a833cb922aa0ba51d6c515 Mon Sep 17 00:00:00 2001 From: Dimitri Furman Date: Wed, 4 May 2022 15:42:53 -0700 Subject: [PATCH 3/3] Fixed 1290 (CCI candidates) --- sqldb-tips/get-sqldb-tips-compat-level-100-only.sql | 6 +++--- sqldb-tips/get-sqldb-tips.sql | 6 +++--- 2 files changed, 6 insertions(+), 6 deletions(-) diff --git a/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql b/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql index c47060f..cade54d 100644 --- a/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql +++ b/sqldb-tips/get-sqldb-tips-compat-level-100-only.sql @@ -1019,7 +1019,7 @@ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1140) AND execute_indic WITH allocated_used_space AS ( SELECT SUM(CAST(size AS bigint) * 8 / 1024.) AS space_allocated_mb, - SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint)) / 1024. / 1024 AS space_used_mb + SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint)) * 8 / 1024. AS space_used_mb FROM sys.database_files WHERE type_desc = 'ROWS' ) @@ -1032,7 +1032,7 @@ SELECT 1140 AS tip_id, @CRLF ) FROM allocated_used_space -WHERE space_used_mb * 8 / 1024. > @UsedToAllocatedSpaceDbMinSizeMB -- not relevant for small databases +WHERE space_used_mb > @UsedToAllocatedSpaceDbMinSizeMB -- not relevant for small databases AND @UsedToAllocatedSpaceThresholdRatio * space_allocated_mb > space_used_mb -- allocated space is more than N times used space AND @@ -3437,7 +3437,7 @@ ON t.object_id = ius.object_id i.index_id = ius.index_id WHERE i.type IN (0,1) -- clustered index or heap AND - tos.table_size_mb > @CCICandidateMinSizeGB / 1024. -- consider sufficiently large tables only + tos.table_size_mb > @CCICandidateMinSizeGB * 1024. -- consider sufficiently large tables only AND t.is_ms_shipped = 0 AND diff --git a/sqldb-tips/get-sqldb-tips.sql b/sqldb-tips/get-sqldb-tips.sql index 803b7c4..9562d84 100644 --- a/sqldb-tips/get-sqldb-tips.sql +++ b/sqldb-tips/get-sqldb-tips.sql @@ -1010,7 +1010,7 @@ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1140) AND execute_indic WITH allocated_used_space AS ( SELECT SUM(CAST(size AS bigint) * 8 / 1024.) AS space_allocated_mb, - SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint)) / 1024. / 1024 AS space_used_mb + SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint)) * 8 / 1024. AS space_used_mb FROM sys.database_files WHERE type_desc = 'ROWS' ) @@ -1023,7 +1023,7 @@ SELECT 1140 AS tip_id, @CRLF ) FROM allocated_used_space -WHERE space_used_mb * 8 / 1024. > @UsedToAllocatedSpaceDbMinSizeMB -- not relevant for small databases +WHERE space_used_mb > @UsedToAllocatedSpaceDbMinSizeMB -- not relevant for small databases AND @UsedToAllocatedSpaceThresholdRatio * space_allocated_mb > space_used_mb -- allocated space is more than N times used space AND @@ -3435,7 +3435,7 @@ ON t.object_id = ius.object_id i.index_id = ius.index_id WHERE i.type IN (0,1) -- clustered index or heap AND - tos.table_size_mb > @CCICandidateMinSizeGB / 1024. -- consider sufficiently large tables only + tos.table_size_mb > @CCICandidateMinSizeGB * 1024. -- consider sufficiently large tables only AND t.is_ms_shipped = 0 AND