forked from Jorriss/sp_DataProfile
-
Notifications
You must be signed in to change notification settings - Fork 4
/
Copy pathsp_DataProfile.sql
1197 lines (973 loc) · 41.1 KB
/
sp_DataProfile.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
USE [master]
GO
IF OBJECT_ID('dbo.sp_DataProfile') IS NOT NULL
DROP PROCEDURE dbo.sp_DataProfile;
GO
CREATE PROCEDURE dbo.sp_DataProfile
@TableName NVARCHAR(500) ,
@Mode TINYINT = 0 , /* 0 = Table Overview, 1 = Column Detail, 2 = Column Statistics, 3 = Candidate Key Check, 4 = Column Value Distribution */
@ColumnList NVARCHAR(4000) = NULL ,
@DatabaseName NVARCHAR(128) = NULL ,
@ShowForeignKeys BIT = 0 ,
@ShowIndexes BIT = 0 ,
@SampleValue INT = NULL ,
@SampleType NVARCHAR(50) = 'PERCENT' ,
@Verbose BIT = 0
AS
BEGIN
SET NOCOUNT ON;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
DECLARE @SQLString NVARCHAR(4000);
DECLARE @SQLStringFK NVARCHAR(4000);
DECLARE @SQLStringIndexes NVARCHAR(4000);
DECLARE @Schema NVARCHAR(100);
DECLARE @DatabaseID INT;
DECLARE @SchemaPosition INT;
DECLARE @Msg NVARCHAR(4000);
DECLARE @ErrorSeverity INT;
DECLARE @ErrorState INT;
DECLARE @RowCount BIGINT;
DECLARE @IsSample BIT = 0;
DECLARE @TableSample NVARCHAR(100) = '';
DECLARE @FromTableName NVARCHAR(100) = '';
DECLARE @ColumnListString NVARCHAR(4000);
DECLARE @ColumnNameFirst NVARCHAR(4000);
DECLARE @SQLServerVersion NVARCHAR(100) = '';
DECLARE @SQLCompatLevelMaster INT;
DECLARE @SQLCompatLevelDB INT;
DECLARE @SQLCompatLevelDBOut INT;
DECLARE @SQLCompatLevel INT;
DECLARE @ViewSQLDataString NVARCHAR(4000);
BEGIN TRY
/* Get that SQL Server Version son! 2005 or older up in here! */
SELECT @SQLServerVersion = CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128));
IF (SELECT LEFT(@SQLServerVersion, CHARINDEX('.', @SQLServerVersion, 0) -1 )) <= 8
BEGIN
SET @Msg = N'I''m sorry Dave. I can''t run on your version of SQL Server. I require a SQL Server 2005 and higher. The version of this instance is: ' + @SQLServerVersion + '. I promise I won''t open the airlock.';
RAISERROR(@Msg, 16, 1);
END
IF @DatabaseName IS NULL
SET @DatabaseName = DB_NAME();
/* Get Compat Level. We're going to use this later to determine if we can do the wierd stuff. */
SELECT @SQLCompatLevelMaster = compatibility_level FROM sys.databases WHERE name = 'master';
SET @SQLString = N'
SELECT @SQLCompatLevelDBOut = compatibility_level
FROM sys.databases WHERE name = ''' + @DatabaseName + ''';'
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXEC sp_executesql @SQLString, N'@SQLCompatLevelDBOut INT OUTPUT', @SQLCompatLevelDBOut = @SQLCompatLevelDB OUTPUT;
IF @SQLCompatLevelMaster < @SQLCompatLevelDB
SET @SQLCompatLevel = @SQLCompatLevelMaster;
ELSE
SET @SQLCompatLevel = @SQLCompatLevelDB;
IF @SQLCompatLevel < 110
BEGIN
SET @Msg = 'Your compatibility level of ' + CAST(@SQLCompatLevel AS NVARCHAR(10)) + ' is a bit too low. I can''t perform median calculations for compatibility levels lower than 110. If this is unacceptable to you feel free to write the median calculation yourself. I accept pull requests. ;)';
RAISERROR(@Msg, 0, 1);
END
SET @Schema = PARSENAME(@TableName, 2);
SET @TableName = PARSENAME(@TableName, 1);
IF @Schema IS NULL
SET @Schema = 'dbo';
IF @Mode NOT IN (0, 1, 2, 3, 4)
BEGIN
SET @Msg = 'Mode values should only be 0, 1, 2, 3 or 4. 0 = Table Overview, 1 = Table Detail, 2 = Column Statistics, 3 = Candidate Key Check, 4 = Column Value Distribution';
RAISERROR(@Msg, 1, 1);
RETURN;
END
IF (@Mode IN (3, 4)) AND (@ColumnList IS NULL OR @ColumnList = '')
BEGIN
SET @Msg = 'It looks like you didn''t provide a ColumnList. A ColumnList is required for the Candidate Key Check and the Column Value Distribution modes.';
RAISERROR(@Msg, 1, 1);
RETURN;
END
IF @SampleType NOT IN ('ROWS', 'PERCENT')
BEGIN
SET @Msg = 'Did you mistype the SampleType value? SampleType should be either ''ROWS'' or ''PERCENT''';
RAISERROR(@Msg, 1, 1);
RETURN;
END
IF @SampleValue < 0 OR @SampleValue > 100
BEGIN
SET @Msg = 'Whoops. The SampleValue should be between 0 and 100.';
RAISERROR(@Msg, 1, 1);
RETURN;
END
IF @SampleValue IS NOT NULL
BEGIN
SET @IsSample = 1;
SET @TableSample = ' TABLESAMPLE (' + CAST(@SampleValue AS NVARCHAR(3)) + ' ' + @SampleType + ') REPEATABLE(100) ';
END
SET @FromTableName = QUOTENAME(@Schema) + '.' + QUOTENAME(@TableName) + @TableSample;
If DB_NAME() <> @DatabaseName
SET @FromTableName = QUOTENAME(@DatabaseName) + '.' + @FromTableName;
SELECT @DatabaseID = database_id
FROM sys.databases
WHERE [name] = @DatabaseName
AND user_access_desc = 'MULTI_USER'
AND state_desc = 'ONLINE';
/* Format ColumnList */
DECLARE @ColumnListClean NVARCHAR(4000);
DECLARE @ColumnListComma NVARCHAR(4000);
DECLARE @CommaPos INT;
DECLARE @CommaPart NVARCHAR(4000);
SET @ColumnListComma = @ColumnList;
SET @ColumnListClean = '';
IF RIGHT(RTRIM(@ColumnListComma), 1) <> N','
SET @ColumnListComma = @ColumnListComma + N',';
SET @CommaPos = PATINDEX(N'%,%', @ColumnListComma);
WHILE @CommaPos <> 0
BEGIN
SET @CommaPart = LEFT(@ColumnListComma, @CommaPos - 1);
SET @ColumnListClean = @ColumnListClean + LTRIM(RTRIM(@CommaPart)) + ',';
SET @ColumnListComma = STUFF(@ColumnListComma, 1, @CommaPos, '');
SET @CommaPos = PATINDEX(N'%,%', @ColumnListComma);
END
SET @ColumnList = @ColumnListClean;
IF RIGHT(@ColumnList, 1) = ','
SET @ColumnList = LEFT(@ColumnList, LEN(@ColumnList) - 1);
SET @ColumnListString = '''' + REPLACE(@ColumnList, ',', ''',''') + '''';
IF @Verbose = 1
BEGIN
SET @Msg = N'ColumnListstring: ' + @ColumnList
RAISERROR (@Msg, 0, 1) WITH NOWAIT;
END
IF OBJECT_ID ('tempdb..#table_column_profile') IS NOT NULL
DROP TABLE #table_column_profile;
CREATE TABLE #table_column_profile (
[object_id] INT NOT NULL ,
[column_id] INT NOT NULL ,
[name] NVARCHAR(128) NOT NULL ,
[system_type] NVARCHAR(100) NOT NULL ,
[user_type] NVARCHAR(100) NOT NULL ,
[collation] NVARCHAR(100) NULL ,
[length] INTEGER NULL ,
[precision] INTEGER NULL ,
[scale] INTEGER NULL ,
[is_nullable] BIT NOT NULL ,
[num_rows] BIGINT NULL ,
[num_unique_values] BIGINT NULL ,
[unique_ratio] AS CAST((CAST([num_unique_values] AS DECIMAL(25,5)) / ISNULL(NULLIF([num_rows], 0), 1)) AS DECIMAL(25,5)) ,
[num_nulls] BIGINT NULL ,
[nulls_ratio] AS CAST((CAST([num_nulls] AS DECIMAL(25,5)) / ISNULL(NULLIF([num_rows], 0), 1)) AS DECIMAL(25,5)) ,
[min_length] INT NULL ,
[max_length] INT NULL ,
[min_value] NVARCHAR(100) NULL ,
[max_value] NVARCHAR(100) NULL ,
[mean] NVARCHAR(100) NULL ,
[median] NVARCHAR(100) NULL ,
[std_dev] NVARCHAR(100) NULL
);
CREATE TABLE #table_relationship (
[relationship_type] NVARCHAR(25) NULL ,
[fk_name] NVARCHAR(128) NOT NULL ,
[parent_table] NVARCHAR(128) NOT NULL ,
[parent_column_name] NVARCHAR(128) NOT NULL ,
[parent_column_id] INT NULL ,
[referrenced_table] NVARCHAR(128) NOT NULL ,
[referrenced_column_name] NVARCHAR(128) NOT NULL ,
[referenced_column_id] INT NULL
);
CREATE TABLE #table_indexes (
[name] NVARCHAR(128) NOT NULL ,
[index_id] INT NULL ,
[type_desc] NVARCHAR(60) NULL ,
[is_primary_key] BIT NULL ,
[is_unique] BIT NULL ,
[is_unique_constraint] BIT NULL ,
[is_disabled] BIT NULL ,
[fill_factor] TINYINT NULL ,
[index_columns] NVARCHAR(max) NULL ,
[included_columns] NVARCHAR(max) NULL ,
[filter_definition] NVARCHAR(max)
);
/* Inserting data into #table_column_profile */
SET @SQLString = N'
SELECT t.object_id ,
c.column_id ,
c.name ,
sys.name,
typ.name ,
c.collation_name ,
CAST(
CASE
WHEN c.max_length = -1 THEN c.max_length
WHEN sys.name = ''nvarchar'' THEN c.max_length / 2
WHEN sys.name = ''nchar'' THEN c.max_length / 2
ELSE c.max_length
END
AS NVARCHAR(100)) AS max_length ,
c.precision ,
c.scale ,
c.is_nullable
FROM ' + QUOTENAME(@DatabaseName) + '.sys.tables t
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns c ON t.object_id = c.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.types typ ON c.system_type_id = typ.system_type_id
AND c.user_type_id = typ.user_type_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.types sys ON typ.system_type_id = sys.system_type_id
AND sys.user_type_id = sys.system_type_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.schemas s ON t.schema_id = s.schema_id
AND s.name = ''' + @Schema + '''
WHERE t.name = ''' + @TableName + '''
ORDER BY c.column_id;'
IF @Verbose = 1
BEGIN
RAISERROR (N'Inserting data into #table_column_profile', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
INSERT INTO #table_column_profile (
[object_id] ,
[column_id] ,
[name] ,
[system_type] ,
[user_type] ,
[collation] ,
[length] ,
[precision] ,
[scale] ,
[is_nullable]
)
EXEC sp_executesql @SQLString;
/* Update actual row count */
SET @SQLString = N'
UPDATE #table_column_profile
SET num_rows = cnt
FROM (SELECT COUNT_BIG(*) cnt
FROM ' + @FromTableName + ') tablecount ;'
IF @Verbose = 1
BEGIN
RAISERROR (N'Updating data in #table_column_profile for table row counts', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXEC sp_executesql @SQLString;
SELECT TOP 1 @RowCount = num_rows FROM #table_column_profile;
/* Insert FK data into #table_relationship */
IF @ShowForeignKeys = 1
BEGIN
SET @SQLString = N'
SELECT relationship_type = ''Outgoing'',
fk_name = fk.name ,
parent_table = tp.name ,
parent_column_name = cp.name ,
parent_column_id = cp.column_id ,
referrenced_table = tr.name ,
referrenced_column_name = cr.name ,
referenced_column_id = cr.column_id
FROM ' + QUOTENAME(@DatabaseName) + '.sys.foreign_keys fk
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.tables tp ON fk.parent_object_id = tp.object_id
LEFT JOIN ' + QUOTENAME(@DatabaseName) + '.sys.tables tr ON fk.referenced_object_id = tr.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.foreign_key_columns fkc ON fkc.constraint_object_id = fk.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns cp ON fkc.parent_column_id = cp.column_id
AND fkc.parent_object_id = cp.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns cr ON fkc.referenced_column_id = cr.column_id
AND fkc.referenced_object_id = cr.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.schemas s ON tr.schema_id = s.schema_id
AND s.name = ''' + @Schema + '''
WHERE tr.name = ''' + @TableName + '''
UNION ALL
SELECT RelationshipType = ''Incoming'',
FKName = fk.name ,
ParentTable = tp.name ,
ParentColumnName = cp.name ,
ParentColumnID = cp.column_id ,
ReferencedTable = tr.name ,
ReferencedColumnName = cr.name ,
ReferencedColumnID = cr.column_id
FROM ' + QUOTENAME(@DatabaseName) + '.sys.foreign_keys fk
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.tables tp ON fk.parent_object_id = tp.object_id
LEFT JOIN ' + QUOTENAME(@DatabaseName) + '.sys.tables tr ON fk.referenced_object_id = tr.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.foreign_key_columns fkc ON fkc.constraint_object_id = fk.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns cp ON fkc.parent_column_id = cp.column_id AND fkc.parent_object_id = cp.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns cr ON fkc.referenced_column_id = cr.column_id AND fkc.referenced_object_id = cr.object_id
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.schemas s ON tp.schema_id = s.schema_id
AND s.name = ''' + @Schema + '''
WHERE tp.name = ''' + @TableName + ''''
IF @Verbose = 1
BEGIN
RAISERROR (N'Insert FK data into #table_relationship', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
INSERT INTO #table_relationship (
[relationship_type] ,
[fk_name] ,
[parent_table] ,
[parent_column_name] ,
[parent_column_id] ,
[referrenced_table] ,
[referrenced_column_name] ,
[referenced_column_id]
)
EXEC sp_executesql @SQLString;
SET @SQLStringFK = N'
SELECT [relationship_type] ,
[fk_name] ,
[parent_table] ,
[parent_column_name] ,
[parent_column_id] ,
[referrenced_table] ,
[referrenced_column_name] ,
[referenced_column_id]
FROM #table_relationship
ORDER BY relationship_type ,
parent_table ,
fk_name ;'
END
/* Insert Index data into #table_indexes */
IF @ShowIndexes = 1
BEGIN
SET @SQLString = N'
SELECT i.name ,
i.index_id ,
i.type_desc ,
i.is_primary_key ,
i.is_unique ,
i.is_unique_constraint ,
i.is_disabled ,
i.fill_factor ,
index_columns =
(SELECT STUFF(
(SELECT '', '' + c.name + CASE WHEN ic.is_descending_key = 1 THEN '' DESC'' ELSE '' ASC'' END
FROM ' + QUOTENAME(@DatabaseName) + '.sys.index_columns ic
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns c ON ic.object_id = c.object_id
AND ic.column_id = c.column_id
WHERE i.object_id = ic.object_id
AND i.index_id = ic.index_id
AND ic.is_included_column = 0
ORDER BY ic.index_column_id
FOR XML PATH (''''))
, 1, 1, '''') ) ,
included_columns =
(SELECT STUFF(
(SELECT '', '' + c.name
FROM ' + QUOTENAME(@DatabaseName) + '.sys.index_columns ic
JOIN ' + QUOTENAME(@DatabaseName) + '.sys.columns c ON ic.object_id = c.object_id
AND ic.column_id = c.column_id
WHERE i.object_id = ic.object_id
AND i.index_id = ic.index_id
AND ic.is_included_column = 1
ORDER BY ic.index_column_id
FOR XML PATH (''''))
, 1, 1, '''') ) ,
i.filter_definition
FROM ' + QUOTENAME(@DatabaseName) + '.sys.indexes i
WHERE i.object_id = OBJECT_ID(''' + @FromTableName + ''')
ORDER BY i.index_id'
IF @Verbose = 1
BEGIN
RAISERROR (N'Insert index data into #table_indexes', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;
END
INSERT INTO #table_indexes (
[name] ,
[index_id] ,
[type_desc] ,
[is_primary_key] ,
[is_unique] ,
[is_unique_constraint] ,
[is_disabled] ,
[fill_factor] ,
[index_columns] ,
[included_columns] ,
[filter_definition]
)
EXEC sp_executesql @SQLString;
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
SET @SQLStringIndexes = N'
SELECT [name] ,
[index_id] ,
[type_desc] ,
[is_primary_key] ,
[is_unique] ,
[is_unique_constraint] ,
[is_disabled] ,
[fill_factor] ,
[index_columns] ,
[included_columns] ,
[filter_definition]
FROM #table_indexes
ORDER BY index_id ;'
END
IF @Mode = 1 /* Table Detail */
BEGIN
-- Determine unique values for each column with a valid type.
DECLARE @uniq_col_name NVARCHAR(500) ,
@uniq_col_id INTEGER;
DECLARE uniq_cur CURSOR
LOCAL STATIC FORWARD_ONLY READ_ONLY FOR
SELECT p.name,
p.column_id
FROM #table_column_profile p
WHERE system_type IN ('uniqueidentifier', 'date', 'time', 'datetime2', 'datetimeoffset', 'tinyint', 'smallint', 'int', 'smalldatetime', 'real', 'money', 'datetime', 'float', 'sql_variant', 'bit', 'decimal', 'numeric', 'smallmoney' ,'bigint', 'hierarchyid', 'geometry', 'geography', 'varbinary', 'varchar', 'binary', 'char', 'timestamp', 'nvarchar', 'nchar') ;
OPEN uniq_cur;
FETCH NEXT FROM uniq_cur INTO @uniq_col_name, @uniq_col_id;
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @SQLString = N'
UPDATE #table_column_profile
SET num_unique_values = val
FROM (
SELECT COUNT(DISTINCT ' + QUOTENAME(@uniq_col_name) + ') val
FROM ' + @FromTableName + ') uniq
WHERE column_id = ' + CAST(@uniq_col_id AS NVARCHAR(10))
IF @Verbose = 1
BEGIN
RAISERROR (N'Determine unique values for each column with a valid type.', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXECUTE sp_executesql @SQLString;
FETCH NEXT FROM uniq_cur INTO @uniq_col_name, @uniq_col_id;
END
-- Determine null values for each column
DECLARE @null_col_name NVARCHAR(500) ,
@null_col_num INTEGER;
DECLARE null_cur CURSOR
LOCAL STATIC FORWARD_ONLY READ_ONLY FOR
SELECT p.name,
p.column_id
FROM #table_column_profile p
WHERE p.is_nullable = 1;
OPEN null_cur;
FETCH NEXT FROM null_cur INTO @null_col_name, @null_col_num;
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @SQLString =
N'UPDATE #table_column_profile ' +
'SET num_nulls = val ' +
'FROM (' +
' SELECT COUNT(*) val ' +
' FROM ' + @FromTableName + ' ' +
' WHERE ' + QUOTENAME(@null_col_name) + ' IS NULL ' +
') uniq ' +
'WHERE column_id = ' + CAST(@null_col_num AS NVARCHAR(10))
IF @Verbose = 1
BEGIN
RAISERROR (N'Updating data in #table_column_profile for column null row counts.', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXECUTE sp_executesql @SQLString;
FETCH NEXT FROM null_cur INTO @null_col_name, @null_col_num;
END
CLOSE null_cur;
DEALLOCATE null_cur;
/* Determine min/max length values */
DECLARE @len_col_name NVARCHAR(500) ,
@len_col_num INTEGER;
DECLARE len_cur CURSOR
LOCAL STATIC FORWARD_ONLY READ_ONLY FOR
SELECT p.name,
p.column_id
FROM #table_column_profile p
WHERE p.system_type IN ('varchar', 'char', 'nvarchar', 'nchar');
OPEN len_cur;
FETCH NEXT FROM len_cur INTO @len_col_name, @len_col_num;
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @SQLString =
N'UPDATE #table_column_profile ' +
'SET max_length = val ' +
'FROM (' +
' SELECT MAX(LEN(' + QUOTENAME(@len_col_name) + ')) val ' +
' FROM ' + @FromTableName + ' ' +
') uniq ' +
'WHERE column_id = ' + CAST(@len_col_num AS NVARCHAR(10));
IF @Verbose = 1
BEGIN
RAISERROR (N'Updating data in #table_column_profile for column max length', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXECUTE sp_executesql @SQLString;
SELECT @SQLString =
N'UPDATE #table_column_profile ' +
'SET min_length = val ' +
'FROM (' +
' SELECT MIN(LEN(' + QUOTENAME(@len_col_name) + ')) val ' +
' FROM ' + @FromTableName + ' ' +
') uniq ' +
'WHERE column_id = ' + CAST(@len_col_num AS NVARCHAR(10));
IF @Verbose = 1
BEGIN
RAISERROR (N'Updating data in #table_column_profile for column min length', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXECUTE sp_executesql @SQLString;
FETCH NEXT FROM len_cur INTO @len_col_name, @len_col_num;
END
CLOSE len_cur;
DEALLOCATE len_cur;
END /* Table Detail */
IF @Mode = 2 /* Column Statistics */
BEGIN
/* Determine Column Statistics */
IF @Verbose = 1
RAISERROR (N'Updating data in #table_column_profile for column statistics', 0, 1) WITH NOWAIT;
DECLARE @stats_col_name NVARCHAR(500) ,
@stats_col_num INTEGER ,
@stats_col_type NVARCHAR(50);
DECLARE stats_cur CURSOR LOCAL STATIC FORWARD_ONLY READ_ONLY FOR
SELECT p.name,
p.column_id,
p.system_type
FROM #table_column_profile p
WHERE p.system_type IN ('bigint', 'bit', 'decimal', 'int', 'money', 'numeric', 'smallint', 'smallmoney', 'tinyint', 'float', 'real', 'date', 'datetime2', 'datetime', 'datetimeoffset', 'smalldatetime', 'time');
OPEN stats_cur;
FETCH NEXT FROM stats_cur INTO @stats_col_name, @stats_col_num, @stats_col_type;
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @SQLString = N'
UPDATE #table_column_profile
SET max_value = max_val ,
min_value = min_val
FROM (
SELECT CAST(MAX(' + QUOTENAME(@stats_col_name) + ') AS NVARCHAR(100)) max_val ,
CAST(MIN(' + QUOTENAME(@stats_col_name) + ') AS NVARCHAR(100)) min_val
FROM ' + @FromTableName + '
) stats
WHERE column_id = ' + CAST(@stats_col_num AS NVARCHAR(10))
IF @Verbose = 1
BEGIN
RAISERROR (N'Updating data in #table_column_profile for column max length', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
IF @stats_col_type != 'bit'
EXECUTE sp_executesql @SQLString;
/* Update mean, standard deviation */
DECLARE @col_name NVARCHAR(100) = QUOTENAME(@stats_col_name);
IF @stats_col_type = 'int'
SET @col_name = 'CAST(' + QUOTENAME(@stats_col_name) + ' AS BIGINT)';
SELECT @SQLString = N'
UPDATE #table_column_profile
SET mean = mean_val ,
std_dev = std_dev_val
FROM (
SELECT mean_val = CAST(AVG(' + @col_name + ') AS NVARCHAR(100)) ,
std_dev_val = CAST(CAST(STDEV(' + QUOTENAME(@stats_col_name) + ') AS NUMERIC(18,4)) AS NVARCHAR(100))
FROM ' + @FromTableName + '
) stats WHERE column_id = ' + CAST(@stats_col_num AS NVARCHAR(10))
IF @Verbose = 1
BEGIN
RAISERROR (N'Update mean, standard deviation', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
IF @stats_col_type IN ('bigint', 'decimal', 'int', 'money', 'numeric', 'smallint', 'smallmoney', 'tinyint', 'float', 'real')
EXECUTE sp_executesql @SQLString;
/* Update median */
IF @SQLCompatLevel >= 110
BEGIN
SELECT @SQLString = N'
UPDATE #table_column_profile
SET median = median_val
FROM (
SELECT DISTINCT median_val = PERCENTILE_DISC(0.5) WITHIN GROUP (ORDER BY ' + @stats_col_name + ') OVER ()
FROM ' + @FromTableName + '
) stats
WHERE column_id = ' + CAST(@stats_col_num AS NVARCHAR(10))
IF @Verbose = 1
BEGIN
RAISERROR (N'Update median', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
IF @stats_col_type IN ('bigint', 'decimal', 'int', 'money', 'numeric', 'smallint', 'smallmoney', 'tinyint', 'float', 'real')
EXECUTE sp_executesql @SQLString;
END /* End Median Update */
FETCH NEXT FROM stats_cur INTO @stats_col_name, @stats_col_num, @stats_col_type;
END /* Column Statistics Loop */
CLOSE stats_cur;
DEALLOCATE stats_cur;
END /* 2 - Column Statistics */
IF @Mode = 3 /* 3 - Candidate Key Check */
BEGIN
DECLARE @WhereString NVARCHAR(MAX)
DECLARE @WhereCtr INT;
IF OBJECT_ID ('tempdb..#ColumnName') IS NOT NULL
DROP TABLE #ColumnName;
CREATE TABLE #ColumnName (
column_name NVARCHAR(500),
column_type NVARCHAR(100)
);
SET @WhereString = ' WHERE ';
SET @WhereCtr = 0;
SET @SQLString = N'
SELECT c.name ,
type = TYPE_NAME(c.system_type_id)
FROM sys.tables t
JOIN sys.columns c ON c.object_id = t.object_id
WHERE t.name = ''' + @TableName + '''
AND t.schema_id = SCHEMA_ID(''' + @Schema + ''')
AND c.name IN (' + @ColumnListString + ');'
IF @Verbose = 1
BEGIN
RAISERROR (N'Find data types for columns for Where clause Candidate Key Check', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
INSERT INTO #ColumnName
EXECUTE sp_executesql @SQLString
-- Determine unique values for each column with a valid type.
DECLARE @where_col_name NVARCHAR(500) ,
@where_type_name NVARCHAR(100) ,
@where_col_value NVARCHAR(500) ;
DECLARE where_type_cur CURSOR
LOCAL STATIC FORWARD_ONLY READ_ONLY FOR
SELECT column_name ,
column_type
FROM #ColumnName
OPEN where_type_cur;
FETCH NEXT FROM where_type_cur INTO @where_col_name, @where_type_name;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @WhereCtr = @WhereCtr + 1;
IF @WhereCtr > 1
SET @WhereString = @WhereString + ' AND ';
IF @where_type_name IN ('datetime', 'datetime2', 'date', 'time', 'datetimeoffset', 'smalldatetime')
BEGIN
SET @where_col_value = 'CONVERT(NVARCHAR, ' + @where_col_name + ', 127)'
END
ELSE
SET @where_col_value = 'CONVERT(NVARCHAR(MAX), ' + @where_col_name + ')'
IF @where_type_name IN ('uniqueidentifier', 'date', 'time', 'datetime2', 'datetimeoffset', 'smalldatetime', 'datetime', 'sql_variant', 'varchar', 'char', 'timestamp', 'nvarchar', 'nchar')
BEGIN
SET @WhereString = @WhereString + @where_col_name + ''' + COALESCE('' = '''''' + ' + @where_col_value + ' + '''''''', '' IS NULL'') + ''';
END
ELSE
BEGIN
SET @WhereString = @WhereString + @where_col_name + ''' + COALESCE('' = '' + ' + @where_col_value + ' + '''', '' IS NULL'') + ''';
END
FETCH NEXT FROM where_type_cur INTO @where_col_name, @where_type_name;
END
CLOSE where_type_cur;
DEALLOCATE where_type_cur;
IF @Verbose = 1
BEGIN
SET @Msg = N'@WhereString: ' + @WhereString;
RAISERROR (@Msg, 0, 1) WITH NOWAIT;
END
END /* 3 - Candidate Key Check */
IF @Mode = 4 /* 4 - Column Value Distribution */
BEGIN
DECLARE @RowCountDistinct BIGINT;
IF OBJECT_ID ('tempdb..#table_distinct_count') IS NOT NULL
DROP TABLE #table_distinct_count;
CREATE TABLE #table_distinct_count (
[column_count] BIGINT NULL);
/* Only process the first column identified */
IF CHARINDEX(',', @ColumnList) > 0
SET @ColumnNameFirst = LEFT(@ColumnList, CHARINDEX(',', @ColumnList) - 1)
ELSE
SET @ColumnNameFirst = RTRIM(LTRIM(@ColumnList))
IF RTRIM(LTRIM(@ColumnNameFirst)) <> RTRIM(LTRIM(@ColumnList))
BEGIN
RAISERROR(N'More than one column was supplied. Only the first column will be used in determining the column value distribution.', 0, 1);
END
SELECT @SQLString = N'
INSERT INTO #table_distinct_count (column_count)
SELECT COUNT(DISTINCT ' + QUOTENAME(@ColumnNameFirst) + ') val
FROM ' + @FromTableName + '
';
IF @Verbose = 1
BEGIN
RAISERROR (N'Insert distinct count for Column Value Distribution.', 0, 1) WITH NOWAIT;
RAISERROR (@SQLString, 0, 1) WITH NOWAIT;;
END
IF @SQLString IS NULL
RAISERROR('@SQLString is null', 16, 1);
EXEC sp_executesql @SQLString;
END /* 4 - Column Value Distribution */
/* Table schema output */
IF @Mode = 0
BEGIN
IF @Verbose = 1
RAISERROR (N'Ouputting data for table schema output.', 0, 1) WITH NOWAIT;
/* Table output */
SELECT [object_id] = OBJECT_ID(QUOTENAME(@Schema) + '.' + QUOTENAME(@TableName)) ,
[schema_name] = @Schema ,
[table_name] = @TableName ,
[row_count] = @RowCount ,
[is_sample] = CASE @IsSample WHEN 1 THEN 'True' ELSE 'False' END;
SELECT [column_id] ,
[name] ,
[user_type] ,
[system_type] ,
[length] =
CASE
WHEN [length] = -1 AND [system_type] = 'xml' THEN NULL
WHEN [length] = -1 THEN 'max'
ELSE CAST([length] AS VARCHAR(50))
END,
[precision] ,
[scale] ,
[is_nullable] ,
[collation]
FROM #table_column_profile;
IF @ShowForeignKeys = 1
BEGIN
IF @Verbose = 1
BEGIN
RAISERROR (N'Displaying Foreign Keys', 0, 1) WITH NOWAIT;
RAISERROR (@SQLStringFK, 0, 1) WITH NOWAIT;
END
IF @SQLStringFK IS NULL
RAISERROR('@SQLStringFK is null', 16, 1);
EXEC sp_executesql @SQLStringFK;
END
IF @ShowIndexes = 1
BEGIN
IF @Verbose = 1
BEGIN
RAISERROR (N'Displaying Indexes', 0, 1) WITH NOWAIT;
RAISERROR (@SQLStringIndexes, 0, 1) WITH NOWAIT;
END
IF @SQLStringIndexes IS NULL
RAISERROR('@SQLStringIndexes is null', 16, 1);
EXEC sp_executesql @SQLStringIndexes;
END
END /* Mode 0: Table schema output */
/* Table detail output */
IF @Mode = 1
BEGIN
IF @Verbose = 1
RAISERROR (N'Ouputting data for table detail output.', 0, 1) WITH NOWAIT;
/* Table output */
SELECT [object_id] = OBJECT_ID(QUOTENAME(@Schema) + '.' + QUOTENAME(@TableName)) ,
[schema_name] = @Schema ,
[table_name] = @TableName ,
[row_count] = @RowCount ,
[is_sample] = CASE @IsSample WHEN 1 THEN 'True' ELSE 'False' END;
SELECT [column_id] ,
[name] ,
[user_type] ,
[system_type] ,
[length] =
CASE
WHEN [length] = -1 AND [system_type] = 'xml' THEN NULL
WHEN [length] = -1 THEN 'max'
ELSE CAST([length] AS VARCHAR(50))
END,
[precision] ,
[scale] ,
[is_nullable] ,
[num_unique_values] ,
[unique_ratio] ,
[num_nulls] ,
[nulls_ratio] ,
[min_length] ,
[max_length]
FROM #table_column_profile;
IF @ShowForeignKeys = 1
BEGIN
IF @Verbose = 1
BEGIN
RAISERROR (N'Displaying Foreign Keys', 0, 1) WITH NOWAIT;
RAISERROR (@SQLStringFK, 0, 1) WITH NOWAIT;
END
IF @SQLStringFK IS NULL
RAISERROR('@SQLStringFK is null', 16, 1);
EXEC sp_executesql @SQLStringFK;
END
IF @ShowIndexes = 1
BEGIN
IF @Verbose = 1
BEGIN
RAISERROR (N'Displaying Indexes', 0, 1) WITH NOWAIT;
RAISERROR (@SQLStringIndexes, 0, 1) WITH NOWAIT;
END
IF @SQLStringIndexes IS NULL
RAISERROR('@SQLStringIndexes is null', 16, 1);
EXEC sp_executesql @SQLStringIndexes;
END
END /* Mode 1: Table detail output */
/* Column statistics output */
IF @Mode = 2
BEGIN
IF @Verbose = 1
RAISERROR (N'Ouputting data for column statistics output.', 0, 1) WITH NOWAIT;
/* Table output */
SELECT [object_id] = OBJECT_ID(QUOTENAME(@Schema) + '.' + QUOTENAME(@TableName)) ,
[schema_name] = @Schema ,
[table_name] = @TableName ,
[row_count] = @RowCount ,
[is_sample] = CASE @IsSample WHEN 1 THEN 'True' ELSE 'False' END;
SET @SQLString = N'
SELECT [column_id] ,
[name] ,
[user_type] ,
[system_type] ,
[length] =
CASE
WHEN [length] = -1 AND [system_type] = ''xml'' THEN NULL
WHEN [length] = -1 THEN ''max''
ELSE CAST([length] AS VARCHAR(50))
END,
[precision] ,
[scale] ,