You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
(1, 1510, 'Most of the IDENTITY range is used', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1510', 'VIEW DATABASE STATE'),
316
322
(1, 1520, 'Most of the sequence range is used', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1520', 'VIEW DATABASE STATE'),
317
-
(1, 1530, 'Disabled or not trusted constraints found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1530', 'VIEW DATABASE STATE')
323
+
(1, 1530, 'Disabled or not trusted constraints found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1530', 'VIEW DATABASE STATE'),
324
+
(1, 1540, 'Page compression is ineffective for some indexes', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1540', 'VIEW SERVER STATE')
318
325
;
319
326
320
327
-- Top queries
@@ -2644,6 +2651,144 @@ BEGIN CATCH
2644
2651
THROW;
2645
2652
ENDCATCH;
2646
2653
2654
+
-- Page compression wasting CPU
2655
+
IFEXISTS (SELECT1FROM @TipDefinition WHERE tip_id IN (1540) AND execute_indicator =1)
2656
+
2657
+
BEGINTRY
2658
+
2659
+
WITH
2660
+
partition_size AS
2661
+
(
2662
+
SELECTp.object_id,
2663
+
p.index_id,
2664
+
p.partition_number,
2665
+
p.data_compression_desc,
2666
+
SUM(ps.used_page_count) *8/1024. AS total_partition_size_mb,
2667
+
SUM(ps.in_row_used_page_count) *8/1024. AS in_row_partition_size_mb,
2668
+
SUM(ps.row_overflow_used_page_count) *8/1024. AS row_overflow_partition_size_mb,
2669
+
SUM(ps.lob_used_page_count) *8/1024. AS lob_partition_size_mb
2670
+
FROMsys.partitionsAS p
2671
+
INNER JOINsys.dm_db_partition_statsAS ps
2672
+
ONp.partition_id=ps.partition_id
2673
+
AND
2674
+
p.object_id=ps.object_id
2675
+
AND
2676
+
p.index_id=ps.index_id
2677
+
GROUP BYp.object_id,
2678
+
p.index_id,
2679
+
p.partition_number,
2680
+
p.data_compression_desc
2681
+
),
2682
+
-- Look at index stats for each partition of an index
2683
+
partition_stats AS
2684
+
(
2685
+
SELECTo.object_id,
2686
+
i.nameAS index_name,
2687
+
i.type_descAS index_type,
2688
+
p.partition_number,
2689
+
p.total_partition_size_mb,
2690
+
p.in_row_partition_size_mb,
2691
+
p.row_overflow_partition_size_mb,
2692
+
p.lob_partition_size_mb,
2693
+
SUM(p.total_partition_size_mb) OVER (PARTITIONBYo.object_id) AS object_size_mb,
2694
+
p.partition_number-ROW_NUMBER() OVER (
2695
+
PARTITIONBYo.object_id, i.name
2696
+
ORDER BYp.partition_number
2697
+
)
2698
+
AS interval_group, -- used to pack contiguous partition intervals for the same object and index
2699
+
ios.page_compression_attempt_count,
2700
+
ios.page_compression_success_count
2701
+
FROMsys.objectsAS o
2702
+
INNER JOINsys.indexesAS i
2703
+
ONo.object_id=i.object_id
2704
+
INNER JOIN partition_size AS p
2705
+
ONi.object_id=p.object_id
2706
+
AND
2707
+
i.index_id=p.index_id
2708
+
CROSSAPPLYsys.dm_db_index_operational_stats(DB_ID(), o.object_id, i.index_id, p.partition_number) AS ios -- assumption: a representative workload has populated index operational stats
(1, 1510, 'Most of the IDENTITY range is used', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1510', 'VIEW DATABASE STATE'),
304
310
(1, 1520, 'Most of the sequence range is used', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1520', 'VIEW DATABASE STATE'),
305
-
(1, 1530, 'Disabled or not trusted constraints found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1530', 'VIEW DATABASE STATE')
311
+
(1, 1530, 'Disabled or not trusted constraints found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1530', 'VIEW DATABASE STATE'),
312
+
(1, 1540, 'Page compression is ineffective for some indexes', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1540', 'VIEW SERVER STATE')
306
313
;
307
314
308
315
-- Top queries
@@ -2640,6 +2647,145 @@ BEGIN CATCH
2640
2647
THROW;
2641
2648
ENDCATCH;
2642
2649
2650
+
-- Page compression wasting CPU
2651
+
IFEXISTS (SELECT1FROM @TipDefinition WHERE tip_id IN (1540) AND execute_indicator =1)
2652
+
2653
+
BEGINTRY
2654
+
2655
+
WITH
2656
+
partition_size AS
2657
+
(
2658
+
SELECTp.object_id,
2659
+
p.index_id,
2660
+
p.partition_number,
2661
+
p.data_compression_desc,
2662
+
SUM(ps.used_page_count) *8/1024. AS total_partition_size_mb,
2663
+
SUM(ps.in_row_used_page_count) *8/1024. AS in_row_partition_size_mb,
2664
+
SUM(ps.row_overflow_used_page_count) *8/1024. AS row_overflow_partition_size_mb,
2665
+
SUM(ps.lob_used_page_count) *8/1024. AS lob_partition_size_mb
2666
+
FROMsys.partitionsAS p
2667
+
INNER JOINsys.dm_db_partition_statsAS ps
2668
+
ONp.partition_id=ps.partition_id
2669
+
AND
2670
+
p.object_id=ps.object_id
2671
+
AND
2672
+
p.index_id=ps.index_id
2673
+
GROUP BYp.object_id,
2674
+
p.index_id,
2675
+
p.partition_number,
2676
+
p.data_compression_desc
2677
+
),
2678
+
-- Look at index stats for each partition of an index
2679
+
partition_stats AS
2680
+
(
2681
+
SELECTo.object_id,
2682
+
i.nameAS index_name,
2683
+
i.type_descAS index_type,
2684
+
p.partition_number,
2685
+
p.total_partition_size_mb,
2686
+
p.in_row_partition_size_mb,
2687
+
p.row_overflow_partition_size_mb,
2688
+
p.lob_partition_size_mb,
2689
+
SUM(p.total_partition_size_mb) OVER (PARTITIONBYo.object_id) AS object_size_mb,
2690
+
p.partition_number-ROW_NUMBER() OVER (
2691
+
PARTITIONBYo.object_id, i.name
2692
+
ORDER BYp.partition_number
2693
+
)
2694
+
AS interval_group, -- used to pack contiguous partition intervals for the same object and index
2695
+
ios.page_compression_attempt_count,
2696
+
ios.page_compression_success_count
2697
+
FROMsys.objectsAS o
2698
+
INNER JOINsys.indexesAS i
2699
+
ONo.object_id=i.object_id
2700
+
INNER JOIN partition_size AS p
2701
+
ONi.object_id=p.object_id
2702
+
AND
2703
+
i.index_id=p.index_id
2704
+
CROSSAPPLYsys.dm_db_index_operational_stats(DB_ID(), o.object_id, i.index_id, p.partition_number) AS ios -- assumption: a representative workload has populated index operational stats
0 commit comments