--select * from dropall('migration_inspect','meta'); CREATE OR REPLACE FUNCTION meta.migration_inspect( p_id_migration_model integer default null ,INOUT p_info jsonb default null ,OUT p_retval integer ,OUT p_errmsg text ) LANGUAGE plpgsql VOLATILE SECURITY DEFINER AS $$ DECLARE --Error Handling-- m_funcname text = 'meta.migration_inspect'; m_errmsg text; m_errcontext text; m_errdetail text; m_errhint text; m_errstate text; m_retval integer; --Error Handling-- m_rowcnt integer; BEGIN p_retval = 0; p_errmsg = ''; --perform log_event(m_funcname,'init',bt_enum('eventlog','local notice')); perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',1,'objecttype',m_funcname)::text); delete from meta.migration_table where isdb; insert into meta.migration_table( rid_migration_model ,tablename ,guid ,schemaname ,isdb ,ismodel ) select p_id_migration_model ,lower(T.table_name) ,obj_description(format('%s.%s',t.table_schema,t.table_name)::regclass, 'pg_class') ,t.table_schema ,true ,false from INFORMATION_SCHEMA.tables t left outer join meta.f_upgrade_table(t.table_schema) tu on lower(tu.tablename) = lower(t.table_name) where t.table_type = 'BASE TABLE' and t.table_schema not ilike 'pg_%' and t.table_schema not ilike 'information_schema%' and tu.tablename is null and ( t.table_schema in ( select distinct mt.schemaname from meta.migration_table mt where mt.ismodel ) or t.table_schema = 'public' ) ; insert into meta.migration_column(rid_migration_table, columnname, columntype, columnlen, precision, prefix, defaultval, indextype, guid, seqseed, ispk,sequence) with det as ( select obj_description(format('%s.%s', c.table_schema, c.table_name)::regclass, 'pg_class') as tbl_guid , lower(c.column_name) as colname , col_description(format('%s.%s', c.table_schema, c.table_name)::regclass, c.ordinal_position) as col_guid , case when c.data_type::citext = 'user-defined' then c.udt_name else c.data_type end || (case when c.data_type::citext = 'numeric' then '(' || c.numeric_precision || (case when c.numeric_scale = 0 then '' else ',' || c.numeric_scale end) || ')' else '' end) as coltype ,'(' || c.numeric_precision || (case when c.numeric_scale = 0 then '' else ',' || c.numeric_scale end) || ')' as numeric_precision_str , COALESCE(pc.constraint_len,null)::integer as constraint_len ,COALESCE(defval.expr,'') as defaultvalue ,mt.id_migration_table ,c.ordinal_position::int as pos ,exists ( select ct.constraint_name,ct.table_schema,ct.table_name, cu.column_name from information_schema.table_constraints ct inner join information_schema.constraint_column_usage cu on cu.constraint_name = ct.constraint_name and cu.table_name = ct.table_name and cu.table_schema = ct.table_schema and cu.table_schema not in ('pg_catalog','') where ct.constraint_type = 'PRIMARY KEY' and ct.table_schema = c.table_schema and ct.table_name = c.table_name and cu.column_name = c.column_name ) as ispk from INFORMATION_SCHEMA.columns c inner join meta.migration_table mt on lower(mt.tablename) = lower(c.table_name) and lower(mt.schemaname) = lower(c.table_schema) and mt.isdb left join lateral ( select pc1.conname ,obj_description(pc1.oid, 'pg_constraint') as constraint_len from pg_constraint pc1 where pc1.conname = 'chk_' || c.table_name || '_' || c.column_name limit 1 ) pc on true left join lateral ( SELECT pg_get_expr(pad.adbin, pad.adrelid)::text as expr FROM pg_attrdef pad , pg_attribute pat , pg_class pc , pg_namespace ns WHERE pc.relname = c.table_name and pc.relnamespace = ns.oid and ns.nspname::text = c.table_schema AND pc.oid = pat.attrelid AND pat.attname = c.column_name AND pat.attrelid = pad.adrelid AND pat.attnum = pad.adnum ) defval on true ) select det.id_migration_table ,det.colname ,det.coltype ,det.constraint_len ,det.numeric_precision_str ,null --prefix ,det.defaultvalue ,'primary key' ,det.col_guid ,null::bigint as seed , det.ispk ,det.pos from det ; ----Indexes with indexes as ( select i1.id_migration_table , lower(i1.indexname) as indexname , i1.schemaname , i1.tablename , i1.indisprimary as ispk , not i1.indisunique as isduplicate , i1.indisunique or i1.indisprimary as isunique , i1.ikeyno + 1 as seq ,i1.oid::text as guid , lower(a.attname) as colname , row_number() over (partition by i1.indexname order by a.attname) as rnidx from ( select obj_description(format('%s.%s', ns.nspname, t.relname)::regclass, 'pg_class') tableident , t.oid , c.relname as indexname , i.indisprimary , i.indisunique as indisunique , i.indkey , unnest(i.indkey) as ikey , generate_subscripts(i.indkey, 1) as ikeyno , mt.id_migration_table , mt.tablename ,mt.schemaname FROM pg_catalog.pg_class c inner join pg_catalog.pg_namespace n on n.oid = c.relnamespace inner join pg_catalog.pg_index i on i.indexrelid = c.oid inner join pg_catalog.pg_class t on t.oid = i.indrelid inner join pg_catalog.pg_namespace ns on ns.OID = t.relnamespace inner join meta.migration_table mt on lower(mt.tablename) = lower(t.relname) and lower(mt.schemaname) = lower(n.nspname::text) and mt.isdb left outer join information_schema.table_constraints cs on cs.constraint_type not in ('CHECK', 'FOREIGN KEY') and cs.constraint_name = c.relname and cs.table_name = t.relname WHERE c.relkind::citext = 'i' ) i1 inner join pg_attribute a on a.attrelid = i1.oid and a.attnum = ikey ), insdex as ( insert into meta.migration_index( rid_migration_model, rid_migration_table, indexname, ispk, isduplicate, sequence, guid, isdb,ismodel, isunique) select p_id_migration_model, r.id_migration_table,r.indexname,r.ispk,nv(r.isduplicate,false),r.seq, r.guid,true,false, nv(r.isunique,false) from indexes r where r.rnidx = 1 returning id_migration_index,rid_migration_table,indexname,guid ), inscol as ( insert into meta.migration_index_col(rid_migration_index, rid_migration_column_parent, options, sequence) select i.id_migration_index, mc.id_migration_column, null, r.seq from indexes r inner join insdex i on i.rid_migration_table = r.id_migration_table and i.indexname = r.indexname inner join meta.migration_column mc on mc.rid_migration_table = r.id_migration_table and lower(mc.columnname) = lower(r.colname) returning * ) select count(1) into m_rowcnt ; ----Relations with cnt as ( select T.relname as parent_tablename ,tns.nspname as parent_schemaname ,t1.relname as child_tablename ,t1ns.nspname as child_schemaname ,obj_description(format('%s.%s',tns.nspname,t.relname)::regclass, 'pg_class') as parent_guid ,obj_description(format('%s.%s',t1ns.nspname,t1.relname) ::regclass, 'pg_class') as child_guid ,t.oid parent_oid ,t1.oid child_oid ,c.confupdtype ,c.confdeltype ,c.conname as constraint_name ,par.key as parentcolumn ,generate_subscripts(c.conkey,1) rpkeyno ,child.key as childcolumn ,generate_subscripts(c.conkey,1) rckeyno from pg_constraint c inner join pg_catalog.pg_class t on t.oid = c.conrelid inner join pg_catalog.pg_namespace tns on tns.oid = t.relnamespace inner join pg_catalog.pg_class t1 on t1.oid = c.confrelid inner join pg_catalog.pg_namespace t1ns on t1ns.oid = t1.relnamespace cross join unnest(c.conkey) par(key) cross join unnest(c.confkey) child(key) where c.contype = 'f' ), det as ( select r1.parent_guid , lower(r1.constraint_name) as constraint_name , r1.child_guid , (case r1.confdeltype::citext when 'r' then 'restrict_server' --restrict server when 'c' then 'cascade_server' --cascade server when 'n' then 'set null' when 'd' then 'set default' else 'no_action' end) as deleteconstraint , (case r1.confupdtype::citext when 'r' then 'restrict_server' --restrict server when 'c' then 'cascade_server' --cascade server when 'n' then 'set null' when 'd' then 'set default' else 'no_action' end) as updateconstraint , lower(ap.attname) as parent_column , lower(ac.attname) as child_column , r1.rpkeyno , row_number() over (partition by constraint_name order by ap.attname, ac.attname) as rncnt ,r1.parent_tablename ,r1.parent_schemaname ,r1.child_tablename ,r1.child_schemaname ,mtp.id_migration_table as id_migration_table_parent ,mtc.id_migration_table as id_migration_table_child from cnt r1 inner join pg_attribute ap on ap.attrelid = r1.parent_oid and ap.attnum = parentcolumn inner join pg_attribute ac on ac.attrelid = r1.child_oid and ac.attnum = childcolumn inner join meta.migration_table mtp on mtp.tablename = r1.parent_tablename and mtp.schemaname = r1.parent_schemaname and mtp.isdb inner join meta.migration_table mtc on mtc.tablename = r1.child_tablename and mtc.schemaname = r1.child_schemaname and mtc.isdb order by r1.child_tablename , r1.constraint_name , r1.rpkeyno , r1.rckeyno ), ins as ( insert into meta.migration_relation(rid_migration_model ,rid_migration_table_parent, rid_migration_table_child, relationname, updateconstraint , deleteconstraint, sequence,isdb,ismodel ) select p_id_migration_model, det.id_migration_table_parent, det.id_migration_table_child, det.constraint_name,det.updateconstraint, det.deleteconstraint,null ,true,false from det where det.rncnt = 1 returning * ), inscol as ( insert into meta.migration_relation_col(rid_migration_relation, rid_migration_column_parent, rid_migration_column_child, sequence) select ins.id_migration_relation, colp.id_migration_column, colc.id_migration_column ,det.rpkeyno from det inner join ins on ins.relationname = det.constraint_name and ins.rid_migration_table_parent = det.id_migration_table_parent and ins.rid_migration_table_child = det.id_migration_table_child inner join meta.migration_column colc on colc.rid_migration_table = ins.rid_migration_table_child and colc.columnname = det.child_column inner join meta.migration_column colp on colp.rid_migration_table = ins.rid_migration_table_child and colc.columnname = det.parent_column returning * ) select count(1) from inscol into m_rowcnt ; ---Load all triggers insert into meta.migration_object(rid_migration_model,rid_migration_table, objecttype,objectname, schema, ismodel, isdb) select distinct on (mt.id_migration_table,tr.trigger_name) p_id_migration_model ,mt.id_migration_table ,'trigger' ,tr.trigger_name ,mt.schemaname ,false ,true from INFORMATION_SCHEMA.triggers tr inner join meta.migration_table mt on mt.isdb and lower(mt.schemaname) = lower(tr.event_object_schema) and lower(mt.tablename) = lower(tr.event_object_table) ; ---Load all sequences insert into meta.migration_object(rid_migration_model,objecttype,rid_migration_table,objectname, schema, ismodel, isdb) select distinct on (seq.sequence_name, seq.schemaname,mt.id_migration_table) p_id_migration_model ,'sequence' ,mt.id_migration_table ,seq.sequence_name ,seq.schemaname ,false ,true from ( SELECT seqclass.relname AS sequence_name, ns.nspname as schemaname, depclass.relname AS table_name, ( select array_agg(attrib.attname) from pg_attribute attrib where attrib.attnum = dep.refobjsubid AND attrib.attrelid = dep.refobjid ) as cols FROM pg_class AS seqclass join pg_namespace ns on ns.oid = seqclass.relnamespace and lower(ns.nspname::text) in ( select distinct mt.schemaname from meta.migration_table mt where mt.isdb ) JOIN pg_sequence AS seq ON ( seq.seqrelid = seqclass.relfilenode ) left outer JOIN pg_depend AS dep ON ( seq.seqrelid = dep.objid ) left outer JOIN pg_class AS depclass ON ( dep.refobjid = depclass.relfilenode ) ) seq left outer join meta.migration_table mt on mt.isdb and lower(mt.schemaname) = lower(seq.schemaname) and lower(mt.tablename) = lower(seq.table_name) ; insert into meta.migration_object(rid_migration_model,objecttype,rid_migration_column,rid_migration_table,objectname, schema, ismodel, isdb,body) SELECT distinct on (col.id_migration_column, tbl.id_migration_table) p_id_migration_model ,'check_constraint' ,col.id_migration_column ,tbl.id_migration_table ,conname AS constraint_name, ns.nspname AS schema, false, true, pg_get_constraintdef(c.oid) AS constraint_definition FROM pg_constraint c JOIN pg_attribute a ON a.attrelid = c.conrelid AND a.attnum = ANY(c.conkey) inner join pg_class tc on tc.oid = c.conrelid inner join pg_namespace ns on ns.oid = tc.relnamespace inner join meta.migration_table tbl on tbl.isdb and lower(tbl.schemaname) = lower( ns.nspname) and lower(tbl.tablename) = lower( tc.relname) inner join meta.migration_column col on col.rid_migration_table = tbl.id_migration_table and lower(col.columnname) = lower(a.attname) WHERE contype = 'c'; ---Views on a table insert into meta.migration_object(rid_migration_model,rid_migration_table, objecttype,objectname, schema, ismodel, isdb) select distinct on (v.oid,mt.id_migration_table) p_id_migration_model ,mt.id_migration_table ,'view' ,v.oid::regclass AS view ,mt.schemaname ,false ,true FROM pg_depend AS d -- objects that depend on the table JOIN pg_rewrite AS r -- rules depending on the table ON r.oid = d.objid JOIN pg_class AS v -- views for the rules ON v.oid = r.ev_class inner join pg_class as tbl on tbl.oid = d.refobjid inner join pg_namespace ns on ns.oid = tbl.relnamespace inner join meta.migration_table mt on mt.isdb and lower(mt.schemaname) = lower(ns.nspname) and lower(mt.tablename) = lower(tbl.relname) WHERE v.relkind = 'v' -- only interested in views AND d.classid = 'pg_rewrite'::regclass AND d.refclassid = 'pg_class'::regclass AND d.deptype = 'n' -- normal dependency ; --All functions insert into meta.migration_object(rid_migration_model,objectname, objecttype, schema, body, ismodel, isdb) SELECT distinct p_id_migration_model ,pp.proname || format('(%s)', pg_get_function_identity_arguments(oid)), --function name. 'function', pp.pronamespace::regnamespace::text AS schema, --function located schema null, false, true -- pg_get_functiondef(oid), --function def -- pg_get_function_arguments(oid), --(including default values). -- pg_get_function_identity_arguments(oid), --This form omits default values. -- pg_get_function_result(oid), --Reconstructs the RETURNS clause of a function FROM pg_proc pp WHERE pp.pronamespace::regnamespace::text not in ('pg_catalog','information_schema') and pp.pronamespace::regnamespace::text not ilike 'pg_%' ; perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',2,'objecttype',m_funcname)::text); EXCEPTION WHEN others THEN GET STACKED DIAGNOSTICS m_errmsg = MESSAGE_TEXT ,m_errcontext = PG_EXCEPTION_CONTEXT ,m_errdetail = PG_EXCEPTION_DETAIL ,m_errhint = PG_EXCEPTION_HINT ,m_errstate = RETURNED_SQLSTATE; p_retval = 1; p_errmsg = format('%s Context %s State: %s', m_errmsg, m_errcontext, m_errstate); perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',3,'error',m_errmsg,'objecttype',m_funcname)::text); END; $$;