forked from awslabs/amazon-redshift-utils
-
Notifications
You must be signed in to change notification settings - Fork 0
/
v_generate_tbl_ddl.sql
300 lines (294 loc) · 11.6 KB
/
v_generate_tbl_ddl.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
--DROP VIEW admin.v_generate_tbl_ddl;
/**********************************************************************************************
Purpose: View to get the DDL for a table. This will contain the distkey, sortkey, constraints,
not null, defaults, etc.
Notes: Default view ordering causes foreign keys to be created at the end.
This is needed due to dependencies of the foreign key constraint and the tables it
links. Due to this one should not manually order the output if you are expecting to
be able to replay the SQL directly from the VIEW query result. It is still possible to
order if you filter out the FOREIGN KEYS and then apply them later.
The following filters are useful:
where ddl not like 'ALTER TABLE %' -- do not return FOREIGN KEY CONSTRAINTS
where ddl like 'ALTER TABLE %' -- only get FOREIGN KEY CONSTRAINTS
where tablename in ('t1', 't2') -- only get DDL for specific tables
where schemaname in ('s1', 's2') -- only get DDL for specific schemas
So for example if you want to order DDL on tablename and only want the tables 't1', 't2'
and 't4' you can do so by using a query like:
select ddl from (
(
select
*
from admin.v_generate_tbl_ddl
where ddl not like 'ALTER TABLE %'
order by tablename
)
UNION ALL
(
select
*
from admin.v_generate_tbl_ddl
where ddl like 'ALTER TABLE %'
order by tablename
)
) where tablename in ('t1', 't2', 't4');
History:
2014-02-10 jjschmit Created
2015-05-18 ericfe Added support for Interleaved sortkey
2015-10-31 ericfe Added cast tp increase size of returning constraint name
2016-05-24 chriz-bigdata Added support for BACKUP NO tables
2017-05-03 pvbouwel Change table & schemaname of Foreign key constraints to allow for filters
2018-01-15 pvbouwel Add QUOTE_IDENT for identifiers (schema,table and column names)
2018-05-30 adedotua Add table_id column
2018-05-30 adedotua Added ENCODE RAW keyword for non compressed columns (Issue #308)
2018-10-12 dmenin Added table ownership to the script (as an alter table statment as the owner of the table is the issuer of the CREATE TABLE command)
2019-03-24 adedotua added filter for diststyle AUTO distribution style
2020-11-11 leisersohn Added COMMENT section
2021-25-03 venkat.yerneni Fixed Table COMMENTS and added Column COMMENTS
**********************************************************************************************/
CREATE OR REPLACE VIEW admin.v_generate_tbl_ddl
AS
SELECT
table_id
,REGEXP_REPLACE (schemaname, '^zzzzzzzz', '') AS schemaname
,REGEXP_REPLACE (tablename, '^zzzzzzzz', '') AS tablename
,seq
,ddl
FROM
(
SELECT
table_id
,schemaname
,tablename
,seq
,ddl
FROM
(
--DROP TABLE
SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,0 AS seq
,'--DROP TABLE ' + QUOTE_IDENT(n.nspname) + '.' + QUOTE_IDENT(c.relname) + ';' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
--CREATE TABLE
UNION SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,2 AS seq
,'CREATE TABLE IF NOT EXISTS ' + QUOTE_IDENT(n.nspname) + '.' + QUOTE_IDENT(c.relname) + '' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
--OPEN PAREN COLUMN LIST
UNION SELECT c.oid::bigint as table_id,n.nspname AS schemaname, c.relname AS tablename, 5 AS seq, '(' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
--COLUMN LIST
UNION SELECT
table_id
,schemaname
,tablename
,seq
,'\t' + col_delim + col_name + ' ' + col_datatype + ' ' + col_nullable + ' ' + col_default + ' ' + col_encoding AS ddl
FROM
(
SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,100000000 + a.attnum AS seq
,CASE WHEN a.attnum > 1 THEN ',' ELSE '' END AS col_delim
,QUOTE_IDENT(a.attname) AS col_name
,CASE WHEN STRPOS(UPPER(format_type(a.atttypid, a.atttypmod)), 'CHARACTER VARYING') > 0
THEN REPLACE(UPPER(format_type(a.atttypid, a.atttypmod)), 'CHARACTER VARYING', 'VARCHAR')
WHEN STRPOS(UPPER(format_type(a.atttypid, a.atttypmod)), 'CHARACTER') > 0
THEN REPLACE(UPPER(format_type(a.atttypid, a.atttypmod)), 'CHARACTER', 'CHAR')
ELSE UPPER(format_type(a.atttypid, a.atttypmod))
END AS col_datatype
,CASE WHEN format_encoding((a.attencodingtype)::integer) = 'none'
THEN 'ENCODE RAW'
ELSE 'ENCODE ' + format_encoding((a.attencodingtype)::integer)
END AS col_encoding
,CASE WHEN a.atthasdef IS TRUE THEN 'DEFAULT ' + adef.adsrc ELSE '' END AS col_default
,CASE WHEN a.attnotnull IS TRUE THEN 'NOT NULL' ELSE '' END AS col_nullable
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN pg_attribute AS a ON c.oid = a.attrelid
LEFT OUTER JOIN pg_attrdef AS adef ON a.attrelid = adef.adrelid AND a.attnum = adef.adnum
WHERE c.relkind = 'r'
AND a.attnum > 0
ORDER BY a.attnum
)
--CONSTRAINT LIST
UNION (SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,200000000 + CAST(con.oid AS INT) AS seq
,'\t,' + pg_get_constraintdef(con.oid) AS ddl
FROM pg_constraint AS con
INNER JOIN pg_class AS c ON c.relnamespace = con.connamespace AND c.oid = con.conrelid
INNER JOIN pg_namespace AS n ON n.oid = c.relnamespace
WHERE c.relkind = 'r' AND pg_get_constraintdef(con.oid) NOT LIKE 'FOREIGN KEY%'
ORDER BY seq)
--CLOSE PAREN COLUMN LIST
UNION SELECT c.oid::bigint as table_id,n.nspname AS schemaname, c.relname AS tablename, 299999999 AS seq, ')' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
--BACKUP
UNION SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,300000000 AS seq
,'BACKUP NO' as ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN (SELECT
SPLIT_PART(key,'_',5) id
FROM pg_conf
WHERE key LIKE 'pg_class_backup_%'
AND SPLIT_PART(key,'_',4) = (SELECT
oid
FROM pg_database
WHERE datname = current_database())) t ON t.id=c.oid
WHERE c.relkind = 'r'
--BACKUP WARNING
UNION SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,1 AS seq
,'--WARNING: This DDL inherited the BACKUP NO property from the source table' as ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN (SELECT
SPLIT_PART(key,'_',5) id
FROM pg_conf
WHERE key LIKE 'pg_class_backup_%'
AND SPLIT_PART(key,'_',4) = (SELECT
oid
FROM pg_database
WHERE datname = current_database())) t ON t.id=c.oid
WHERE c.relkind = 'r'
--DISTSTYLE
UNION SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,300000001 AS seq
,CASE WHEN c.reldiststyle = 0 THEN 'DISTSTYLE EVEN'
WHEN c.reldiststyle = 1 THEN 'DISTSTYLE KEY'
WHEN c.reldiststyle = 8 THEN 'DISTSTYLE ALL'
WHEN c.reldiststyle = 9 THEN 'DISTSTYLE AUTO'
ELSE '<<Error - UNKNOWN DISTSTYLE>>'
END AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
--DISTKEY COLUMNS
UNION SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,400000000 + a.attnum AS seq
,' DISTKEY (' + QUOTE_IDENT(a.attname) + ')' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN pg_attribute AS a ON c.oid = a.attrelid
WHERE c.relkind = 'r'
AND a.attisdistkey IS TRUE
AND a.attnum > 0
--SORTKEY COLUMNS
UNION select table_id,schemaname, tablename, seq,
case when min_sort <0 then 'INTERLEAVED SORTKEY (' else ' SORTKEY (' end as ddl
from (SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,499999999 AS seq
,min(attsortkeyord) min_sort FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN pg_attribute AS a ON c.oid = a.attrelid
WHERE c.relkind = 'r'
AND abs(a.attsortkeyord) > 0
AND a.attnum > 0
group by 1,2,3,4 )
UNION (SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,500000000 + abs(a.attsortkeyord) AS seq
,CASE WHEN abs(a.attsortkeyord) = 1
THEN '\t' + QUOTE_IDENT(a.attname)
ELSE '\t, ' + QUOTE_IDENT(a.attname)
END AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN pg_attribute AS a ON c.oid = a.attrelid
WHERE c.relkind = 'r'
AND abs(a.attsortkeyord) > 0
AND a.attnum > 0
ORDER BY abs(a.attsortkeyord))
UNION SELECT
c.oid::bigint as table_id
,n.nspname AS schemaname
,c.relname AS tablename
,599999999 AS seq
,'\t)' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN pg_attribute AS a ON c.oid = a.attrelid
WHERE c.relkind = 'r'
AND abs(a.attsortkeyord) > 0
AND a.attnum > 0
--END SEMICOLON
UNION SELECT c.oid::bigint as table_id ,n.nspname AS schemaname, c.relname AS tablename, 600000000 AS seq, ';' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
--COMMENT
UNION
SELECT c.oid::bigint AS table_id,
n.nspname AS schemaname,
c.relname AS tablename,
600250000 AS seq,
('COMMENT ON '::text + nvl2(cl.column_name, 'column '::text, 'table '::text) + quote_ident(n.nspname::text) + '.'::text + quote_ident(c.relname::text) + nvl2(cl.column_name, '.'::text + cl.column_name::text, ''::text) + ' IS \''::text + quote_ident(des.description) + '\'; '::text)::character VARYING AS ddl
FROM pg_description des
JOIN pg_class c ON c.oid = des.objoid
JOIN pg_namespace n ON n.oid = c.relnamespace
LEFT JOIN information_schema."columns" cl
ON cl.ordinal_position::integer = des.objsubid AND cl.table_name::NAME = c.relname
WHERE c.relkind = 'r'
UNION
--TABLE OWNERSHIP AS AN ALTER TABLE STATMENT
SELECT c.oid::bigint as table_id ,n.nspname AS schemaname, c.relname AS tablename, 600500000 AS seq,
'ALTER TABLE ' + QUOTE_IDENT(n.nspname) + '.' + QUOTE_IDENT(c.relname) + ' owner to '+ QUOTE_IDENT(u.usename) +';' AS ddl
FROM pg_namespace AS n
INNER JOIN pg_class AS c ON n.oid = c.relnamespace
INNER JOIN pg_user AS u ON c.relowner = u.usesysid
WHERE c.relkind = 'r'
)
UNION (
SELECT c.oid::bigint as table_id,'zzzzzzzz' || n.nspname AS schemaname,
'zzzzzzzz' || c.relname AS tablename,
700000000 + CAST(con.oid AS INT) AS seq,
'ALTER TABLE ' + QUOTE_IDENT(n.nspname) + '.' + QUOTE_IDENT(c.relname) + ' ADD ' + pg_get_constraintdef(con.oid)::VARCHAR(1024) + ';' AS ddl
FROM pg_constraint AS con
INNER JOIN pg_class AS c
ON c.relnamespace = con.connamespace
AND c.oid = con.conrelid
INNER JOIN pg_namespace AS n ON n.oid = c.relnamespace
WHERE c.relkind = 'r'
AND con.contype = 'f'
ORDER BY seq
)
ORDER BY table_id,schemaname, tablename, seq
)
;