Last active
August 29, 2016 23:17
-
-
Save EyePulp/0a7a28d8d3a31b6165dd1e97d8320f45 to your computer and use it in GitHub Desktop.
Create a viable copy of a table schema for moving redshift table data between DB's -- doesn't copy secondary index details (would be nice to get it improved to do that though) Edit the "source_table_name" string at the bottom to the table you want the structure for. This script DOES NOT create the table - merely creates the SQL statement necessa…
This file contains 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 pk.pkey, tm.schemaname||'.'||tm.tablename, 'create table '||tm.schemaname||'.'||tm.tablename | |
||' (' | |
||cp.coldef | |
-- primary key | |
||decode(pk.pkey,null,'',pk.pkey) | |
-- diststyle and dist key | |
||decode(d.distkey,null,')\n diststyle '||dist_style||' ',d.distkey) | |
--sort key | |
|| (select decode(skey,null,'',skey) from (select | |
' sortkey(' ||substr(array_to_string( | |
array( select ','||cast(column_name as varchar(100)) as str from | |
(select column_name from information_schema.columns col where col.table_schema= tm.schemaname and col.table_name=tm.tablename) c2 | |
join | |
(-- gives sort cols | |
select attrelid as tableid, attname as colname, attsortkeyord as sort_col_order from pg_attribute pa where | |
pa.attnum > 0 AND NOT pa.attisdropped AND pa.attsortkeyord > 0 | |
) st on tm.tableid=st.tableid and c2.column_name=st.colname order by sort_col_order | |
) | |
,'') | |
,2,10000) || ')' as skey | |
)) | |
||';' | |
-- additional alter table queries here to set owner | |
|| '\nalter table '||tm.schemaname||'.'||tm.tablename||' owner to "'||tm.owner||'";' | |
from | |
-- t master table list | |
( | |
SELECT substring(n.nspname,1,100) as schemaname, substring(c.relname,1,100) as tablename, c.oid as tableid ,use2.usename as owner, decode(c.reldiststyle,0,'EVEN',1,'KEY',8,'ALL') as dist_style | |
FROM pg_namespace n, pg_class c, pg_user use2 | |
WHERE n.oid = c.relnamespace | |
AND nspname NOT IN ('pg_catalog', 'pg_toast', 'information_schema') | |
AND c.relname <> 'temp_staging_tables_1' | |
and c.relowner = use2.usesysid | |
) tm | |
-- cp creates the col params for the create string | |
join | |
(select | |
substr(str,(charindex('QQQ',str)+3),(charindex('ZZZ',str))-(charindex('QQQ',str)+3)) as tableid | |
,substr(replace(replace(str,'ZZZ',''),'QQQ'||substr(str,(charindex('QQQ',str)+3),(charindex('ZZZ',str))-(charindex('QQQ',str)+3)),''),2,10000) as coldef | |
from | |
( select array_to_string(array( | |
SELECT 'QQQ'||cast(t.tableid as varchar(10))||'ZZZ'|| ',\n "'||column_name||'" '|| decode(udt_name,'bpchar','char',udt_name) || decode(character_maximum_length,null,'', '('||cast(character_maximum_length as varchar(9))||')' ) | |
-- default | |
|| decode(substr(column_default,2,8),'identity','',null,'',' default '||column_default||' ') | |
-- nullable | |
|| decode(is_nullable,'YES',' NULL ','NO',' NOT NULL ') | |
-- identity | |
|| decode(substr(column_default,2,8),'identity',' identity('||substr(column_default,(charindex('''',column_default)+1), (length(column_default)-charindex('''',reverse(column_default))-charindex('''',column_default) ) ) ||')\n ', '') | |
-- encoding | |
|| decode(enc,'none','',' encode '||enc) | |
as str | |
from | |
-- ci all the col info | |
( | |
select cast(t.tableid as int), cast(table_schema as varchar(100)), cast(table_name as varchar(100)), cast(column_name as varchar(100)), | |
cast(ordinal_position as int), cast(column_default as varchar(100)), cast(is_nullable as varchar(20)) , cast(udt_name as varchar(50)) ,cast(character_maximum_length as int), | |
sort_col_order , decode(d.colname,null,0,1) dist_key , e.enc | |
from | |
(select * from information_schema.columns c where c.table_schema= t.schemaname and c.table_name=t.tablename) c | |
left join | |
(-- gives sort cols | |
select attrelid as tableid, attname as colname, attsortkeyord as sort_col_order from pg_attribute a where | |
a.attnum > 0 AND NOT a.attisdropped AND a.attsortkeyord > 0 | |
) s on t.tableid=s.tableid and c.column_name=s.colname | |
left join | |
(-- gives encoding | |
select attrelid as tableid, attname as colname, format_encoding(a.attencodingtype::integer) AS enc from pg_attribute a where | |
a.attnum > 0 AND NOT a.attisdropped | |
) e on t.tableid=e.tableid and c.column_name=e.colname | |
left join | |
-- gives dist col | |
(select attrelid as tableid, attname as colname from pg_attribute a where | |
a.attnum > 0 AND NOT a.attisdropped AND a.attisdistkey = 't' | |
) d on t.tableid=d.tableid and c.column_name=d.colname | |
order by ordinal_position | |
) ci | |
-- for the working array funct | |
), '') as str | |
from | |
(-- need tableid | |
SELECT substring(n.nspname,1,100) as schemaname, substring(c.relname,1,100) as tablename, c.oid as tableid | |
FROM pg_namespace n, pg_class c | |
WHERE n.oid = c.relnamespace | |
AND nspname NOT IN ('pg_catalog', 'pg_toast', 'information_schema') | |
) t | |
)) cp on tm.tableid=cp.tableid | |
-- primary key query here | |
left join | |
(select c.oid as tableid, ',\n primary key '|| substring(pg_get_indexdef(indexrelid),charindex('(',pg_get_indexdef(indexrelid))-1 ,60) as pkey | |
from pg_index i , pg_namespace n, pg_class c | |
where i.indisprimary=true | |
and i.indrelid =c.oid | |
and n.oid = c.relnamespace | |
) pk on tm.tableid=pk.tableid | |
-- dist key | |
left join | |
( select | |
-- close off the col defs after the primary key | |
')\n' || | |
'distkey('|| cast(column_name as varchar(100)) ||')' as distkey, t.tableid | |
from information_schema.columns c | |
join | |
(-- need tableid | |
SELECT substring(n.nspname,1,100) as schemaname, substring(c.relname,1,100) as tablename, c.oid as tableid | |
FROM pg_namespace n, pg_class c | |
WHERE n.oid = c.relnamespace | |
AND nspname NOT IN ('pg_catalog', 'pg_toast', 'information_schema') | |
) t on c.table_schema= t.schemaname and c.table_name=t.tablename | |
join | |
-- gives dist col | |
(select attrelid as tableid, attname as colname from pg_attribute a where | |
a.attnum > 0 AND NOT a.attisdropped AND a.attisdistkey = 't' | |
) d on t.tableid=d.tableid and c.column_name=d.colname | |
) d on tm.tableid=d.tableid | |
where tm.schemaname||'.'||tm.tablename='public.source_table_name' |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment