Last active
April 24, 2020 04:57
-
-
Save mehuled/25c901d430caf0374b9c97d45e4822a2 to your computer and use it in GitHub Desktop.
Redshift DDL Generation without Encoding & Sort Key Styles.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
--CREATE THE VIEW TO GENERATE DDL | |
-- Orginal DDL courtesy : https://github.com/awslabs/amazon-redshift-utils/blob/master/src/AdminViews/v_generate_tbl_ddl.sql | |
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 '' | |
ELSE '' | |
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' | |
--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' | |
) | |
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 | |
) | |
; |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
SELECT ddl FROM admin.v_generate_tbl_ddl WHERE schemaname = '{schema_name}' AND tablename = '{table_name}' ; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment