forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
sp_BlitzIndex.sql
4384 lines (4080 loc) · 241 KB
/
sp_BlitzIndex.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
SET ANSI_NULLS ON;
SET ANSI_PADDING ON;
SET ANSI_WARNINGS ON;
SET ARITHABORT ON;
SET CONCAT_NULL_YIELDS_NULL ON;
SET QUOTED_IDENTIFIER ON;
SET STATISTICS IO OFF;
SET STATISTICS TIME OFF;
GO
IF OBJECT_ID('dbo.sp_BlitzIndex') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_BlitzIndex AS RETURN 0;');
GO
ALTER PROCEDURE dbo.sp_BlitzIndex
@DatabaseName NVARCHAR(128) = NULL, /*Defaults to current DB if not specified*/
@SchemaName NVARCHAR(128) = NULL, /*Requires table_name as well.*/
@TableName NVARCHAR(128) = NULL, /*Requires schema_name as well.*/
@Mode TINYINT=0, /*0=Diagnose, 1=Summarize, 2=Index Usage Detail, 3=Missing Index Detail, 4=Diagnose Details*/
/*Note:@Mode doesn't matter if you're specifying schema_name and @TableName.*/
@Filter TINYINT = 0, /* 0=no filter (default). 1=No low-usage warnings for objects with 0 reads. 2=Only warn for objects >= 500MB */
/*Note:@Filter doesn't do anything unless @Mode=0*/
@SkipPartitions BIT = 0,
@SkipStatistics BIT = 1,
@GetAllDatabases BIT = 0,
@BringThePain BIT = 0,
@ThresholdMB INT = 250 /* Number of megabytes that an object must be before we include it in basic results */,
@OutputServerName NVARCHAR(256) = NULL ,
@OutputDatabaseName NVARCHAR(256) = NULL ,
@OutputSchemaName NVARCHAR(256) = NULL ,
@OutputTableName NVARCHAR(256) = NULL ,
@Help TINYINT = 0,
@VersionDate DATETIME = NULL OUTPUT
WITH RECOMPILE
AS
SET NOCOUNT ON;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @Version VARCHAR(30);
SET @Version = '6.3';
SET @VersionDate = '20180301';
IF @Help = 1 PRINT '
/*
sp_BlitzIndex from http://FirstResponderKit.org
This script analyzes the design and performance of your indexes.
To learn more, visit http://FirstResponderKit.org where you can download new
versions for free, watch training videos on how it works, get more info on
the findings, contribute your own code, and more.
Known limitations of this version:
- Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000.
- The @OutputDatabaseName parameters are not functional yet. To check the
status of this enhancement request, visit:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/issues/221
- Does not analyze columnstore, spatial, XML, or full text indexes. If you
would like to contribute code to analyze those, head over to Github and
check out the issues list: http://FirstResponderKit.org
- Index create statements are just to give you a rough idea of the syntax. It includes filters and fillfactor.
-- Example 1: index creates use ONLINE=? instead of ONLINE=ON / ONLINE=OFF. This is because it is important
for the user to understand if it is going to be offline and not just run a script.
-- Example 2: they do not include all the options the index may have been created with (padding, compression
filegroup/partition scheme etc.)
-- (The compression and filegroup index create syntax is not trivial because it is set at the partition
level and is not trivial to code.)
- Does not advise you about data modeling for clustered indexes and primary keys (primarily looks for signs of insanity.)
Unknown limitations of this version:
- We knew them once, but we forgot.
Changes - for the full list of improvements and fixes in this version, see:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/milestone/4?closed=1
MIT License
Copyright (c) 2016 Brent Ozar Unlimited
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.
';
DECLARE @ScriptVersionName NVARCHAR(50);
DECLARE @DaysUptime NUMERIC(23,2);
DECLARE @DatabaseID INT;
DECLARE @ObjectID INT;
DECLARE @dsql NVARCHAR(MAX);
DECLARE @params NVARCHAR(MAX);
DECLARE @msg NVARCHAR(4000);
DECLARE @ErrorSeverity INT;
DECLARE @ErrorState INT;
DECLARE @Rowcount BIGINT;
DECLARE @SQLServerProductVersion NVARCHAR(128);
DECLARE @SQLServerEdition INT;
DECLARE @FilterMB INT;
DECLARE @collation NVARCHAR(256);
DECLARE @NumDatabases INT;
DECLARE @LineFeed NVARCHAR(5);
SET @LineFeed = CHAR(13) + CHAR(10);
SELECT @SQLServerProductVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128));
SELECT @SQLServerEdition =CAST(SERVERPROPERTY('EngineEdition') AS INT); /* We default to online index creates where EngineEdition=3*/
SET @FilterMB=250;
SELECT @ScriptVersionName = 'sp_BlitzIndex(TM) v' + @Version + ' - ' + DATENAME(MM, @VersionDate) + ' ' + RIGHT('0'+DATENAME(DD, @VersionDate),2) + ', ' + DATENAME(YY, @VersionDate);
RAISERROR(N'Starting run. %s', 0,1, @ScriptVersionName) WITH NOWAIT;
IF OBJECT_ID('tempdb..#IndexSanity') IS NOT NULL
DROP TABLE #IndexSanity;
IF OBJECT_ID('tempdb..#IndexPartitionSanity') IS NOT NULL
DROP TABLE #IndexPartitionSanity;
IF OBJECT_ID('tempdb..#IndexSanitySize') IS NOT NULL
DROP TABLE #IndexSanitySize;
IF OBJECT_ID('tempdb..#IndexColumns') IS NOT NULL
DROP TABLE #IndexColumns;
IF OBJECT_ID('tempdb..#MissingIndexes') IS NOT NULL
DROP TABLE #MissingIndexes;
IF OBJECT_ID('tempdb..#ForeignKeys') IS NOT NULL
DROP TABLE #ForeignKeys;
IF OBJECT_ID('tempdb..#BlitzIndexResults') IS NOT NULL
DROP TABLE #BlitzIndexResults;
IF OBJECT_ID('tempdb..#IndexCreateTsql') IS NOT NULL
DROP TABLE #IndexCreateTsql;
IF OBJECT_ID('tempdb..#DatabaseList') IS NOT NULL
DROP TABLE #DatabaseList;
IF OBJECT_ID('tempdb..#Statistics') IS NOT NULL
DROP TABLE #Statistics;
IF OBJECT_ID('tempdb..#PartitionCompressionInfo') IS NOT NULL
DROP TABLE #PartitionCompressionInfo;
IF OBJECT_ID('tempdb..#ComputedColumns') IS NOT NULL
DROP TABLE #ComputedColumns;
IF OBJECT_ID('tempdb..#TraceStatus') IS NOT NULL
DROP TABLE #TraceStatus;
IF OBJECT_ID('tempdb..#TemporalTables') IS NOT NULL
DROP TABLE #TemporalTables;
RAISERROR (N'Create temp tables.',0,1) WITH NOWAIT;
CREATE TABLE #BlitzIndexResults
(
blitz_result_id INT IDENTITY PRIMARY KEY,
check_id INT NOT NULL,
index_sanity_id INT NULL,
Priority INT NULL,
findings_group VARCHAR(4000) NOT NULL,
finding VARCHAR(200) NOT NULL,
[database_name] VARCHAR(200) NULL,
URL VARCHAR(200) NOT NULL,
details NVARCHAR(MAX) NOT NULL,
index_definition NVARCHAR(MAX) NOT NULL,
secret_columns NVARCHAR(MAX) NULL,
index_usage_summary NVARCHAR(MAX) NULL,
index_size_summary NVARCHAR(MAX) NULL,
create_tsql NVARCHAR(MAX) NULL,
more_info NVARCHAR(MAX)NULL
);
CREATE TABLE #IndexSanity
(
[index_sanity_id] INT IDENTITY PRIMARY KEY CLUSTERED,
[database_id] SMALLINT NOT NULL ,
[object_id] INT NOT NULL ,
[index_id] INT NOT NULL ,
[index_type] TINYINT NOT NULL,
[database_name] NVARCHAR(128) NOT NULL ,
[schema_name] NVARCHAR(128) NOT NULL ,
[object_name] NVARCHAR(128) NOT NULL ,
index_name NVARCHAR(128) NULL ,
key_column_names NVARCHAR(MAX) NULL ,
key_column_names_with_sort_order NVARCHAR(MAX) NULL ,
key_column_names_with_sort_order_no_types NVARCHAR(MAX) NULL ,
count_key_columns INT NULL ,
include_column_names NVARCHAR(MAX) NULL ,
include_column_names_no_types NVARCHAR(MAX) NULL ,
count_included_columns INT NULL ,
partition_key_column_name NVARCHAR(MAX) NULL,
filter_definition NVARCHAR(MAX) NOT NULL ,
is_indexed_view BIT NOT NULL ,
is_unique BIT NOT NULL ,
is_primary_key BIT NOT NULL ,
is_XML BIT NOT NULL,
is_spatial BIT NOT NULL,
is_NC_columnstore BIT NOT NULL,
is_CX_columnstore BIT NOT NULL,
is_disabled BIT NOT NULL ,
is_hypothetical BIT NOT NULL ,
is_padded BIT NOT NULL ,
fill_factor SMALLINT NOT NULL ,
user_seeks BIGINT NOT NULL ,
user_scans BIGINT NOT NULL ,
user_lookups BIGINT NOT NULL ,
user_updates BIGINT NULL ,
last_user_seek DATETIME NULL ,
last_user_scan DATETIME NULL ,
last_user_lookup DATETIME NULL ,
last_user_update DATETIME NULL ,
is_referenced_by_foreign_key BIT DEFAULT(0),
secret_columns NVARCHAR(MAX) NULL,
count_secret_columns INT NULL,
create_date DATETIME NOT NULL,
modify_date DATETIME NOT NULL,
[db_schema_object_name] AS [schema_name] + '.' + [object_name] ,
[db_schema_object_indexid] AS [schema_name] + '.' + [object_name]
+ CASE WHEN [index_name] IS NOT NULL THEN '.' + index_name
ELSE ''
END + ' (' + CAST(index_id AS NVARCHAR(20)) + ')' ,
first_key_column_name AS CASE WHEN count_key_columns > 1
THEN LEFT(key_column_names, CHARINDEX(',', key_column_names, 0) - 1)
ELSE key_column_names
END ,
index_definition AS
CASE WHEN partition_key_column_name IS NOT NULL
THEN N'[PARTITIONED BY:' + partition_key_column_name + N']'
ELSE ''
END +
CASE index_id
WHEN 0 THEN N'[HEAP] '
WHEN 1 THEN N'[CX] '
ELSE N'' END + CASE WHEN is_indexed_view = 1 THEN '[VIEW] '
ELSE N'' END + CASE WHEN is_primary_key = 1 THEN N'[PK] '
ELSE N'' END + CASE WHEN is_XML = 1 THEN N'[XML] '
ELSE N'' END + CASE WHEN is_spatial = 1 THEN N'[SPATIAL] '
ELSE N'' END + CASE WHEN is_NC_columnstore = 1 THEN N'[COLUMNSTORE] '
ELSE N'' END + CASE WHEN is_disabled = 1 THEN N'[DISABLED] '
ELSE N'' END + CASE WHEN is_hypothetical = 1 THEN N'[HYPOTHETICAL] '
ELSE N'' END + CASE WHEN is_unique = 1 AND is_primary_key = 0 THEN N'[UNIQUE] '
ELSE N'' END + CASE WHEN count_key_columns > 0 THEN
N'[' + CAST(count_key_columns AS VARCHAR(10)) + N' KEY'
+ CASE WHEN count_key_columns > 1 THEN N'S' ELSE N'' END
+ N'] ' + LTRIM(key_column_names_with_sort_order)
ELSE N'' END + CASE WHEN count_included_columns > 0 THEN
N' [' + CAST(count_included_columns AS VARCHAR(10)) + N' INCLUDE' +
+ CASE WHEN count_included_columns > 1 THEN N'S' ELSE N'' END
+ N'] ' + include_column_names
ELSE N'' END + CASE WHEN filter_definition <> N'' THEN N' [FILTER] ' + filter_definition
ELSE N'' END ,
[total_reads] AS user_seeks + user_scans + user_lookups,
[reads_per_write] AS CAST(CASE WHEN user_updates > 0
THEN ( user_seeks + user_scans + user_lookups ) / (1.0 * user_updates)
ELSE 0 END AS MONEY) ,
[index_usage_summary] AS N'Reads: ' +
REPLACE(CONVERT(NVARCHAR(30),CAST((user_seeks + user_scans + user_lookups) AS MONEY), 1), '.00', '')
+ CASE WHEN user_seeks + user_scans + user_lookups > 0 THEN
N' ('
+ RTRIM(
CASE WHEN user_seeks > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_seeks) AS MONEY), 1), '.00', '') + N' seek ' ELSE N'' END
+ CASE WHEN user_scans > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_scans) AS MONEY), 1), '.00', '') + N' scan ' ELSE N'' END
+ CASE WHEN user_lookups > 0 THEN REPLACE(CONVERT(NVARCHAR(30),CAST((user_lookups) AS MONEY), 1), '.00', '') + N' lookup' ELSE N'' END
)
+ N') '
ELSE N' ' END
+ N'Writes:' +
REPLACE(CONVERT(NVARCHAR(30),CAST(user_updates AS MONEY), 1), '.00', ''),
[more_info] AS N'EXEC dbo.sp_BlitzIndex @DatabaseName=' + QUOTENAME([database_name],'''') +
N', @SchemaName=' + QUOTENAME([schema_name],'''') + N', @TableName=' + QUOTENAME([object_name],'''') + N';'
);
RAISERROR (N'Adding UQ index on #IndexSanity (database_id, object_id, index_id)',0,1) WITH NOWAIT;
IF NOT EXISTS(SELECT 1 FROM tempdb.sys.indexes WHERE name='uq_database_id_object_id_index_id')
CREATE UNIQUE INDEX uq_database_id_object_id_index_id ON #IndexSanity (database_id, object_id, index_id);
CREATE TABLE #IndexPartitionSanity
(
[index_partition_sanity_id] INT IDENTITY,
[index_sanity_id] INT NULL ,
[database_id] INT NOT NULL ,
[object_id] INT NOT NULL ,
[schema_name] NVARCHAR(128) NOT NULL,
[index_id] INT NOT NULL ,
[partition_number] INT NOT NULL ,
row_count BIGINT NOT NULL ,
reserved_MB NUMERIC(29,2) NOT NULL ,
reserved_LOB_MB NUMERIC(29,2) NOT NULL ,
reserved_row_overflow_MB NUMERIC(29,2) NOT NULL ,
leaf_insert_count BIGINT NULL ,
leaf_delete_count BIGINT NULL ,
leaf_update_count BIGINT NULL ,
range_scan_count BIGINT NULL ,
singleton_lookup_count BIGINT NULL ,
forwarded_fetch_count BIGINT NULL ,
lob_fetch_in_pages BIGINT NULL ,
lob_fetch_in_bytes BIGINT NULL ,
row_overflow_fetch_in_pages BIGINT NULL ,
row_overflow_fetch_in_bytes BIGINT NULL ,
row_lock_count BIGINT NULL ,
row_lock_wait_count BIGINT NULL ,
row_lock_wait_in_ms BIGINT NULL ,
page_lock_count BIGINT NULL ,
page_lock_wait_count BIGINT NULL ,
page_lock_wait_in_ms BIGINT NULL ,
index_lock_promotion_attempt_count BIGINT NULL ,
index_lock_promotion_count BIGINT NULL,
data_compression_desc VARCHAR(60) NULL
);
CREATE TABLE #IndexSanitySize
(
[index_sanity_size_id] INT IDENTITY NOT NULL ,
[index_sanity_id] INT NULL ,
[database_id] INT NOT NULL,
[schema_name] NVARCHAR(128) NOT NULL,
partition_count INT NOT NULL ,
total_rows BIGINT NOT NULL ,
total_reserved_MB NUMERIC(29,2) NOT NULL ,
total_reserved_LOB_MB NUMERIC(29,2) NOT NULL ,
total_reserved_row_overflow_MB NUMERIC(29,2) NOT NULL ,
total_leaf_delete_count BIGINT NULL,
total_leaf_update_count BIGINT NULL,
total_range_scan_count BIGINT NULL,
total_singleton_lookup_count BIGINT NULL,
total_forwarded_fetch_count BIGINT NULL,
total_row_lock_count BIGINT NULL ,
total_row_lock_wait_count BIGINT NULL ,
total_row_lock_wait_in_ms BIGINT NULL ,
avg_row_lock_wait_in_ms BIGINT NULL ,
total_page_lock_count BIGINT NULL ,
total_page_lock_wait_count BIGINT NULL ,
total_page_lock_wait_in_ms BIGINT NULL ,
avg_page_lock_wait_in_ms BIGINT NULL ,
total_index_lock_promotion_attempt_count BIGINT NULL ,
total_index_lock_promotion_count BIGINT NULL ,
data_compression_desc VARCHAR(8000) NULL,
index_size_summary AS ISNULL(
CASE WHEN partition_count > 1
THEN N'[' + CAST(partition_count AS NVARCHAR(10)) + N' PARTITIONS] '
ELSE N''
END + REPLACE(CONVERT(NVARCHAR(30),CAST([total_rows] AS MONEY), 1), N'.00', N'') + N' rows; '
+ CASE WHEN total_reserved_MB > 1024 THEN
CAST(CAST(total_reserved_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB'
ELSE
CAST(CAST(total_reserved_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB'
END
+ CASE WHEN total_reserved_LOB_MB > 1024 THEN
N'; ' + CAST(CAST(total_reserved_LOB_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB LOB'
WHEN total_reserved_LOB_MB > 0 THEN
N'; ' + CAST(CAST(total_reserved_LOB_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB LOB'
ELSE ''
END
+ CASE WHEN total_reserved_row_overflow_MB > 1024 THEN
N'; ' + CAST(CAST(total_reserved_row_overflow_MB/1024. AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'GB Row Overflow'
WHEN total_reserved_row_overflow_MB > 0 THEN
N'; ' + CAST(CAST(total_reserved_row_overflow_MB AS NUMERIC(29,1)) AS NVARCHAR(30)) + N'MB Row Overflow'
ELSE ''
END ,
N'Error- NULL in computed column'),
index_op_stats AS ISNULL(
(
REPLACE(CONVERT(NVARCHAR(30),CAST(total_singleton_lookup_count AS MONEY), 1),N'.00',N'') + N' singleton lookups; '
+ REPLACE(CONVERT(NVARCHAR(30),CAST(total_range_scan_count AS MONEY), 1),N'.00',N'') + N' scans/seeks; '
+ REPLACE(CONVERT(NVARCHAR(30),CAST(total_leaf_delete_count AS MONEY), 1),N'.00',N'') + N' deletes; '
+ REPLACE(CONVERT(NVARCHAR(30),CAST(total_leaf_update_count AS MONEY), 1),N'.00',N'') + N' updates; '
+ CASE WHEN ISNULL(total_forwarded_fetch_count,0) >0 THEN
REPLACE(CONVERT(NVARCHAR(30),CAST(total_forwarded_fetch_count AS MONEY), 1),N'.00',N'') + N' forward records fetched; '
ELSE N'' END
/* rows will only be in this dmv when data is in memory for the table */
), N'Table metadata not in memory'),
index_lock_wait_summary AS ISNULL(
CASE WHEN total_row_lock_wait_count = 0 AND total_page_lock_wait_count = 0 AND
total_index_lock_promotion_attempt_count = 0 THEN N'0 lock waits.'
ELSE
CASE WHEN total_row_lock_wait_count > 0 THEN
N'Row lock waits: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_row_lock_wait_count AS MONEY), 1), N'.00', N'')
+ N'; total duration: ' +
CASE WHEN total_row_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/
REPLACE(CONVERT(NVARCHAR(30),CAST((total_row_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; '
ELSE
REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_row_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; '
END
+ N'avg duration: ' +
CASE WHEN avg_row_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/
REPLACE(CONVERT(NVARCHAR(30),CAST((avg_row_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; '
ELSE
REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(avg_row_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; '
END
ELSE N''
END +
CASE WHEN total_page_lock_wait_count > 0 THEN
N'Page lock waits: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_page_lock_wait_count AS MONEY), 1), N'.00', N'')
+ N'; total duration: ' +
CASE WHEN total_page_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/
REPLACE(CONVERT(NVARCHAR(30),CAST((total_page_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; '
ELSE
REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_page_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; '
END
+ N'avg duration: ' +
CASE WHEN avg_page_lock_wait_in_ms >= 60000 THEN /*More than 1 min*/
REPLACE(CONVERT(NVARCHAR(30),CAST((avg_page_lock_wait_in_ms/60000) AS MONEY), 1), N'.00', N'') + N' minutes; '
ELSE
REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(avg_page_lock_wait_in_ms/1000,0) AS MONEY), 1), N'.00', N'') + N' seconds; '
END
ELSE N''
END +
CASE WHEN total_index_lock_promotion_attempt_count > 0 THEN
N'Lock escalation attempts: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(total_index_lock_promotion_attempt_count AS MONEY), 1), N'.00', N'')
+ N'; Actual Escalations: ' + REPLACE(CONVERT(NVARCHAR(30),CAST(ISNULL(total_index_lock_promotion_count,0) AS MONEY), 1), N'.00', N'') + N'.'
ELSE N''
END
END
,'Error- NULL in computed column')
);
CREATE TABLE #IndexColumns
(
[database_id] INT NOT NULL,
[schema_name] NVARCHAR(128),
[object_id] INT NOT NULL ,
[index_id] INT NOT NULL ,
[key_ordinal] INT NULL ,
is_included_column BIT NULL ,
is_descending_key BIT NULL ,
[partition_ordinal] INT NULL ,
column_name NVARCHAR(256) NOT NULL ,
system_type_name NVARCHAR(256) NOT NULL,
max_length SMALLINT NOT NULL,
[precision] TINYINT NOT NULL,
[scale] TINYINT NOT NULL,
collation_name NVARCHAR(256) NULL,
is_nullable BIT NULL,
is_identity BIT NULL,
is_computed BIT NULL,
is_replicated BIT NULL,
is_sparse BIT NULL,
is_filestream BIT NULL,
seed_value BIGINT NULL,
increment_value INT NULL ,
last_value BIGINT NULL,
is_not_for_replication BIT NULL
);
CREATE CLUSTERED INDEX CLIX_database_id_object_id_index_id ON #IndexColumns
(database_id, object_id, index_id);
CREATE TABLE #MissingIndexes
([database_id] INT NOT NULL,
[object_id] INT NOT NULL,
[database_name] NVARCHAR(128) NOT NULL ,
[schema_name] NVARCHAR(128) NOT NULL ,
[table_name] NVARCHAR(128),
[statement] NVARCHAR(512) NOT NULL,
magic_benefit_number AS (( user_seeks + user_scans ) * avg_total_user_cost * avg_user_impact),
avg_total_user_cost NUMERIC(29,4) NOT NULL,
avg_user_impact NUMERIC(29,1) NOT NULL,
user_seeks BIGINT NOT NULL,
user_scans BIGINT NOT NULL,
unique_compiles BIGINT NULL,
equality_columns NVARCHAR(4000),
inequality_columns NVARCHAR(4000),
included_columns NVARCHAR(4000),
is_low BIT,
[index_estimated_impact] AS
REPLACE(CONVERT(NVARCHAR(256),CAST(CAST(
(user_seeks + user_scans)
AS BIGINT) AS MONEY), 1), '.00', '') + N' use'
+ CASE WHEN (user_seeks + user_scans) > 1 THEN N's' ELSE N'' END
+N'; Impact: ' + CAST(avg_user_impact AS NVARCHAR(30))
+ N'%; Avg query cost: '
+ CAST(avg_total_user_cost AS NVARCHAR(30)),
[missing_index_details] AS
CASE WHEN equality_columns IS NOT NULL THEN N'EQUALITY: ' + equality_columns + N' '
ELSE N''
END + CASE WHEN inequality_columns IS NOT NULL THEN N'INEQUALITY: ' + inequality_columns + N' '
ELSE N''
END + CASE WHEN included_columns IS NOT NULL THEN N'INCLUDES: ' + included_columns + N' '
ELSE N''
END,
[create_tsql] AS N'CREATE INDEX [ix_' + table_name + N'_'
+ REPLACE(REPLACE(REPLACE(REPLACE(
ISNULL(equality_columns,N'')+
CASE WHEN equality_columns IS NOT NULL AND inequality_columns IS NOT NULL THEN N'_' ELSE N'' END
+ ISNULL(inequality_columns,''),',','')
,'[',''),']',''),' ','_')
+ CASE WHEN included_columns IS NOT NULL THEN N'_includes' ELSE N'' END + N'] ON '
+ [statement] + N' (' + ISNULL(equality_columns,N'')
+ CASE WHEN equality_columns IS NOT NULL AND inequality_columns IS NOT NULL THEN N', ' ELSE N'' END
+ CASE WHEN inequality_columns IS NOT NULL THEN inequality_columns ELSE N'' END +
') ' + CASE WHEN included_columns IS NOT NULL THEN N' INCLUDE (' + included_columns + N')' ELSE N'' END
+ N' WITH ('
+ N'FILLFACTOR=100, ONLINE=?, SORT_IN_TEMPDB=?, DATA_COMPRESSION=?'
+ N')'
+ N';'
,
[more_info] AS N'EXEC dbo.sp_BlitzIndex @DatabaseName=' + QUOTENAME([database_name],'''') +
N', @SchemaName=' + QUOTENAME([schema_name],'''') + N', @TableName=' + QUOTENAME([table_name],'''') + N';'
);
CREATE TABLE #ForeignKeys (
[database_id] INT NOT NULL,
[database_name] NVARCHAR(128) NOT NULL ,
[schema_name] NVARCHAR(128) NOT NULL ,
foreign_key_name NVARCHAR(256),
parent_object_id INT,
parent_object_name NVARCHAR(256),
referenced_object_id INT,
referenced_object_name NVARCHAR(256),
is_disabled BIT,
is_not_trusted BIT,
is_not_for_replication BIT,
parent_fk_columns NVARCHAR(MAX),
referenced_fk_columns NVARCHAR(MAX),
update_referential_action_desc NVARCHAR(16),
delete_referential_action_desc NVARCHAR(60)
);
CREATE TABLE #IndexCreateTsql (
index_sanity_id INT NOT NULL,
create_tsql NVARCHAR(MAX) NOT NULL
);
CREATE TABLE #DatabaseList (
DatabaseName NVARCHAR(256),
secondary_role_allow_connections_desc NVARCHAR(50)
);
CREATE TABLE #PartitionCompressionInfo (
[index_sanity_id] INT NULL,
[partition_compression_detail] VARCHAR(8000) NULL
);
CREATE TABLE #Statistics (
database_id INT NOT NULL,
database_name NVARCHAR(256) NOT NULL,
table_name NVARCHAR(128) NULL,
schema_name NVARCHAR(128) NULL,
index_name NVARCHAR(128) NULL,
column_names NVARCHAR(4000) NULL,
statistics_name NVARCHAR(128) NULL,
last_statistics_update DATETIME NULL,
days_since_last_stats_update INT NULL,
rows BIGINT NULL,
rows_sampled BIGINT NULL,
percent_sampled DECIMAL(18, 1) NULL,
histogram_steps INT NULL,
modification_counter BIGINT NULL,
percent_modifications DECIMAL(18, 1) NULL,
modifications_before_auto_update INT NULL,
index_type_desc NVARCHAR(128) NULL,
table_create_date DATETIME NULL,
table_modify_date DATETIME NULL,
no_recompute BIT NULL,
has_filter BIT NULL,
filter_definition NVARCHAR(MAX) NULL
);
CREATE TABLE #ComputedColumns
(
index_sanity_id INT IDENTITY(1, 1) NOT NULL,
database_name NVARCHAR(128) NULL,
database_id INT NOT NULL,
table_name NVARCHAR(128) NOT NULL,
schema_name NVARCHAR(128) NOT NULL,
column_name NVARCHAR(128) NULL,
is_nullable BIT NULL,
definition NVARCHAR(MAX) NULL,
uses_database_collation BIT NOT NULL,
is_persisted BIT NOT NULL,
is_computed BIT NOT NULL,
is_function INT NOT NULL,
column_definition NVARCHAR(MAX) NULL
);
CREATE TABLE #TraceStatus
(
TraceFlag VARCHAR(10) ,
status BIT ,
Global BIT ,
Session BIT
);
CREATE TABLE #TemporalTables
(
index_sanity_id INT IDENTITY(1, 1) NOT NULL,
database_name NVARCHAR(128) NOT NULL,
database_id INT NOT NULL,
schema_name NVARCHAR(128) NOT NULL,
table_name NVARCHAR(128) NOT NULL,
history_table_name NVARCHAR(128) NOT NULL,
history_schema_name NVARCHAR(128) NOT NULL,
start_column_name NVARCHAR(128) NOT NULL,
end_column_name NVARCHAR(128) NOT NULL,
period_name NVARCHAR(128) NOT NULL
);
/* Sanitize our inputs */
SELECT
@OutputServerName = QUOTENAME(@OutputServerName),
@OutputDatabaseName = QUOTENAME(@OutputDatabaseName),
@OutputSchemaName = QUOTENAME(@OutputSchemaName),
@OutputTableName = QUOTENAME(@OutputTableName);
IF @GetAllDatabases = 1
BEGIN
INSERT INTO #DatabaseList (DatabaseName)
SELECT DB_NAME(database_id)
FROM sys.databases
WHERE user_access_desc='MULTI_USER'
AND state_desc = 'ONLINE'
AND database_id > 4
AND DB_NAME(database_id) NOT LIKE 'ReportServer%'
AND is_distributor = 0;
/* Skip non-readable databases in an AG - see Github issue #1160 */
IF EXISTS (SELECT * FROM sys.all_objects o INNER JOIN sys.all_columns c ON o.object_id = c.object_id AND o.name = 'dm_hadr_availability_replica_states' AND c.name = 'role_desc')
BEGIN
SET @dsql = N'UPDATE #DatabaseList SET secondary_role_allow_connections_desc = ''NO'' WHERE DatabaseName IN (
SELECT d.name
FROM sys.dm_hadr_availability_replica_states rs
INNER JOIN sys.databases d ON rs.replica_id = d.replica_id
INNER JOIN sys.availability_replicas r ON rs.replica_id = r.replica_id
WHERE rs.role_desc = ''SECONDARY''
AND r.secondary_role_allow_connections_desc = ''NO'');';
EXEC sp_executesql @dsql;
IF EXISTS (SELECT * FROM #DatabaseList WHERE secondary_role_allow_connections_desc = 'NO')
BEGIN
INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, database_name, URL, details, index_definition,
index_usage_summary, index_size_summary )
VALUES ( 1, 0 ,
N'Skipped non-readable AG secondary databases.',
N'You are running this on an AG secondary, and some of your databases are configured as non-readable when this is a secondary node.',
N'To analyze those databases, run sp_BlitzIndex on the primary, or on a readable secondary.',
'http://FirstResponderKit.org', '', '', '', ''
);
END;
END;
END;
ELSE
BEGIN
INSERT INTO #DatabaseList
( DatabaseName )
SELECT CASE WHEN @DatabaseName IS NULL OR @DatabaseName = N'' THEN DB_NAME()
ELSE @DatabaseName END;
END;
SET @NumDatabases = @@ROWCOUNT;
/* Running on 50+ databases can take a reaaallly long time, so we want explicit permission to do so (and only after warning about it) */
BEGIN TRY
IF @NumDatabases >= 50 AND @BringThePain != 1
BEGIN
INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, URL, details, index_definition,
index_usage_summary, index_size_summary )
VALUES ( -1, 0 ,
@ScriptVersionName,
CASE WHEN @GetAllDatabases = 1 THEN N'All Databases' ELSE N'Database ' + QUOTENAME(@DatabaseName) + N' as of ' + CONVERT(NVARCHAR(16),GETDATE(),121) END,
N'From Your Community Volunteers' , N'http://www.BrentOzar.com/BlitzIndex' ,
N''
, N'',N''
);
INSERT #BlitzIndexResults ( Priority, check_id, findings_group, finding, database_name, URL, details, index_definition,
index_usage_summary, index_size_summary )
VALUES ( 1, 0 ,
N'You''re trying to run sp_BlitzIndex on a server with ' + CAST(@NumDatabases AS NVARCHAR(8)) + N' databases. ',
N'Running sp_BlitzIndex on a server with 50+ databases may cause temporary insanity for the server and/or user.',
N'If you''re sure you want to do this, run again with the parameter @BringThePain = 1.',
'http://FirstResponderKit.org', '', '', '', ''
);
SELECT bir.blitz_result_id,
bir.check_id,
bir.index_sanity_id,
bir.Priority,
bir.findings_group,
bir.finding,
bir.database_name,
bir.URL,
bir.details,
bir.index_definition,
bir.secret_columns,
bir.index_usage_summary,
bir.index_size_summary,
bir.create_tsql,
bir.more_info
FROM #BlitzIndexResults AS bir;
RETURN;
END;
END TRY
BEGIN CATCH
RAISERROR (N'Failure to execute due to number of databases.', 0,1) WITH NOWAIT;
SELECT @msg = ERROR_MESSAGE(), @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE();
RAISERROR (@msg,
@ErrorSeverity,
@ErrorState
);
WHILE @@trancount > 0
ROLLBACK;
RETURN;
END CATCH;
/* Permission granted or unnecessary? Ok, let's go! */
DECLARE c1 CURSOR
LOCAL FAST_FORWARD
FOR
SELECT DatabaseName FROM #DatabaseList WHERE COALESCE(secondary_role_allow_connections_desc, 'OK') <> 'NO' ORDER BY DatabaseName;
OPEN c1;
FETCH NEXT FROM c1 INTO @DatabaseName;
WHILE @@FETCH_STATUS = 0
BEGIN
RAISERROR (@LineFeed, 0, 1) WITH NOWAIT;
RAISERROR (@LineFeed, 0, 1) WITH NOWAIT;
RAISERROR (@DatabaseName, 0, 1) WITH NOWAIT;
SELECT @DatabaseID = [database_id]
FROM sys.databases
WHERE [name] = @DatabaseName
AND user_access_desc='MULTI_USER'
AND state_desc = 'ONLINE';
/* Last startup */
SELECT @DaysUptime = CAST(DATEDIFF(hh,create_date,GETDATE())/24. AS NUMERIC (23,2))
FROM sys.databases
WHERE database_id = 2;
IF @DaysUptime = 0 SET @DaysUptime = .01;
----------------------------------------
--STEP 1: OBSERVE THE PATIENT
--This step puts index information into temp tables.
----------------------------------------
BEGIN TRY
BEGIN
--Validate SQL Server Verson
IF (SELECT LEFT(@SQLServerProductVersion,
CHARINDEX('.',@SQLServerProductVersion,0)-1
)) <= 9
BEGIN
SET @msg=N'sp_BlitzIndex is only supported on SQL Server 2008 and higher. The version of this instance is: ' + @SQLServerProductVersion;
RAISERROR(@msg,16,1);
END;
--Short circuit here if database name does not exist.
IF @DatabaseName IS NULL OR @DatabaseID IS NULL
BEGIN
SET @msg='Database does not exist or is not online/multi-user: cannot proceed.';
RAISERROR(@msg,16,1);
END;
--Validate parameters.
IF (@Mode NOT IN (0,1,2,3,4))
BEGIN
SET @msg=N'Invalid @Mode parameter. 0=diagnose, 1=summarize, 2=index detail, 3=missing index detail, 4=diagnose detail';
RAISERROR(@msg,16,1);
END;
IF (@Mode <> 0 AND @TableName IS NOT NULL)
BEGIN
SET @msg=N'Setting the @Mode doesn''t change behavior if you supply @TableName. Use default @Mode=0 to see table detail.';
RAISERROR(@msg,16,1);
END;
IF ((@Mode <> 0 OR @TableName IS NOT NULL) AND @Filter <> 0)
BEGIN
SET @msg=N'@Filter only appies when @Mode=0 and @TableName is not specified. Please try again.';
RAISERROR(@msg,16,1);
END;
IF (@SchemaName IS NOT NULL AND @TableName IS NULL)
BEGIN
SET @msg='We can''t run against a whole schema! Specify a @TableName, or leave both NULL for diagnosis.';
RAISERROR(@msg,16,1);
END;
IF (@TableName IS NOT NULL AND @SchemaName IS NULL)
BEGIN
SET @SchemaName=N'dbo';
SET @msg='@SchemaName wasn''t specified-- assuming schema=dbo.';
RAISERROR(@msg,1,1) WITH NOWAIT;
END;
--If a table is specified, grab the object id.
--Short circuit if it doesn't exist.
IF @TableName IS NOT NULL
BEGIN
SET @dsql = N'
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT @ObjectID= OBJECT_ID
FROM ' + QUOTENAME(@DatabaseName) + N'.sys.objects AS so
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.schemas AS sc on
so.schema_id=sc.schema_id
where so.type in (''U'', ''V'')
and so.name=' + QUOTENAME(@TableName,'''')+ N'
and sc.name=' + QUOTENAME(@SchemaName,'''')+ N'
/*Has a row in sys.indexes. This lets us get indexed views.*/
and exists (
SELECT si.name
FROM ' + QUOTENAME(@DatabaseName) + '.sys.indexes AS si
WHERE so.object_id=si.object_id)
OPTION (RECOMPILE);';
SET @params='@ObjectID INT OUTPUT';
IF @dsql IS NULL
RAISERROR('@dsql is null',16,1);
EXEC sp_executesql @dsql, @params, @ObjectID=@ObjectID OUTPUT;
IF @ObjectID IS NULL
BEGIN
SET @msg=N'Oh, this is awkward. I can''t find the table or indexed view you''re looking for in that database.' + CHAR(10) +
N'Please check your parameters.';
RAISERROR(@msg,1,1);
RETURN;
END;
END;
--set @collation
SELECT @collation=collation_name
FROM sys.databases
WHERE database_id=@DatabaseID;
--insert columns for clustered indexes and heaps
--collect info on identity columns for this one
SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT ' + CAST(@DatabaseID AS NVARCHAR(16)) + ',
s.name,
si.object_id,
si.index_id,
sc.key_ordinal,
sc.is_included_column,
sc.is_descending_key,
sc.partition_ordinal,
c.name as column_name,
st.name as system_type_name,
c.max_length,
c.[precision],
c.[scale],
c.collation_name,
c.is_nullable,
c.is_identity,
c.is_computed,
c.is_replicated,
' + CASE WHEN @SQLServerProductVersion NOT LIKE '9%' THEN N'c.is_sparse' ELSE N'NULL as is_sparse' END + N',
' + CASE WHEN @SQLServerProductVersion NOT LIKE '9%' THEN N'c.is_filestream' ELSE N'NULL as is_filestream' END + N',
CAST(ic.seed_value AS BIGINT),
CAST(ic.increment_value AS INT),
CAST(ic.last_value AS BIGINT),
ic.is_not_for_replication
FROM ' + QUOTENAME(@DatabaseName) + N'.sys.indexes si
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.columns c ON
si.object_id=c.object_id
LEFT JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.index_columns sc ON
sc.object_id = si.object_id
and sc.index_id=si.index_id
AND sc.column_id=c.column_id
LEFT JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.identity_columns ic ON
c.object_id=ic.object_id and
c.column_id=ic.column_id
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.types st ON
c.system_type_id=st.system_type_id
AND c.user_type_id=st.user_type_id
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.objects AS so ON si.object_id = so.object_id
AND so.is_ms_shipped = 0
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.schemas AS s ON s.schema_id = so.schema_id
WHERE si.index_id in (0,1) '
+ CASE WHEN @ObjectID IS NOT NULL
THEN N' AND si.object_id=' + CAST(@ObjectID AS NVARCHAR(30))
ELSE N'' END
+ N'OPTION (RECOMPILE);';
IF @dsql IS NULL
RAISERROR('@dsql is null',16,1);
RAISERROR (N'Inserting data into #IndexColumns for clustered indexes and heaps',0,1) WITH NOWAIT;
INSERT #IndexColumns ( database_id, [schema_name], [object_id], index_id, key_ordinal, is_included_column, is_descending_key, partition_ordinal,
column_name, system_type_name, max_length, precision, scale, collation_name, is_nullable, is_identity, is_computed,
is_replicated, is_sparse, is_filestream, seed_value, increment_value, last_value, is_not_for_replication )
EXEC sp_executesql @dsql;
--insert columns for nonclustered indexes
--this uses a full join to sys.index_columns
--We don't collect info on identity columns here. They may be in NC indexes, but we just analyze identities in the base table.
SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT ' + CAST(@DatabaseID AS NVARCHAR(16)) + ',
s.name,
si.object_id,
si.index_id,
sc.key_ordinal,
sc.is_included_column,
sc.is_descending_key,
sc.partition_ordinal,
c.name as column_name,
st.name as system_type_name,
c.max_length,
c.[precision],
c.[scale],
c.collation_name,
c.is_nullable,
c.is_identity,
c.is_computed,
c.is_replicated,
' + CASE WHEN @SQLServerProductVersion NOT LIKE '9%' THEN N'c.is_sparse' ELSE N'NULL AS is_sparse' END + N',
' + CASE WHEN @SQLServerProductVersion NOT LIKE '9%' THEN N'c.is_filestream' ELSE N'NULL AS is_filestream' END + N'
FROM ' + QUOTENAME(@DatabaseName) + N'.sys.indexes AS si
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.columns AS c ON
si.object_id=c.object_id
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.index_columns AS sc ON
sc.object_id = si.object_id
and sc.index_id=si.index_id
AND sc.column_id=c.column_id
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.types AS st ON
c.system_type_id=st.system_type_id
AND c.user_type_id=st.user_type_id
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.objects AS so ON si.object_id = so.object_id
AND so.is_ms_shipped = 0
JOIN ' + QUOTENAME(@DatabaseName) + N'.sys.schemas AS s ON s.schema_id = so.schema_id
WHERE si.index_id not in (0,1) '
+ CASE WHEN @ObjectID IS NOT NULL
THEN N' AND si.object_id=' + CAST(@ObjectID AS NVARCHAR(30))
ELSE N'' END
+ N'OPTION (RECOMPILE);';
IF @dsql IS NULL
RAISERROR('@dsql is null',16,1);
RAISERROR (N'Inserting data into #IndexColumns for nonclustered indexes',0,1) WITH NOWAIT;
INSERT #IndexColumns ( database_id, [schema_name], [object_id], index_id, key_ordinal, is_included_column, is_descending_key, partition_ordinal,
column_name, system_type_name, max_length, precision, scale, collation_name, is_nullable, is_identity, is_computed,
is_replicated, is_sparse, is_filestream )
EXEC sp_executesql @dsql;
SET @dsql = N'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT ' + CAST(@DatabaseID AS NVARCHAR(10)) + ' AS database_id,
so.object_id,
si.index_id,
si.type,
' + QUOTENAME(@DatabaseName, '''') + ' AS database_name,
COALESCE(sc.NAME, ''Unknown'') AS [schema_name],
COALESCE(so.name, ''Unknown'') AS [object_name],
COALESCE(si.name, ''Unknown'') AS [index_name],
CASE WHEN so.[type] = CAST(''V'' AS CHAR(2)) THEN 1 ELSE 0 END,
si.is_unique,
si.is_primary_key,
CASE when si.type = 3 THEN 1 ELSE 0 END AS is_XML,
CASE when si.type = 4 THEN 1 ELSE 0 END AS is_spatial,
CASE when si.type = 6 THEN 1 ELSE 0 END AS is_NC_columnstore,
CASE when si.type = 5 then 1 else 0 end as is_CX_columnstore,
si.is_disabled,
si.is_hypothetical,
si.is_padded,
si.fill_factor,'
+ CASE WHEN @SQLServerProductVersion NOT LIKE '9%' THEN '
CASE WHEN si.filter_definition IS NOT NULL THEN si.filter_definition
ELSE ''''
END AS filter_definition' ELSE ''''' AS filter_definition' END + '
, ISNULL(us.user_seeks, 0), ISNULL(us.user_scans, 0),
ISNULL(us.user_lookups, 0), ISNULL(us.user_updates, 0), us.last_user_seek, us.last_user_scan,
us.last_user_lookup, us.last_user_update,
so.create_date, so.modify_date
FROM ' + QUOTENAME(@DatabaseName) + '.sys.indexes AS si WITH (NOLOCK)
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.objects AS so WITH (NOLOCK) ON si.object_id = so.object_id
AND so.is_ms_shipped = 0 /*Exclude objects shipped by Microsoft*/
AND so.type <> ''TF'' /*Exclude table valued functions*/