forked from DavidWiseman/sqlserver-kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
dbo.sp_sizeoptimiser.sql
1367 lines (1233 loc) · 54.7 KB
/
dbo.sp_sizeoptimiser.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;
GO
SET QUOTED_IDENTIFIER ON;
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'Description' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'Description' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'Description' , N'SCHEMA',N'dbo', N'TYPE',N'SizeOptimiserTableType', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'Description' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TYPE',@level1name=N'SizeOptimiserTableType';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@SqlMinorVersion' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@SqlMinorVersion' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@SqlMajorVersion' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@SqlMajorVersion' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IndexNumThreshold' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@IndexNumThreshold' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IncludeDatabases' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@IncludeDatabases' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@ExcludeDatabases' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@ExcludeDatabases' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IncludeSysDatabases' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@IncludeSysDatabases' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IncludeSSRSDatabases' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@IncludeSSRSDatabases' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@Verbose' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@Verbose' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
IF EXISTS (SELECT * FROM sys.fn_listextendedproperty(N'@IsExpress' , N'SCHEMA',N'dbo', N'PROCEDURE',N'sp_sizeoptimiser', NULL,NULL))
BEGIN;
EXEC sys.sp_dropextendedproperty @name=N'@IsExpress' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_sizeoptimiser';
END
GO
/******************************/
/* Cleanup existing versions */
/******************************/
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[sp_sizeoptimiser]'))
BEGIN
DROP PROCEDURE [dbo].[sp_sizeoptimiser];
END;
IF EXISTS (SELECT * FROM sys.types st JOIN sys.schemas ss ON st.schema_id = ss.schema_id WHERE st.name = N'SizeOptimiserTableType' AND ss.name = N'dbo')
BEGIN
DROP TYPE [dbo].[SizeOptimiserTableType];
END;
GO
/**************************************************************/
/* Create user defined table type for database list parameter */
/**************************************************************/
IF NOT EXISTS (SELECT * FROM sys.types st JOIN sys.schemas ss ON st.schema_id = ss.schema_id WHERE st.name = N'SizeOptimiserTableType' AND ss.name = N'dbo')
BEGIN
CREATE TYPE [dbo].[SizeOptimiserTableType] AS TABLE(
[database_name] [sysname] NOT NULL,
PRIMARY KEY CLUSTERED ([database_name] ASC) WITH (IGNORE_DUP_KEY = OFF));
END;
GO
/***************************/
/* Create stored procedure */
/***************************/
IF NOT EXISTS(SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[sp_sizeoptimiser]'))
BEGIN
EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[sp_sizeoptimiser] AS';
END;
GO
ALTER PROCEDURE [dbo].[sp_sizeoptimiser]
@IndexNumThreshold SMALLINT = 10
,@IncludeDatabases [dbo].[SizeOptimiserTableType] READONLY
,@ExcludeDatabases [dbo].[SizeOptimiserTableType] READONLY
,@IncludeSysDatabases BIT = 0
,@IncludeSSRSDatabases BIT = 0
,@Verbose BIT = 1
/* Parameters defined here for testing only */
,@IsExpress BIT = NULL
,@SqlMajorVersion TINYINT = NULL
,@SqlMinorVersion SMALLINT = NULL
WITH RECOMPILE
AS
/*
sp_sizeoptimiser - Recommends space saving measures for data footprints.
Part of the DBA MultiTool http://dba-multitool.org
Version: 20201110
MIT License
Copyright (c) 2020 John McCall
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.
=========
Example:
DECLARE @include SizeOptimiserTableType;
INSERT INTO @include ([database_name])
VALUES (N'WideWorldImporters');
EXEC [dbo].[sp_sizeoptimiser] @IncludeDatabases = @include
*/
BEGIN
SET NOCOUNT ON;
BEGIN TRY
DECLARE @HasTempStat BIT = 0
,@HasPersistedSamplePercent BIT = 0
,@CheckNumber TINYINT = 0
,@EngineEdition TINYINT
,@CheckSQL NVARCHAR(MAX) = N''
,@Msg NVARCHAR(MAX) = N''
,@DbName SYSNAME = N''
,@TempCheckSQL NVARCHAR(MAX) = N''
,@BaseURL VARCHAR(1000) = 'http://dba-multitool.org/';
/* Validate @IndexNumThreshold */
IF (@IndexNumThreshold < 1 OR @IndexNumThreshold > 999)
BEGIN
SET @Msg = '@IndexNumThreshold must be between 1 and 999.';
RAISERROR(@Msg, 16, 1);
END
/* Validate database list */
IF (SELECT COUNT(*) FROM @IncludeDatabases) >= 1 AND (SELECT COUNT(*) FROM @ExcludeDatabases) >= 1
BEGIN
SET @Msg = 'Both @IncludeDatabases and @ExcludeDatabases cannot be specified.';
RAISERROR(@Msg, 16, 1);
END
CREATE TABLE #Databases (
[database_name] SYSNAME NOT NULL);
/* Build database list if no parameters set */
IF (SELECT COUNT(*) FROM @IncludeDatabases) = 0 AND (SELECT COUNT(*) FROM @ExcludeDatabases) = 0
BEGIN
INSERT INTO #Databases
SELECT [sd].[name]
FROM [sys].[databases] AS [sd]
WHERE ([sd].[database_id] > 4 OR @IncludeSysDatabases = 1)
AND ([sd].[name] NOT IN ('ReportServer', 'ReportServerTempDB') OR @IncludeSSRSDatabases = 1)
AND DATABASEPROPERTYEX([sd].[name], 'UPDATEABILITY') = N'READ_WRITE'
AND DATABASEPROPERTYEX([sd].[name], 'USERACCESS') = N'MULTI_USER'
AND DATABASEPROPERTYEX([sd].[name], 'STATUS') = N'ONLINE';
END;
/* Build database list from @IncludeDatabases */
ELSE IF (SELECT COUNT(*) FROM @IncludeDatabases) >= 1
BEGIN
INSERT INTO #Databases
SELECT [sd].[name]
FROM @IncludeDatabases AS [d]
INNER JOIN [sys].[databases] AS [sd] ON [sd].[name] COLLATE database_default = REPLACE(REPLACE([d].[database_name], '[', ''), ']', '')
WHERE DATABASEPROPERTYEX([sd].[name], 'UPDATEABILITY') = N'READ_WRITE'
AND DATABASEPROPERTYEX([sd].[name], 'USERACCESS') = N'MULTI_USER'
AND DATABASEPROPERTYEX([sd].[name], 'STATUS') = N'ONLINE';
IF (SELECT COUNT(*) FROM @IncludeDatabases) > (SELECT COUNT(*) FROM #Databases)
BEGIN
DECLARE @ErrorDatabaseList NVARCHAR(MAX);
WITH ErrorDatabase AS(
SELECT [database_name]
FROM @IncludeDatabases
EXCEPT
SELECT [database_name]
FROM #Databases)
SELECT @ErrorDatabaseList = ISNULL(@ErrorDatabaseList + N', ' + [database_name], [database_name])
FROM ErrorDatabase;
SET @Msg = 'Supplied databases do not exist or are not accessible: ' + @ErrorDatabaseList + '.';
RAISERROR(@Msg, 16, 1);
END;
END;
/* Build database list from @ExcludeDatabases */
ELSE IF (SELECT COUNT(*) FROM @ExcludeDatabases) >= 1
BEGIN
INSERT INTO #Databases
SELECT [sd].[name]
FROM [sys].[databases] AS [sd]
WHERE NOT EXISTS (SELECT [d].[database_name]
FROM @IncludeDatabases AS [d]
WHERE [sd].[name] COLLATE database_default = REPLACE(REPLACE([d].[database_name], '[', ''), ']', ''))
AND DATABASEPROPERTYEX([sd].[name], 'UPDATEABILITY') = N'READ_WRITE'
AND DATABASEPROPERTYEX([sd].[name], 'USERACCESS') = N'MULTI_USER'
AND DATABASEPROPERTYEX([sd].[name], 'STATUS') = N'ONLINE'
AND [sd].[name] <> 'tempdb';
END
/* Find edition */
IF (@IsExpress IS NULL AND CAST(SERVERPROPERTY('Edition') AS VARCHAR(50)) LIKE 'Express%')
BEGIN
SET @IsExpress = 1;
END;
ELSE IF (@IsExpress IS NULL)
BEGIN;
SET @IsExpress = 0;
END;
/* Find engine edition */
IF (@EngineEdition IS NULL)
BEGIN
SET @EngineEdition = CAST(SERVERPROPERTY('EditionEdition') AS TINYINT);
END;
/* Find Version */
IF (@SqlMajorVersion IS NULL)
BEGIN;
SET @SqlMajorVersion = CAST(SERVERPROPERTY('ProductMajorVersion') AS TINYINT);
END;
IF (@SqlMinorVersion IS NULL)
BEGIN;
SET @SqlMinorVersion = CAST(SERVERPROPERTY('ProductMinorVersion') AS SMALLINT);
END;
/* Validate Version */
IF (@SqlMajorVersion < 11)
BEGIN;
SET @Msg = 'SQL Server versions below 2012 are not supported, sorry!';
RAISERROR(@Msg, 16, 1);
END;
/* Check for is_temp value on statistics */
IF 1 = (SELECT 1 FROM [sys].[all_columns] AS [ac] WHERE [ac].[name] = 'is_temporary' AND OBJECT_NAME([ac].[object_id]) = 'all_columns')
BEGIN;
SET @HasTempStat = 1;
END;
/* Check for Persisted Sample Percent update */
IF 1 = (SELECT 1 FROM [sys].[all_columns] AS [ac] WHERE [ac].[name] = 'persisted_sample_percent' AND OBJECT_NAME([ac].[object_id]) = 'dm_db_stats_properties')
BEGIN;
SET @HasPersistedSamplePercent = 1;
END;
IF (@Verbose = 1)
BEGIN;
/* Print info */
SET @Msg = 'sp_sizeoptimiser';
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = '------------';
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = CONCAT('Time: ', GETDATE());
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = CONCAT('SQL Major Version: ', @SqlMajorVersion);
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = CONCAT('SQL Minor Version: ', @SqlMinorVersion);
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = CONCAT('Is Express Edition: ', @IsExpress);
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = CONCAT('Is feature "persisted sample percent" available: ', @HasPersistedSamplePercent);
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
SET @Msg = CONCAT(CHAR(13), CHAR(10));
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
/* Build temp tables */
IF OBJECT_ID(N'tempdb..#results') IS NOT NULL
BEGIN;
DROP TABLE #results;
END;
CREATE TABLE #results
([check_num] INT NOT NULL,
[check_type] NVARCHAR(50) NOT NULL,
[db_name] SYSNAME NOT NULL,
[obj_type] SYSNAME NOT NULL,
[obj_name] NVARCHAR(400) NOT NULL,
[col_name] SYSNAME NULL,
[message] NVARCHAR(500) NULL,
[ref_link] NVARCHAR(500) NULL);
IF OBJECT_ID('tempdb..#DuplicateIndex') IS NOT NULL
BEGIN;
DROP TABLE #DuplicateIndex;
END;
CREATE TABLE #DuplicateIndex
([check_type] NVARCHAR(50) NOT NULL
,[obj_type] SYSNAME NOT NULL
,[db_name] SYSNAME NOT NULL
,[obj_name] SYSNAME NOT NULL
,[col_name] SYSNAME NULL
,[message] NVARCHAR(500) NULL
,[object_id] INT NOT NULL
,[index_id] INT NOT NULL);
IF OBJECT_ID('tempdb..#OverlappingIndex') IS NOT NULL
BEGIN;
DROP TABLE #OverlappingIndex;
END;
CREATE TABLE #OverlappingIndex
([check_type] NVARCHAR(50) NOT NULL
,[obj_type] SYSNAME NOT NULL
,[db_name] SYSNAME NOT NULL
,[obj_name] SYSNAME NOT NULL
,[col_name] SYSNAME NULL
,[message] NVARCHAR(500) NULL
,[object_id] INT NOT NULL
,[index_id] INT NOT NULL);
/* Header row */
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N'Lets do this'
,N'Vroom vroom'
,N'beep boop'
,N'Off to the races'
,N'Ready set go'
,N'Thanks for using'
,@BaseURL;
/* Date & Time Data Type Usage */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Date and Time Data Types');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,N''USER_TABLE''
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME([t].[schema_id])) + ''.'' + QUOTENAME([t].[name])
,QUOTENAME([c].[name])
,N''Columns storing date or time should use a temporal specific data type, but this column is using '' + ty.name + ''.''
,CONCAT(@BaseURL COLLATE database_default, ''time-based-formats'')
FROM [sys].[columns] AS [c]
INNER JOIN [sys].[tables] AS [t] on [t].[object_id] = [c].[object_id]
INNER JOIN [sys].[types] AS [ty] on [ty].[user_type_id] = [c].[user_type_id]
WHERE [c].[is_identity] = 0 --exclude identity cols
AND [t].[is_ms_shipped] = 0 --exclude sys table
AND ([c].[name] LIKE ''%date%'' OR [c].[name] LIKE ''%time%'')
AND [c].[name] NOT LIKE ''%UpdatedBy%''
AND [c].[name] NOT LIKE ''%days%''
AND [ty].[name] NOT IN (''datetime'', ''datetime2'', ''datetimeoffset'', ''date'', ''smalldatetime'', ''time'');'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; --Date and Time Data Type Check
/* Archaic varchar Lengths (255/256) */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Archaic varchar Lengths');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N'; WITH archaic AS (
SELECT QUOTENAME(SCHEMA_NAME(t.schema_id)) + ''.'' + QUOTENAME(t.name) AS [obj_name]
,QUOTENAME(c.name) AS [col_name]
,N''Possible arbitrary variable length column in use. Is the '' + ty.name + N'' length of '' + CAST (c.max_length / 2 AS varchar(MAX)) + N'' based on requirements?'' AS [message]
,CONCAT(@BaseURL COLLATE database_default, ''arbitrary-varchar-length'') AS [ref_link]
FROM sys.columns c
INNER JOIN sys.tables as t on t.object_id = c.object_id
INNER JOIN sys.types as ty on ty.user_type_id = c.user_type_id
WHERE c.is_identity = 0 --exclude identity cols
AND t.is_ms_shipped = 0 --exclude sys table
AND ty.name = ''NVARCHAR''
AND c.max_length IN (510, 512)
UNION
SELECT QUOTENAME(SCHEMA_NAME(t.schema_id)) + ''.'' + QUOTENAME(t.name)
,QUOTENAME(c.name)
,N''Possible arbitrary variable length column in use. Is the '' + ty.name + N'' length of '' + CAST (c.max_length AS varchar(MAX)) + N'' based on requirements''
,CONCAT(@BaseURL COLLATE database_default, ''arbitrary-varchar-length'')
FROM sys.columns as c
INNER JOIN sys.tables as t on t.object_id = c.object_id
INNER JOIN sys.types as ty on ty.user_type_id = c.user_type_id
WHERE c.is_identity = 0 --exclude identity cols
AND t.is_ms_shipped = 0 --exclude sys table
AND ty.name = ''VARCHAR''
AND c.max_length IN (255, 256))
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,N''USER_TABLE''
,QUOTENAME(DB_NAME())
,[obj_name]
,[col_name]
,[message]
,[ref_link]
FROM [archaic];'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; --Archaic varchar Lengths
/* Unspecified VARCHAR Length */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber,' - Unspecified VARCHAR Length');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + ';
WITH UnspecifiedVarChar AS (
SELECT QUOTENAME(SCHEMA_NAME(t.schema_id)) + ''.'' + QUOTENAME(t.name) AS [obj_name]
,QUOTENAME(c.name) AS [col_name]
,N''VARCHAR column without specified length, it should not have a length of '' + CAST (c.max_length AS varchar(10)) + '''' AS [message]
,CONCAT(@BaseURL COLLATE database_default, ''unspecified-varchar-length'') AS [ref_link]
FROM sys.columns as c
INNER JOIN sys.tables as t on t.object_id = c.object_id
INNER JOIN sys.types as ty on ty.user_type_id = c.user_type_id
WHERE c.is_identity = 0 --exclude identity cols
AND t.is_ms_shipped = 0 --exclude sys table
AND ty.name IN (''VARCHAR'', ''NVARCHAR'')
AND c.max_length = 1)
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,N''USER_TABLE''
,QUOTENAME(DB_NAME())
,[obj_name]
,[col_name]
,[message]
,[ref_link]
FROM [UnspecifiedVarChar];'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; --Unspecified VARCHAR Length
/* Mad MAX - Varchar(MAX) */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Mad MAX VARCHAR');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,N''USER_TABLE''
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME(t.schema_id)) + ''.'' + QUOTENAME(t.name)
,QUOTENAME(c.name)
,N''Column is NVARCHAR(MAX) which allows very large row sizes. Consider a character limit.''
,CONCAT(@BaseURL COLLATE database_default, ''mad-varchar-max'')
FROM sys.columns as c
INNER JOIN sys.tables as t on t.object_id = c.object_id
INNER JOIN sys.types as ty on ty.user_type_id = c.user_type_id
WHERE t.is_ms_shipped = 0 --exclude sys table
AND ty.[name] = ''nvarchar''
AND c.max_length = -1;'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; --NVARCHAR MAX Check
/* NVARCHAR data type in Express */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Use of NVARCHAR (EXPRESS)');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
IF (@IsExpress = 1)
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,N''USER_TABLE''
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME([o].schema_id)) + ''.'' + QUOTENAME(OBJECT_NAME([o].object_id))
,QUOTENAME([ac].[name])
,N''nvarchar columns take 2x the space per char of varchar. Only use if you need Unicode characters.''
,CONCAT(@BaseURL COLLATE database_default, ''nvarchar-in-express'')
FROM [sys].[all_columns] AS [ac]
INNER JOIN [sys].[types] AS [t] ON [t].[user_type_id] = [ac].[user_type_id]
INNER JOIN [sys].[objects] AS [o] ON [o].object_id = [ac].object_id
WHERE [t].[name] = ''NVARCHAR''
AND [o].[is_ms_shipped] = 0'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; --NVARCHAR Use Check
ELSE IF (@Verbose = 1) --Skip check
BEGIN;
RAISERROR(' Skipping check, not Express...', 10, 1) WITH NOWAIT;
END; -- Skip check
END; --NVARCHAR Use Check
/* FLOAT and REAL data types */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg =CONCAT(N'Check ', @CheckNumber, ' - Use of FLOAT/REAL data types');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,[o].[type_desc]
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME([o].[schema_id])) + ''.'' + QUOTENAME([o].[name])
,QUOTENAME([ac].[name])
,N''Best practice is to use DECIMAL/NUMERIC instead of '' + UPPER([st].[name]) + '' for non floating point math.''
,CONCAT(@BaseURL COLLATE database_default, ''float-and-real-data-types'')
FROM [sys].[all_columns] AS [ac]
INNER JOIN [sys].[objects] AS [o] ON [o].[object_id] = [ac].[object_id]
INNER JOIN [sys].[systypes] AS [st] ON [st].[xtype] = [ac].[system_type_id]
WHERE [st].[name] IN (''FLOAT'', ''REAL'')
AND [o].[type_desc] = ''USER_TABLE'';'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- FLOAT/REAL Check
/* Deprecated data types (NTEXT, TEXT, IMAGE) */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Deprecated data types');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,[o].[type_desc]
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME(o.schema_id)) + ''.'' + QUOTENAME(o.name)
,QUOTENAME(ac.name)
,N''Deprecated data type in use: '' + st.name + ''.''
,CONCAT(@BaseURL COLLATE database_default, ''deprecated-data-types'')
FROM sys.all_columns AS ac
INNER JOIN sys.objects AS o ON o.object_id = ac.object_id
INNER JOIN sys.systypes AS st ON st.xtype = ac.system_type_id
WHERE st.name IN(''NEXT'', ''TEXT'', ''IMAGE'')
AND o.type_desc = ''USER_TABLE'';'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; --Don't use deprecated data types check
/* BIGINT for identity values in Express */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - BIGINT used for identity columns (EXPRESS)');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
IF (@IsExpress = 1)
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,N''USER_TABLE''
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME(t.schema_id)) + ''.'' + QUOTENAME(t.name)
,QUOTENAME(c.name)
,N''BIGINT used on IDENTITY column in SQL Express. If values will never exceed 2,147,483,647 use INT instead.''
,CONCAT(@BaseURL COLLATE database_default, ''bigint-as-identity'')
FROM sys.columns as c
INNER JOIN sys.tables as t on t.object_id = c.object_id
INNER JOIN sys.types as ty on ty.user_type_id = c.user_type_id
WHERE t.is_ms_shipped = 0 --exclude sys table
AND ty.name = ''BIGINT''
AND c.is_identity = 1;'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- BIGINT for identity Check
ELSE IF (@Verbose = 1) --Skip check
BEGIN
RAISERROR(' Skipping check, not Express...', 10, 1) WITH NOWAIT;
END; ----Skip check
END; -- BIGINT for identity Check
/* Numeric or decimal with 0 scale */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - NUMERIC or DECIMAL with scale of 0');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,[o].[type_desc]
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME(o.schema_id)) + ''.'' + QUOTENAME(o.name)
,QUOTENAME(ac.name)
,N''Column is '' + UPPER(st.name) + ''('' + CAST(ac.precision AS VARCHAR) + '','' + CAST(ac.scale AS VARCHAR) + '')''
+ '' . Consider using an INT variety for space reduction since the scale is 0.''
,CONCAT(@BaseURL COLLATE database_default, ''numeric-or-decimal-0-scale'')
FROM sys.objects AS o
INNER JOIN sys.all_columns AS ac ON ac.object_id = o.object_id
INNER JOIN sys.systypes AS st ON st.xtype = ac.system_type_id
WHERE ac.scale = 0
AND ac.precision < 19
AND st.name IN(''DECIMAL'', ''NUMERIC'')
AND o.is_ms_shipped = 0;'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- Numeric or decimal with 0 scale check
/* Enum columns not implemented as foreign key */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Enum columns not implemented as foreign key.');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Data Types''
,[o].[type_desc]
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME(o.schema_id)) + ''.'' + QUOTENAME(o.name)
,QUOTENAME(ac.name)
,N''Column is potentially an enum that should be a foreign key to a normalized table for data integrity, space savings, and performance.''
,CONCAT(@BaseURL COLLATE database_default, ''enum-column-not-implemented-as-foreign-key'')
FROM sys.objects AS o
INNER JOIN sys.all_columns AS ac ON ac.object_id = o.object_id
INNER JOIN sys.systypes AS st ON st.xtype = ac.system_type_id
WHERE (ac.[name] LIKE ''%Type'' OR ac.[name] LIKE ''%Status'')
AND o.is_ms_shipped = 0
AND [o].[type] = ''U''
AND st.[name] IN (''nvarchar'', ''varchar'', ''char'');'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- Enum columns not implemented as foreign key
/* User DB or model db Growth set past 10GB - ONLY IF EXPRESS */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Data file growth set past 10GB (EXPRESS)');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
IF (@IsExpress = 1)
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''File Growth''
,N''DATABASE''
,QUOTENAME(DB_NAME())
,QUOTENAME(DB_NAME(database_id))
,NULL
,N''Database file '' + name + '' has a maximum growth set to '' +
CASE
WHEN max_size = -1
THEN ''Unlimited''
WHEN max_size > 0
THEN CAST((max_size / 1024) * 8 AS VARCHAR(MAX))
END + '', which is over the user database maximum file size of 10GB.''
,CONCAT(@BaseURL COLLATE database_default, ''database-growth-past-10GB'')
FROM sys.master_files mf
WHERE (max_size > 1280000 OR max_size = -1) -- greater than 10GB or unlimited
AND [mf].[database_id] > 5
AND [mf].[data_space_id] > 0 -- limit doesn''t apply to log files;'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- User DB or model db Growth check
ELSE IF (@Verbose = 1) --Skip check
BEGIN;
RAISERROR(' Skipping check, not Express...', 10, 1) WITH NOWAIT;
END;
END; -- User DB or model db Growth check
/* User DB or model db growth set to % */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Data file growth set to percentage.');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
IF (@EngineEdition <> 5) --Not Azure SQL
BEGIN
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N'File Growth'
,N'DATABASE'
,QUOTENAME(DB_NAME([sd].[database_id]))
,[mf].[name]
,NULL
,N'Database file '+[mf].[name]+' has growth set to % instead of a fixed amount. This may grow quickly.'
,CONCAT(@BaseURL, 'database-growth-type')
FROM [sys].[master_files] AS [mf]
INNER JOIN [sys].[databases] AS [sd] ON [sd].[database_id] = [mf].[database_id]
INNER JOIN #Databases AS [d] ON [d].[database_name] = [sd].[name]
WHERE [mf].[is_percent_growth] = 1
AND [mf].[data_space_id] = 1; --ignore log files
END;
END; -- User DB or model db growth set to % Check
/* Default fill factor (EXPRESS ONLY) */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Non-default fill factor (EXPRESS)');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
IF(@IsExpress = 1)
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Architecture''
,N''INDEX''
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME([o].[schema_id])) + ''.'' + QUOTENAME([o].[name]) + ''.'' + QUOTENAME([i].[name])
,NULL
,N''Non-default fill factor on this index. Not inherently bad, but will increase table size more quickly.''
,CONCAT(@BaseURL COLLATE database_default, ''default-fill-factor'')
FROM [sys].[indexes] AS [i]
INNER JOIN [sys].[objects] AS [o] ON [o].[object_id] = [i].[object_id]
WHERE [i].[fill_factor] NOT IN(0, 100);'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- Non-default fill factor check
ELSE IF (@Verbose = 1) --Skip check
BEGIN;
RAISERROR(' Skipping check, not Express...', 10, 1) WITH NOWAIT;
END;
END; --Default fill factor
/* Number of indexes */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT('Check ', @CheckNumber, ' - Questionable number of indexes');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N'USE ' + QUOTENAME([database_name]) + N';
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,N''Architecture''
,N''INDEX''
,QUOTENAME(DB_NAME())
,QUOTENAME(SCHEMA_NAME(t.schema_id)) + ''.'' + QUOTENAME(t.name)
,NULL
,''There are '' + CAST(COUNT(DISTINCT(i.index_id)) AS VARCHAR) + '' indexes on this table taking up '' + CAST(CAST(SUM(s.[used_page_count]) * 8 / 1024.00 AS DECIMAL(10, 2)) AS VARCHAR) + '' MB of space.''
,CONCAT(@BaseURL COLLATE database_default, ''number-of-indexes'')
FROM sys.indexes AS i
INNER JOIN sys.tables AS t ON i.object_id = t.object_id
INNER JOIN sys.dm_db_partition_stats AS s ON s.object_id = i.object_id
AND s.index_id = i.index_id
WHERE t.is_ms_shipped = 0 --exclude sys table
AND i.type_desc = ''NONCLUSTERED'' --exclude clustered indexes from count
GROUP BY t.name,
t.schema_id
HAVING COUNT(DISTINCT(i.index_id)) > @IndexNumThreshold;'
FROM #Databases;
EXEC sp_executesql @CheckSQL, N'@IndexNumThreshold TINYINT, @CheckNumber TINYINT, @BaseURL VARCHAR(1000)', @IndexNumThreshold = @IndexNumThreshold, @CheckNumber = @CheckNumber, @BaseURL = @BaseURL;
END; -- Questionable number of indexes check
/* Inefficient Indexes */
SET @CheckNumber = @CheckNumber + 1;
IF (@Verbose = 1)
BEGIN;
SET @Msg = CONCAT(N'Check ', @CheckNumber, ' - Inefficient indexes');
RAISERROR(@Msg, 10, 1) WITH NOWAIT;
END;
BEGIN;
SET @CheckSQL = N'';
SELECT @CheckSQL = @CheckSQL +
N' USE ? ;
BEGIN
IF OBJECT_ID(''tempdb..#Indexes'') IS NOT NULL
BEGIN;
DROP TABLE [#Indexes];
END;
IF OBJECT_ID(''tempdb..#IdxChecksum'') IS NOT NULL
BEGIN;
DROP TABLE [#IdxChecksum];
END;
IF OBJECT_ID(''tempdb..#MatchingIdxInclChecksum'') IS NOT NULL
BEGIN;
DROP TABLE [#MatchingIdxInclChecksum];
END;
IF OBJECT_ID(''tempdb..#MatchingIdxChecksum'') IS NOT NULL
BEGIN;
DROP TABLE [#MatchingIdxChecksum];
END; '
+ /* Retrieve all indexes */ +
N'SELECT ac.[name] AS [col_name]
,row_number () OVER (PARTITION BY ind.[object_id], ind.index_id ORDER BY indc.index_column_id ) AS row_num
,ind.index_id
,ind.[object_id]
,DENSE_RANK() OVER (ORDER BY ind.[object_id], ind.index_id) AS [index_num]
,indc.is_included_column
,NULL AS [ix_checksum]
,NULL AS [ix_incl_checksum]
,ao.[schema_id]
INTO #Indexes
FROM sys.indexes as [ind]
INNER JOIN sys.index_columns AS [indc] ON [ind].[object_id] = [indc].[object_id] AND ind.index_id = indc.index_id
INNER JOIN sys.all_columns as [ac] ON [ac].[column_id] = [indc].[column_id] and indc.[object_id] = ac.[object_id]
INNER JOIN sys.all_objects AS [ao] ON [ao].[object_id] = [ac].[object_id]
WHERE ao.is_ms_shipped = 0
ORDER BY ind.[object_id];
DECLARE @Counter BIGINT = (SELECT 1);
DECLARE @MaxNumIndex BIGINT = (SELECT MAX(index_num) FROM #Indexes); '
+ /* Iterate through each index, adding together columns for each */ +
N'WHILE @Counter <= @MaxNumIndex
BEGIN
DECLARE @IndexedColumns NVARCHAR(MAX) = N'''';
DECLARE @IndexedColumnsInclude NVARCHAR(MAX) = N''''; '
+ /* Add together index columns */ +
N'SELECT @IndexedColumns += CAST([col_name] AS SYSNAME)
FROM #Indexes
WHERE is_included_column = 0
AND index_num = @Counter
ORDER BY row_num; '
+ /* Add together index + included columns */ +
N'SELECT @IndexedColumnsInclude += CAST([col_name] AS SYSNAME)
FROM #Indexes
WHERE index_num = @Counter
ORDER BY row_num; '
+ /* Generate a checksum for index columns and index + included columns for each index */ +
N'UPDATE #Indexes
SET [ix_checksum] = CHECKSUM(@IndexedColumns), [ix_incl_checksum] = CHECKSUM(@IndexedColumnsInclude)
WHERE index_num = @Counter;
SET @Counter += 1;
END; '
+ /* Narrow down to one row per index */ +
N'SELECT DISTINCT [object_id], index_id, [ix_checksum], [ix_incl_checksum], [schema_id]
INTO #IdxChecksum
FROM #Indexes; '
+ /* Find duplicate indexes */ +
N'SELECT COUNT(*) AS [num_dup_indexes], [ix_incl_checksum], [object_id]
INTO #MatchingIdxInclChecksum
FROM #IdxChecksum
GROUP BY [ix_incl_checksum], [object_id]
HAVING COUNT(*) > 1; '
+ /* Find overlapping indexes with same indexed columns */ +
N'SELECT COUNT(*) AS [num_dup_indexes], [ix_checksum], [object_id]
INTO #MatchingIdxChecksum
FROM #IdxChecksum
GROUP BY [ix_checksum], [object_id]
HAVING COUNT(*) > 1
INSERT INTO #DuplicateIndex
SELECT N''Inefficient Indexes - Duplicate'' AS [check_type]
,N''INDEX'' AS [obj_type]
,QUOTENAME(DB_NAME()) AS [db_name]
,QUOTENAME(SCHEMA_NAME([schema_id])) + ''.'' + QUOTENAME(OBJECT_NAME(ic.[object_id])) + ''.'' + QUOTENAME(i.[name]) AS [obj_name]
,NULL AS [col_name]
,''Indexes in group '' + CAST(DENSE_RANK() over (order by miic.[ix_incl_checksum]) AS VARCHAR(5)) + '' share the same indexed and any included columns.'' AS [message]
,ic.[object_id]
,ic.[index_id]
FROM #MatchingIdxInclChecksum AS miic
INNER JOIN #IdxChecksum AS ic ON ic.[object_id] = miic.[object_id] AND ic.[ix_incl_checksum] = miic.[ix_incl_checksum]
INNER JOIN sys.indexes AS [i] ON [i].[index_id] = ic.index_id AND i.[object_id] = ic.[object_id]
INSERT INTO #OverlappingIndex
SELECT N''Inefficient Indexes - Overlapping'' AS [check_type]
,N''INDEX'' AS [obj_type]
,QUOTENAME(DB_NAME()) AS [db_name]
,QUOTENAME(SCHEMA_NAME([schema_id])) + ''.'' + QUOTENAME(OBJECT_NAME(ic.[object_id])) + ''.'' + QUOTENAME(i.[name]) AS [obj_name]
,NULL AS [col_name]
,''Indexes in group '' + CAST(DENSE_RANK() OVER (order by mic.[ix_checksum]) AS VARCHAR(5)) + '' share the same indexed columns.'' AS [message]
,ic.[object_id]
,ic.[index_id]
FROM #MatchingIdxChecksum AS mic
INNER JOIN #IdxChecksum AS ic ON ic.[object_id] = mic.[object_id] AND ic.[ix_checksum] = mic.[ix_checksum]
INNER JOIN sys.indexes AS [i] ON [i].[index_id] = ic.index_id AND i.[object_id] = ic.[object_id] '
+ /* Dont include any indexes that are already identified as 100% duplicates */ +
N'WHERE NOT EXISTS (SELECT * FROM #DuplicateIndex AS [di] WHERE [di].[object_id] = ic.[object_id] AND di.index_id = ic.index_id);
END';
DECLARE [DB_Cursor] CURSOR LOCAL FAST_FORWARD
FOR SELECT QUOTENAME([database_name])
FROM #Databases;
OPEN [DB_Cursor];
FETCH NEXT FROM [DB_Cursor]
INTO @DbName;
/* Run index query for each database */
WHILE @@FETCH_STATUS = 0
BEGIN;
SET @TempCheckSQL = REPLACE(@CheckSQL, N'?', @DbName);
EXEC sp_executesql @TempCheckSQL;
FETCH NEXT FROM [DB_Cursor]
INTO @DbName;
END;
CLOSE [DB_Cursor];
DEALLOCATE [DB_Cursor];
/* Duplicate Indexes */
INSERT INTO #results ([check_num], [check_type], [obj_type], [db_name], [obj_name], [col_name], [message], [ref_link])
SELECT @CheckNumber
,[check_type]
,[obj_type]
,[db_name]
,[obj_name]