@@ -3,14 +3,15 @@ CREATE PROCEDURE [dbo].[sp_doc]
3
3
@DatabaseName SYSNAME = NULL
4
4
,@ExtendedPropertyName SYSNAME = 'Description'
5
5
,@LimitStoredProcLength BIT = 1
6
+ ,@Emojis BIT = 0
6
7
/* Parameters defined here for testing only */
7
8
,@SqlMajorVersion TINYINT = 0
8
9
,@SqlMinorVersion SMALLINT = 0
9
10
WITH RECOMPILE
10
11
AS
11
12
12
13
/*
13
- sp_doc - Part of the ExpressSQL Suite https://expresssql.lowlydba.com/
14
+ sp_doc - Part of the DBA MultiTool https://expresssql.lowlydba.com/
14
15
15
16
Version: 09112020
16
17
47
48
,@ParmDefinition NVARCHAR(500)
48
49
,@QuotedDatabaseName SYSNAME
49
50
,@Msg NVARCHAR(MAX)
50
- ,@LastUpdated NVARCHAR(20) = '2020-09-22';
51
-
51
+ ,@LastUpdated NVARCHAR(20) = '2020-10-01'
52
+ -- Variables used for Emoji mode
53
+ ,@Yes VARCHAR(20) = 'yes'
54
+ ,@No VARCHAR(20) = 'no'
55
+ ,@PK VARCHAR(20) = NULL
56
+ ,@FK VARCHAR(20) = NULL
57
+ ,@Column VARCHAR(20) = NULL;
52
58
53
59
-- Find Version
54
60
IF (@SqlMajorVersion = 0)
67
73
RAISERROR(@Msg, 16, 1);
68
74
END;
69
75
70
- --Check database name
76
+ -- Check database name
71
77
IF (@DatabaseName IS NULL)
72
78
BEGIN
73
79
SET @DatabaseName = DB_NAME();
78
84
RAISERROR(@Msg, 16, 1);
79
85
END;
80
86
87
+ -- Check Emoji Mode
88
+ IF (@Emojis = 1)
89
+ BEGIN;
90
+ SET @Yes = ':heavy_check_mark:';
91
+ SET @No = ':x:';
92
+ SET @PK = ':key: ';
93
+ SET @FK = ':old_key: ';
94
+ SET @Column = ':page_facing_up: ';
95
+ END;
96
+
81
97
SET @QuotedDatabaseName = QUOTENAME(@DatabaseName); --Avoid injections
82
98
83
99
--Create table to hold EP data
@@ -162,8 +178,10 @@ BEGIN
162
178
SELECT CONCAT(''| ''
163
179
,CASE
164
180
WHEN [ic].[object_id] IS NOT NULL
165
- THEN ISNULL(CONCAT(''**'',[c].[name],''**''), ''N/A'')
166
- ELSE ISNULL([c].[name], ''N/A'')
181
+ THEN CONCAT(@PK, ''**'',[c].[name],''**'')
182
+ WHEN [fk].[parent_object_id] IS NOT NULL
183
+ THEN CONCAT(@FK, [c].[name])
184
+ ELSE CONCAT(@Column, [c].[name])
167
185
END
168
186
,'' | ''
169
187
,CONCAT(UPPER(TYPE_NAME([user_type_id]))
@@ -199,14 +217,14 @@ BEGIN
199
217
,'' | ''
200
218
,CASE [c].[is_nullable]
201
219
WHEN 1
202
- THEN ''yes''
203
- ELSE ''no''
220
+ THEN @Yes
221
+ ELSE @No
204
222
END
205
223
,'' | ''
206
224
,CASE
207
- WHEN [fk].[parent_object_id] IS NULL
208
- THEN ''''
209
- ELSE CONCAT(''['',QUOTENAME(OBJECT_SCHEMA_NAME([fk].[referenced_object_id])), ''.'', QUOTENAME(OBJECT_NAME([fk].[referenced_object_id])), ''.'', QUOTENAME(COL_NAME([fk].[referenced_object_id], [fk].[referenced_column_id])),'']'',''(#'',LOWER(OBJECT_SCHEMA_NAME([fk].[referenced_object_id])), LOWER(OBJECT_NAME([fk].[referenced_object_id])), '')'')
225
+ WHEN [fk].[parent_object_id] IS NOT NULL
226
+ THEN CONCAT(''['',QUOTENAME(OBJECT_SCHEMA_NAME([fk].[referenced_object_id])), ''.'', QUOTENAME(OBJECT_NAME([fk].[referenced_object_id])), ''.'', QUOTENAME(COL_NAME([fk].[referenced_object_id], [fk].[referenced_column_id])),'']'',''(#'',LOWER(OBJECT_SCHEMA_NAME([fk].[referenced_object_id])), LOWER(OBJECT_NAME([fk].[referenced_object_id])), '')'')
227
+ ELSE ''''
210
228
END
211
229
,'' | ''
212
230
,OBJECT_DEFINITION([dc].[object_id])
@@ -408,8 +426,8 @@ BEGIN
408
426
,'' | ''
409
427
,CASE [c].[is_nullable]
410
428
WHEN 1
411
- THEN ''yes''
412
- ELSE ''no''
429
+ THEN @Yes
430
+ ELSE @No
413
431
END
414
432
,'' | ''
415
433
,CAST([ep].[value] AS VARCHAR(8000))
@@ -536,8 +554,8 @@ BEGIN
536
554
,'' | ''
537
555
,CASE [is_output]
538
556
WHEN 1
539
- THEN ''yes''
540
- ELSE ''no''
557
+ THEN @Yes
558
+ ELSE @No
541
559
END
542
560
,'' | ''
543
561
,CAST([ep].[value] AS VARCHAR(8000))
@@ -679,8 +697,8 @@ BEGIN
679
697
,'' | ''
680
698
,CASE [is_output]
681
699
WHEN 1
682
- THEN ''yes''
683
- ELSE ''no''
700
+ THEN @Yes
701
+ ELSE @No
684
702
END
685
703
,'' | ''
686
704
,CAST([ep].[value] AS VARCHAR(8000))
@@ -804,8 +822,8 @@ BEGIN
804
822
,'' | ''
805
823
,CASE [is_output]
806
824
WHEN 1
807
- THEN ''yes''
808
- ELSE ''no''
825
+ THEN @Yes
826
+ ELSE @No
809
827
END
810
828
,'' | ''
811
829
,CAST([ep].[value] AS VARCHAR(8000))
@@ -916,10 +934,144 @@ BEGIN
916
934
--End collapsible synonyms section
917
935
+ N'INSERT INTO #markdown
918
936
VALUES (CONCAT(CHAR(13), CHAR(10), ''</details>''));
919
- END;' --End markdown for synonyms
937
+ END;'; --End markdown for synonyms
938
+
939
+ /***********************************************
940
+ Generate markdown for user defined table types
941
+ ***********************************************/
942
+ --Build table of contents
943
+ SET @Sql = @Sql + N'
944
+ IF EXISTS (SELECT 1 FROM [sys].[all_objects] WHERE [type] = ''TT'')
945
+ BEGIN
946
+ INSERT INTO #markdown (value)
947
+ VALUES (CONCAT(CHAR(13), CHAR(10), ''## User Defined Table Types''))
948
+ ,(CONCAT(CHAR(13), CHAR(10), ''<details><summary>Click to expand</summary>'', CHAR(13), CHAR(10)));
949
+ ' +
950
+
951
+ + N'INSERT INTO #markdown (value)
952
+ SELECT CONCAT(''* ['', SCHEMA_NAME([schema_id]), ''.'', [name], ''](#'', REPLACE(LOWER(SCHEMA_NAME([schema_id])), '' '', ''-''), REPLACE(LOWER([name]), '' '', ''-''), '')'')
953
+ FROM [sys].[table_types]
954
+ WHERE [is_user_defined] = 1
955
+ ORDER BY OBJECT_SCHEMA_NAME([type_table_object_id]), [name] ASC;' +
956
+
957
+ --Object details
958
+ + N'DECLARE Obj_Cursor CURSOR
959
+ LOCAL STATIC READ_ONLY FORWARD_ONLY
960
+ FOR
961
+ SELECT [type_table_object_id]
962
+ FROM [sys].[table_types]
963
+ WHERE [is_user_defined] = 1
964
+ ORDER BY OBJECT_SCHEMA_NAME([type_table_object_id]), [name] ASC;
965
+
966
+ OPEN Obj_Cursor
967
+ FETCH NEXT FROM Obj_Cursor INTO @objectid
968
+ WHILE @@FETCH_STATUS = 0
969
+ BEGIN
970
+
971
+ INSERT INTO #markdown
972
+ SELECT CONCAT(CHAR(13), CHAR(10), ''### '', SCHEMA_NAME([schema_id]), ''.'', [name])
973
+ FROM [sys].[table_types]
974
+ WHERE [type_table_object_id] = @objectid;' +
975
+
976
+ --Extended Properties
977
+ + N'INSERT INTO #markdown
978
+ SELECT CONCAT(CHAR(13), CHAR(10), CAST([ep].[value] AS VARCHAR(8000)))
979
+ FROM [sys].[all_objects] AS [o]
980
+ INNER JOIN [sys].[extended_properties] AS [ep] ON [o].[object_id] = [ep].[major_id]
981
+ WHERE [o].[object_id] = @objectid
982
+ AND [ep].[minor_id] = 0 --On the table
983
+ AND [ep].[name] = @ExtendedPropertyName;
984
+
985
+ INSERT INTO #markdown (value)
986
+ VALUES ('''')
987
+ ,(CONCAT(''| Column | Type | Null | Default | '', @ExtendedPropertyName COLLATE DATABASE_DEFAULT, '' |''))
988
+ ,(''| --- | ---| --- | --- | --- |'');' +
989
+
990
+ --Columns
991
+ + N'INSERT INTO #markdown
992
+ SELECT CONCAT(''| ''
993
+ ,CASE
994
+ WHEN [ic].[object_id] IS NOT NULL
995
+ THEN ISNULL(CONCAT(''**'',[c].[name],''**''), ''N/A'')
996
+ ELSE ISNULL([c].[name], ''N/A'')
997
+ END
998
+ ,'' | ''
999
+ ,CONCAT(UPPER(TYPE_NAME([c].[user_type_id]))
1000
+ ,CASE
1001
+ WHEN TYPE_NAME([c].[user_type_id]) IN (N''decimal'',N''numeric'')
1002
+ THEN CONCAT(N''('',CAST([c].[precision] AS VARCHAR(5)), N'','',CAST([c].[scale] AS varchar(5)), N'')'')
1003
+ WHEN TYPE_NAME([c].[user_type_id]) IN (''varchar'', ''char'', ''varbinary'')
1004
+ THEN CASE
1005
+ WHEN [c].[max_length] = -1
1006
+ THEN N''(MAX)''
1007
+ ELSE QUOTENAME(CAST([c].[max_length] AS VARCHAR(10)), ''('')
1008
+ END
1009
+ WHEN TYPE_NAME([c].[user_type_id]) IN (N''time'',N''datetime2'',N''datetimeoffset'')
1010
+ THEN QUOTENAME(CAST([c].[scale] AS VARCHAR(5)), ''('')
1011
+ WHEN TYPE_NAME([c].[user_type_id]) in (N''float'')
1012
+ THEN CASE
1013
+ WHEN [c].precision = 53
1014
+ THEN N''''
1015
+ ELSE CONCAT(N''('',CAST([c].[precision] AS VARCHAR(5)),N'')'')
1016
+ END
1017
+ WHEN TYPE_NAME([c].[user_type_id]) IN (N''int'',N''bigint'',N''smallint'',N''tinyint'',N''money'',N''smallmoney'',
1018
+ N''real'',N''datetime'',N''smalldatetime'',N''bit'',N''image'',N''text'',N''uniqueidentifier'',
1019
+ N''date'',N''ntext'',N''sql_variant'',N''hierarchyid'',''geography'',N''timestamp'',N''xml'')
1020
+ THEN N''''
1021
+ WHEN TYPE_NAME([c].[user_type_id]) IN (N''nvarchar'',N''nchar'', N''sysname'')
1022
+ THEN CASE
1023
+ WHEN [c].[max_length] = -1
1024
+ THEN N''(MAX)''
1025
+ ELSE QUOTENAME(CAST([c].[max_length]/2 AS VARCHAR(10)), ''('')
1026
+ END
1027
+ ELSE QUOTENAME(CAST([c].[max_length] AS VARCHAR(10)), ''('')
1028
+ END)
1029
+ ,'' | ''
1030
+ ,CASE [c].[is_nullable]
1031
+ WHEN 1
1032
+ THEN @Yes
1033
+ ELSE @No
1034
+ END
1035
+ ,'' | ''
1036
+ ,OBJECT_DEFINITION([dc].[object_id])
1037
+ ,'' | ''
1038
+ ,CAST([ep].[value] AS VARCHAR(8000))
1039
+ ,'' |'')
1040
+ FROM [sys].[table_types] AS [tt]
1041
+ INNER JOIN [sys].[columns] AS [c] ON [tt].[type_table_object_id] = [c].[object_id]
1042
+ LEFT JOIN [sys].[extended_properties] AS [ep] ON [tt].[type_table_object_id] = [ep].[major_id]
1043
+ AND [ep].[minor_id] > 0
1044
+ AND [ep].[minor_id] = [c].[column_id]
1045
+ AND [ep].[class] = 1 --Object/col
1046
+ -- AND [ep].[name] = @ExtendedPropertyName
1047
+ LEFT JOIN [sys].[foreign_key_columns] AS [fk] ON [fk].[parent_object_id] = [c].[object_id]
1048
+ AND [fk].[parent_column_id] = [c].[column_id]
1049
+ LEFT JOIN [sys].[default_constraints] [dc] ON [dc].[parent_object_id] = [c].[object_id]
1050
+ AND [dc].[parent_column_id] = [c].[column_id]
1051
+ LEFT JOIN [sys].[indexes] AS [pk] ON [pk].[object_id] = [tt].[type_table_object_id]
1052
+ AND [pk].[is_primary_key] = 1
1053
+ LEFT JOIN [sys].[index_columns] AS [ic] ON [ic].[index_id] = [pk].[index_id]
1054
+ AND [ic].[object_id] = [tt].[type_table_object_id]
1055
+ AND [ic].[column_id] = [c].[column_id]
1056
+ WHERE [tt].[type_table_object_id] = @objectid;' +
1057
+
1058
+ --Back to top
1059
+ + N'INSERT INTO #markdown
1060
+ VALUES (CONCAT(CHAR(13), CHAR(10), ''[Back to top](#'', LOWER(@DatabaseName COLLATE DATABASE_DEFAULT), '')''))
1061
+
1062
+ FETCH NEXT FROM Obj_Cursor INTO @objectid;
1063
+
1064
+ END;
1065
+ CLOSE Obj_Cursor;
1066
+ DEALLOCATE Obj_Cursor;' +
1067
+
1068
+ --End collapsible table section
1069
+ + N'INSERT INTO #markdown
1070
+ VALUES (CONCAT(CHAR(13), CHAR(10), ''</details>''));
1071
+ END;'; --End markdown for user defined table types
920
1072
921
1073
--Attribution
922
- + N'INSERT INTO #markdown
1074
+ SET @Sql = @Sql + N'INSERT INTO #markdown
923
1075
VALUES (CONCAT(CHAR(13), CHAR(10), ''----''))
924
1076
,(CONCAT(CHAR(13), CHAR(10), ''*Markdown generated by [sp_doc](https://expresssql.lowlydba.com/)''))
925
1077
,(CONCAT('' at '', SYSDATETIMEOFFSET(), ''.*''));';
@@ -930,12 +1082,17 @@ BEGIN
930
1082
FROM #markdown
931
1083
ORDER BY [ID] ASC;';
932
1084
933
- SET @ParmDefinition = N'@ExtendedPropertyName SYSNAME, @DatabaseName SYSNAME, @LimitStoredProcLength BIT';
1085
+ SET @ParmDefinition = N'@ExtendedPropertyName SYSNAME, @DatabaseName SYSNAME, @LimitStoredProcLength BIT, @Yes VARCHAR(20), @No VARCHAR(20), @PK VARCHAR(20), @FK VARCHAR(20), @Column VARCHAR(20) ';
934
1086
EXEC sp_executesql @Sql
935
1087
,@ParmDefinition
936
1088
,@ExtendedPropertyName
937
1089
,@DatabaseName
938
- ,@LimitStoredProcLength;
1090
+ ,@LimitStoredProcLength
1091
+ ,@Yes
1092
+ ,@No
1093
+ ,@PK
1094
+ ,@FK
1095
+ ,@Column;
939
1096
END;
940
1097
941
1098
0 commit comments