|
72 | 72 | SET NOCOUNT ON; |
73 | 73 | BEGIN TRY |
74 | 74 | SELECT |
75 | | - @version = '1.6', |
76 | | - @version_date = '20250601'; |
| 75 | + @version = '1.11', |
| 76 | + @version_date = '20251114'; |
77 | 77 |
|
78 | 78 | IF |
79 | 79 | /* Check SQL Server 2012+ for FORMAT and CONCAT functions */ |
@@ -438,10 +438,13 @@ WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. |
438 | 438 | index_id integer NOT NULL, |
439 | 439 | index_name sysname NOT NULL, |
440 | 440 | can_compress bit NOT NULL |
441 | | - INDEX filtered_objects CLUSTERED |
442 | | - (database_id, schema_id, object_id, index_id) |
443 | 441 | ); |
444 | 442 |
|
| 443 | + CREATE CLUSTERED INDEX |
| 444 | + filtered_objects |
| 445 | + ON #filtered_objects |
| 446 | + (database_id, schema_id, object_id, index_id); |
| 447 | + |
445 | 448 | CREATE TABLE |
446 | 449 | #operational_stats |
447 | 450 | ( |
@@ -584,10 +587,13 @@ WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. |
584 | 587 | superseded_by nvarchar(4000) NULL, |
585 | 588 | /* Priority score from 0-1 to determine which index to keep (higher is better) */ |
586 | 589 | index_priority decimal(10,6) NULL |
587 | | - INDEX index_analysis CLUSTERED |
588 | | - (database_id, schema_id, object_id, index_id) |
589 | 590 | ); |
590 | 591 |
|
| 592 | + CREATE CLUSTERED INDEX |
| 593 | + index_analysis |
| 594 | + ON #index_analysis |
| 595 | + (database_id, schema_id, object_id, index_id); |
| 596 | + |
591 | 597 | CREATE TABLE |
592 | 598 | #compression_eligibility |
593 | 599 | ( |
@@ -782,11 +788,14 @@ WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. |
782 | 788 | index_name sysname NULL, |
783 | 789 | filter_definition nvarchar(max) NULL, |
784 | 790 | missing_included_columns nvarchar(max) NULL, |
785 | | - should_include_filter_columns bit NOT NULL, |
786 | | - INDEX c CLUSTERED |
787 | | - (database_id, schema_id, object_id, index_id) |
| 791 | + should_include_filter_columns bit NOT NULL |
788 | 792 | ); |
789 | 793 |
|
| 794 | + CREATE CLUSTERED INDEX |
| 795 | + c |
| 796 | + ON #filtered_index_columns_analysis |
| 797 | + (database_id, schema_id, object_id, index_id); |
| 798 | + |
790 | 799 | /* Parse @include_databases comma-separated list */ |
791 | 800 | IF @get_all_databases = 1 |
792 | 801 | AND @include_databases IS NOT NULL |
@@ -2719,6 +2728,13 @@ WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. |
2719 | 2728 | AND id.user_scans > 0 |
2720 | 2729 | ) THEN 100 ELSE 0 |
2721 | 2730 | END /* Indexes with scans get some priority */ |
| 2731 | + + |
| 2732 | + CASE |
| 2733 | + WHEN #index_analysis.included_columns IS NOT NULL |
| 2734 | + AND LEN(#index_analysis.included_columns) > 0 |
| 2735 | + THEN 50 /* Indexes with includes get priority over those without */ |
| 2736 | + ELSE 0 |
| 2737 | + END /* Prefer indexes with included columns */ |
2722 | 2738 | OPTION(RECOMPILE); |
2723 | 2739 |
|
2724 | 2740 | IF @debug = 1 |
@@ -3736,6 +3752,115 @@ WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. |
3736 | 3752 | WHERE ia.index_name = kdd.winning_index_name |
3737 | 3753 | OPTION(RECOMPILE); |
3738 | 3754 |
|
| 3755 | + /* Merge all included columns from Key Duplicate indexes into the winning index */ |
| 3756 | + IF @debug = 1 |
| 3757 | + BEGIN |
| 3758 | + RAISERROR('Merging included columns from Key Duplicate indexes', 0, 0) WITH NOWAIT; |
| 3759 | + END; |
| 3760 | + |
| 3761 | + WITH |
| 3762 | + KeyDuplicateIncludes AS |
| 3763 | + ( |
| 3764 | + SELECT |
| 3765 | + winner.database_id, |
| 3766 | + winner.object_id, |
| 3767 | + winner.index_id, |
| 3768 | + winner.index_name, |
| 3769 | + winner.included_columns AS winner_includes, |
| 3770 | + loser.included_columns AS loser_includes |
| 3771 | + FROM #index_analysis AS winner |
| 3772 | + JOIN #key_duplicate_dedupe AS kdd |
| 3773 | + ON winner.database_id = kdd.database_id |
| 3774 | + AND winner.object_id = kdd.object_id |
| 3775 | + AND winner.key_columns = kdd.base_key_columns |
| 3776 | + AND ISNULL(winner.filter_definition, '') = kdd.filter_definition |
| 3777 | + AND winner.index_name = kdd.winning_index_name |
| 3778 | + JOIN #index_analysis AS loser |
| 3779 | + ON loser.database_id = kdd.database_id |
| 3780 | + AND loser.object_id = kdd.object_id |
| 3781 | + AND loser.key_columns = kdd.base_key_columns |
| 3782 | + AND ISNULL(loser.filter_definition, '') = kdd.filter_definition |
| 3783 | + AND loser.index_name <> kdd.winning_index_name |
| 3784 | + AND loser.action = N'DISABLE' |
| 3785 | + AND loser.consolidation_rule = N'Key Duplicate' |
| 3786 | + WHERE winner.action = N'MERGE INCLUDES' |
| 3787 | + AND winner.consolidation_rule = N'Key Duplicate' |
| 3788 | + ) |
| 3789 | + UPDATE |
| 3790 | + ia |
| 3791 | + SET |
| 3792 | + ia.included_columns = |
| 3793 | + ( |
| 3794 | + SELECT |
| 3795 | + /* Combine all includes from winner and all losers, removing duplicates */ |
| 3796 | + combined_cols = |
| 3797 | + STUFF |
| 3798 | + ( |
| 3799 | + ( |
| 3800 | + SELECT DISTINCT |
| 3801 | + N', ' + |
| 3802 | + t.c.value('.', 'sysname') |
| 3803 | + FROM |
| 3804 | + ( |
| 3805 | + /* Create XML from winner's includes */ |
| 3806 | + SELECT |
| 3807 | + x = CONVERT |
| 3808 | + ( |
| 3809 | + xml, |
| 3810 | + N'<c>' + |
| 3811 | + REPLACE(ISNULL(kdi.winner_includes, N''), N', ', N'</c><c>') + |
| 3812 | + N'</c>' |
| 3813 | + ) |
| 3814 | + FROM KeyDuplicateIncludes AS kdi |
| 3815 | + WHERE kdi.database_id = ia.database_id |
| 3816 | + AND kdi.object_id = ia.object_id |
| 3817 | + AND kdi.index_id = ia.index_id |
| 3818 | + AND kdi.winner_includes IS NOT NULL |
| 3819 | + |
| 3820 | + UNION ALL |
| 3821 | + |
| 3822 | + /* Create XML from each loser's includes */ |
| 3823 | + SELECT |
| 3824 | + x = CONVERT |
| 3825 | + ( |
| 3826 | + xml, |
| 3827 | + N'<c>' + |
| 3828 | + REPLACE(kdi.loser_includes, N', ', N'</c><c>') + |
| 3829 | + N'</c>' |
| 3830 | + ) |
| 3831 | + FROM KeyDuplicateIncludes AS kdi |
| 3832 | + WHERE kdi.database_id = ia.database_id |
| 3833 | + AND kdi.object_id = ia.object_id |
| 3834 | + AND kdi.index_id = ia.index_id |
| 3835 | + AND kdi.loser_includes IS NOT NULL |
| 3836 | + ) AS a |
| 3837 | + /* Split XML into individual columns */ |
| 3838 | + CROSS APPLY a.x.nodes('/c') AS t(c) |
| 3839 | + /* Filter out empty strings that can result from NULL handling */ |
| 3840 | + WHERE LEN(t.c.value('.', 'sysname')) > 0 |
| 3841 | + FOR |
| 3842 | + XML |
| 3843 | + PATH('') |
| 3844 | + ), |
| 3845 | + 1, |
| 3846 | + 2, |
| 3847 | + '' |
| 3848 | + ) |
| 3849 | + ) |
| 3850 | + FROM #index_analysis AS ia |
| 3851 | + WHERE ia.action = N'MERGE INCLUDES' |
| 3852 | + AND ia.consolidation_rule = N'Key Duplicate' |
| 3853 | + AND EXISTS |
| 3854 | + ( |
| 3855 | + SELECT |
| 3856 | + 1/0 |
| 3857 | + FROM #key_duplicate_dedupe AS kdd |
| 3858 | + WHERE kdd.database_id = ia.database_id |
| 3859 | + AND kdd.object_id = ia.object_id |
| 3860 | + AND kdd.winning_index_name = ia.index_name |
| 3861 | + ) |
| 3862 | + OPTION(RECOMPILE); |
| 3863 | + |
3739 | 3864 | /* Find indexes with same key columns where one has includes that are a subset of another */ |
3740 | 3865 | IF @debug = 1 |
3741 | 3866 | BEGIN |
|
0 commit comments