From fcc230a78ae991f4190821a3d0f9db0b0e14420c Mon Sep 17 00:00:00 2001 From: Eitan Blumin Date: Mon, 8 Jan 2024 09:52:34 +0200 Subject: [PATCH] added index-level details --- ...what could slow down SHRINK operations.sql | 24 ++++++++++++++++--- 1 file changed, 21 insertions(+), 3 deletions(-) diff --git a/Utility Scripts/Find what could slow down SHRINK operations.sql b/Utility Scripts/Find what could slow down SHRINK operations.sql index a2b63b5..bf5da46 100644 --- a/Utility Scripts/Find what could slow down SHRINK operations.sql +++ b/Utility Scripts/Find what could slow down SHRINK operations.sql @@ -14,12 +14,24 @@ DECLARE @TableSizeThresholdMB INT = 500 +DECLARE @RebuildOptions nvarchar(max) = N''; + +IF ISNULL(CONVERT(int, SERVERPROPERTY('EngineEdition')),0) IN (3,5,8) +BEGIN + SET @RebuildOptions = N' WITH (ONLINE=ON)' +END +ELSE +BEGIN + SET @RebuildOptions = N'' +END + ;WITH TabsCTE AS ( SELECT DISTINCT 'Table with LOB or ROW-OVERFLOW data' AS Issue, p.object_id + ,p.index_id FROM sys.system_internals_allocation_units au JOIN sys.partitions p ON au.container_id = p.partition_id WHERE type_desc <> 'IN_ROW_DATA' AND total_pages > 8 @@ -30,6 +42,7 @@ UNION ALL SELECT 'Heap with Non-clustered indexes', p.object_id + ,p.index_id FROM sys.partitions AS p WHERE p.index_id = 0 AND p.rows > 0 @@ -40,6 +53,7 @@ UNION ALL SELECT DISTINCT 'Partitioned Heap', p.object_id + ,p.index_id FROM sys.partitions AS p WHERE p.index_id = 0 AND p.rows > 0 @@ -48,13 +62,17 @@ AND p.partition_number > 1 SELECT t.*, OBJECT_SCHEMA_NAME(t.object_id) table_schema, OBJECT_NAME(t.object_id) table_name, +ix.name AS index_name, SUM(p.rows) AS RowCounts, CAST(ROUND((SUM(a.used_pages) / 128.00), 2) AS NUMERIC(36, 2)) AS Used_MB, CAST(ROUND((SUM(a.total_pages) - SUM(a.used_pages)) / 128.00, 2) AS NUMERIC(36, 2)) AS Unused_MB, -CAST(ROUND((SUM(a.total_pages) / 128.00), 2) AS NUMERIC(36, 2)) AS Total_MB +CAST(ROUND((SUM(a.total_pages) / 128.00), 2) AS NUMERIC(36, 2)) AS Total_MB, +RebuildCmd = N'ALTER ' + ISNULL(N'INDEX ' + QUOTENAME(ix.name) + N' ON ', N'TABLE ') + QUOTENAME(OBJECT_SCHEMA_NAME(t.object_id)) + N'.' + QUOTENAME(OBJECT_NAME(t.object_id)) + N' REBUILD' + @RebuildOptions + N'; +GO' FROM TabsCTE AS t INNER JOIN sys.partitions p ON t.object_id = p.object_id INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id -GROUP BY t.Issue, t.object_id +LEFT JOIN sys.indexes AS ix ON t.index_id = ix.index_id AND t.object_id = ix.object_id +GROUP BY t.Issue, t.object_id, t.index_id, ix.name HAVING SUM(a.used_pages) / 128.00 >= @TableSizeThresholdMB -ORDER BY Used_MB DESC \ No newline at end of file +ORDER BY Used_MB ASC \ No newline at end of file