1
+ -- ---------------------------------------------------------------------------------
2
+ -- Data Dictionary Dump:
3
+ -- This SQL script will dump table, column, key, and description design related
4
+ -- metadata so that you can copy-paste or export to Excel as a Data Dictionary.
5
+ -- ----------------------------------------------------------------------------------
6
+ -- Platform: SQL Server
7
+ -- Author: DataResearchLabs
8
+ -- GitHub: https://github.com/DataResearchLabs/sql_scripts
9
+ -- GitHub Tool: https://github.com/DataResearchLabs/data_analysts_toolbox/blob/main/data_dictionary_generator/readme.md
10
+ -- --------------------------------------------------------------------------------
11
+
12
+ -- IMPORTANT
13
+ USE AdventureWorksLT2019; -- <<<<<<<<<<<< CHANGE THIS VALUE to Schema you want to dump
14
+ ;
15
+
16
+ -- All variables are consolidated here in the first CTE (Common Table Expression)
17
+ -- Each given row is a variable, with the value you change preceding the "AS" command
18
+ WITH vars
19
+ AS (
20
+ SELECT
21
+ DB_NAME() AS v_SchemaName -- (Do not change this value, it is picked up from changes above)
22
+ , ' NO' AS v_TablesOnly -- Change this setting: YES=Limit To Tables only; NO=Include views too
23
+ )
24
+
25
+
26
+ , baseTbl
27
+ AS (
28
+ SELECT TABLE_CATALOG AS SchemaName, table_type, table_name, table_schema
29
+ FROM INFORMATION_SCHEMA .TABLES
30
+ WHERE TABLE_CATALOG = (SELECT v_SchemaName FROM vars)
31
+ AND ( (TABLE_TYPE = ' BASE TABLE' )
32
+ OR ((SELECT v_TablesOnly FROM vars) = ' NO' )
33
+ )
34
+ )
35
+
36
+
37
+ , metadata
38
+ AS (
39
+ SELECT
40
+ bt .SchemaName AS schema_nm
41
+ , bt .table_name AS table_nm
42
+ , CASE WHEN bt .table_type = ' BASE TABLE' THEN ' TBL'
43
+ WHEN bt .table_type = ' VIEW' THEN ' VW'
44
+ ELSE ' UK'
45
+ END AS obj_typ
46
+ , RIGHT(' 000' + CAST(tut .ORDINAL_POSITION AS VARCHAR (3 )), 3 ) AS ord_pos
47
+ , tut .column_name AS column_nm
48
+ , COALESCE(tut .data_type , ' unknown' ) +
49
+ CASE WHEN tut .data_type IN (' varchar' ,' nvarchar' ) THEN ' (' + CAST(tut .CHARACTER_MAXIMUM_LENGTH AS VARCHAR (10 )) + ' )'
50
+ WHEN tut .data_type IN (' char' ,' nchar' ) THEN ' (' + CAST(tut .CHARACTER_MAXIMUM_LENGTH AS VARCHAR (10 )) + ' )'
51
+ WHEN tut .data_type = ' date' THEN ' (' + CAST(tut .DATETIME_PRECISION AS VARCHAR (10 )) + ' )'
52
+ WHEN tut .data_type = ' datetime' THEN ' (' + CAST(tut .DATETIME_PRECISION AS VARCHAR (10 )) + ' )'
53
+ WHEN tut .data_type in (' bigint' ,' int' ,' smallint' , ' tinyint' ) THEN ' (' + CAST(tut .NUMERIC_PRECISION AS VARCHAR (10 )) + ' )'
54
+ WHEN tut .data_type = ' uniqueidentifier' THEN ' (16)'
55
+ WHEN tut .data_type = ' money' THEN ' (' + CAST(tut .NUMERIC_PRECISION AS VARCHAR (10 )) + ' )'
56
+ WHEN tut .data_type = ' decimal' THEN ' (' + CAST(tut .NUMERIC_PRECISION AS VARCHAR (10 )) + ' ,' + CAST(tut .NUMERIC_SCALE AS VARCHAR (10 )) + ' )'
57
+ WHEN tut .data_type = ' numeric' THEN ' (' + CAST(tut .NUMERIC_PRECISION AS VARCHAR (10 )) + ' ,' + CAST(tut .NUMERIC_SCALE AS VARCHAR (10 )) + ' )'
58
+ WHEN tut .data_type = ' varbinary' THEN ' (' + CAST(tut .CHARACTER_MAXIMUM_LENGTH AS VARCHAR (10 )) + ' )'
59
+ WHEN tut .data_type = ' xml' THEN ' (' + CAST(tut .CHARACTER_MAXIMUM_LENGTH AS VARCHAR (10 )) + ' )'
60
+ WHEN tut .data_type IN (' char' ,' nchar' ) THEN ' (' + CAST(tut .CHARACTER_MAXIMUM_LENGTH AS VARCHAR (10 )) + ' )'
61
+ WHEN tut .CHARACTER_MAXIMUM_LENGTH IS NOT NULL THEN ' (' + CAST(tut .CHARACTER_MAXIMUM_LENGTH AS VARCHAR (10 )) + ' )'
62
+ WHEN tut .DATETIME_PRECISION IS NOT NULL THEN ' (' + CAST(tut .DATETIME_PRECISION AS VARCHAR (10 )) + ' )'
63
+ WHEN tut .NUMERIC_PRECISION IS NOT NULL
64
+ AND tut .NUMERIC_SCALE IS NULL THEN ' (' + CAST(tut .NUMERIC_PRECISION AS VARCHAR (10 )) + ' )'
65
+ WHEN tut .NUMERIC_PRECISION IS NOT NULL
66
+ AND tut .NUMERIC_SCALE IS NOT NULL THEN ' (' + CAST(tut .NUMERIC_PRECISION AS VARCHAR (10 )) + ' ,' + CAST(tut .NUMERIC_SCALE AS VARCHAR (10 )) + ' )'
67
+ ELSE ' '
68
+ END AS data_typ
69
+ , CASE WHEN tut .IS_NULLABLE = ' YES' THEN ' NULL' ELSE ' NOT NULL' END AS nullable
70
+ FROM INFORMATION_SCHEMA .COLUMNS tut
71
+ INNER JOIN baseTbl bt ON bt .SchemaName = tut .TABLE_CATALOG AND bt .table_name = tut .table_name
72
+ )
73
+
74
+ , descr
75
+ AS (
76
+ SELECT
77
+ bt .SchemaName AS schema_nm
78
+ , bt .table_name AS table_nm
79
+ , tut .column_name AS column_nm
80
+ , STRING_AGG(CAST(de .value AS VARCHAR (1024 )), ' . ' ) WITHIN GROUP (ORDER BY de .value ) AS description
81
+ FROM INFORMATION_SCHEMA .COLUMNS tut
82
+ INNER JOIN baseTbl bt ON bt .SchemaName = tut .TABLE_CATALOG AND bt .table_name = tut .table_name
83
+ LEFT JOIN sys .extended_properties de ON de .major_id = OBJECT_ID(bt .table_schema + ' .' + bt .table_name )
84
+ AND de .minor_id = tut .ORDINAL_POSITION
85
+ AND de .name = ' MS_Description'
86
+ GROUP BY bt .SchemaName , bt .table_name , tut .column_name
87
+ )
88
+
89
+
90
+ , metadata_keys
91
+ AS (
92
+ SELECT schema_nm, table_nm, column_nm
93
+ , STRING_AGG(key_typ, ' ,' ) WITHIN GROUP (ORDER BY key_typ) AS is_key
94
+ FROM (
95
+ SELECT
96
+ cons .TABLE_CATALOG AS schema_nm
97
+ , cons .TABLE_NAME AS table_nm
98
+ , kcu .COLUMN_NAME AS column_nm
99
+ , CASE WHEN cons .CONSTRAINT_TYPE = ' PRIMARY KEY' THEN ' PK'
100
+ WHEN cons .CONSTRAINT_TYPE = ' UNIQUE' THEN ' UK'
101
+ WHEN cons .CONSTRAINT_TYPE = ' FOREIGN KEY' THEN ' FK'
102
+ ELSE ' X'
103
+ END AS key_typ
104
+ FROM INFORMATION_SCHEMA .TABLE_CONSTRAINTS cons
105
+ INNER JOIN INFORMATION_SCHEMA .KEY_COLUMN_USAGE kcu
106
+ ON cons .TABLE_CATALOG = kcu .TABLE_CATALOG
107
+ AND cons .TABLE_NAME = kcu .TABLE_NAME
108
+ AND cons .CONSTRAINT_NAME = kcu .CONSTRAINT_NAME
109
+ WHERE cons .TABLE_CATALOG = (SELECT v_SchemaName FROM vars)
110
+ AND cons .table_name IN (SELECT DISTINCT table_name FROM baseTbl)
111
+ AND cons .constraint_type IN (' PRIMARY KEY' ,' FOREIGN KEY' ,' UNIQUE' )
112
+ GROUP BY cons .TABLE_CATALOG , cons .TABLE_NAME , kcu .COLUMN_NAME , cons .CONSTRAINT_TYPE
113
+ ) AS t
114
+ GROUP BY schema_nm, table_nm, column_nm
115
+ )
116
+
117
+
118
+ SELECT md .schema_nm , md .table_nm , md .obj_typ , md .ord_pos
119
+ , COALESCE(mk .is_key , ' ' ) AS keys
120
+ , md .column_nm , md .data_typ , md .nullable
121
+ , de.[description]
122
+ FROM metadata md
123
+ LEFT JOIN descr de ON de .schema_nm = md .schema_nm AND de .table_nm = md .table_nm AND de .column_nm = md .column_nm
124
+ LEFT JOIN metadata_keys mk ON mk .schema_nm = md .schema_nm AND mk .table_nm = md .table_nm AND mk .column_nm = md .column_nm
125
+ ORDER BY schema_nm, table_nm, ord_pos
0 commit comments