Files
relspecgo/examples/pgsql_meta_upgrade/migration_build.sql
Hein db6cd21511
Some checks are pending
CI / Build (push) Waiting to run
CI / Test (1.23) (push) Waiting to run
CI / Test (1.24) (push) Waiting to run
CI / Test (1.25) (push) Waiting to run
CI / Lint (push) Waiting to run
Added more examples and pgsql reader
2025-12-17 10:08:50 +02:00

1527 lines
58 KiB
PL/PgSQL

select * from dropall('migration_build','meta');
CREATE OR REPLACE FUNCTION meta.migration_build(
p_id_migration_model integer default null
,IN p_type text default 'all'
,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_build';
m_errmsg text;
m_errcontext text;
m_errdetail text;
m_errhint text;
m_errstate text;
m_retval integer;
--Error Handling--
m_version text;
m_template text;
BEGIN
p_retval = 0;
p_errmsg = '';
m_version = '1';
if p_id_migration_model is null
then
select m.id_migration_model
from meta.migration_model m
order by m.version desc
limit 1;
end if;
perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',1,'objecttype','id_migration_model',p_id_migration_model,m_funcname,'tm',clock_timestamp())::text);
--perform log_event(m_funcname,'init',bt_enum('eventlog','local notice'));
---delete from meta.migration_script ; --deleted inside init
--where version = m_version
if p_type in ('all','check')
then
insert into meta.migration_script(rid_migration_model,objectname, objecttype, schema, version, sequence, priority, error,status)
select p_id_migration_model
,format('%s.%s',tdb.schemaname,tdb.tablename)
,'warning'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,50
,format('Table %s does not exist in the model', tdb.tablename)
,4
from meta.migration_table tdb
left outer join meta.migration_table tmd on tmd.ismodel
and tdb.schemaname = tmd.schemaname
and lower(tdb.tablename) = lower(tmd.tablename)
where tdb.isdb
and tmd.id_migration_table is null
and tdb.tablename not in (
select f.tablename
from meta.f_upgrade_table(tdb.schemaname) f
)
;
insert into meta.migration_script(rid_migration_model,objectname, objecttype, schema, version, sequence, priority, error,status)
select p_id_migration_model
,format('%s.%s',tdb.schemaname,tdb.tablename)
,'warning'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,50
,format('This column %s does not exist in the model for %s',cdb.columnname, tdb.tablename)
,4
from meta.migration_table tdb
inner join meta.migration_table tmd on tmd.ismodel
and tdb.schemaname = tmd.schemaname
and lower(tdb.tablename) = lower(tmd.tablename)
inner join meta.migration_column cdb on cdb.rid_migration_table = tdb.id_migration_table
and (cdb.columnname not ilike '%dropped_%' or cdb.columnname not ilike '%_dropped%')
and cdb.columnname <> 'updatecnt'
left outer join meta.migration_column cmd on cmd.rid_migration_table = tmd.id_migration_table
and cmd.columnname = cdb.columnname
where tdb.isdb
and cmd.id_migration_column is null
;
insert into meta.migration_script(rid_migration_model,objectname, objecttype, schema, version, sequence, priority, error,status)
select p_id_migration_model
,format('%s.%s',tdb.schemaname,tdb.tablename)
,'warning'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,50
,format('This column does not conform to the standard primary key names rid_%s. It''currently %s',tdb.tablename,cmd.columnname)
,4
from meta.migration_table tdb
inner join meta.migration_table tmd on tmd.ismodel
and tdb.schemaname = tmd.schemaname
and lower(tdb.tablename) = lower(tmd.tablename)
inner join meta.migration_column cmd on cmd.rid_migration_table = tmd.id_migration_table
and cmd.ispk
where tdb.isdb
and not (lower(format('rid_%s',tmd.tablename)) <> cmd.columnname
or lower(format('id_%s',tmd.tablename)) <> cmd.columnname
)
;
insert into meta.migration_script(rid_migration_model,objectname, objecttype, schema, version, sequence, priority, error,status)
select p_id_migration_model
,format('%s.%s',tdb1.schemaname,tdb1.tablename)
,'warning'
,tdb1.schemaname
,m_version
,row_number() over (order by col1.columnname)
,50
,format('Foreign key does not match primary key %s (%s) <> %s (%s)',tdb1.tablename,col1.columnname,tdb2.tablename,col2.columnname)
,4
from meta.migration_relation rel
inner join meta.migration_table tdb1 on tdb1.id_migration_table = rel.rid_migration_table_parent
and tdb1.isdb
inner join meta.migration_table tdb2 on tdb2.id_migration_table = rel.rid_migration_table_child
and tdb2.isdb
inner join meta.migration_relation_col rcol on rcol.rid_migration_relation = rel.id_migration_relation
inner join meta.migration_column col1 on col1.id_migration_column = rcol.rid_migration_column_parent
inner join meta.migration_column col2 on col2.id_migration_column = rcol.rid_migration_column_child
where rel.isdb
and col1.columnname is distinct from col2.columnname
and (col1.columnname not ilike '%dropped_%' or col1.columnname not ilike '%_dropped%')
and col1.columnname <> 'updatecnt'
and (col2.columnname not ilike '%dropped_%' or col2.columnname not ilike '%_dropped%')
and col2.columnname <> 'updatecnt'
;
end if;
if p_type in ('drop')
then
----Drop all views
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (tbl.schemaname,tbl.tablename,tr.objectname)
format('%s.%s.%s', tbl.schemaname,tbl.tablename,tr.objectname)
,'drop view'
,tbl.schemaname
,m_version
,row_number() over (order by tbl.schemaname,tbl.tablename, tr.objectname)
,2
,format($A$do $C$
begin
perform set_config('lock_timeout', '500ms', false);
SET LOCAL statement_timeout = '2s';
drop view if exists %1$s;
end;
$C$
$A$,tr.objectname)
from meta.migration_object tr
inner join meta.migration_table tbl on tbl.id_migration_table = tr.rid_migration_table
where tr.isdb
and tr.objecttype = 'view'
and exists (select 1 from meta.migration_table t3 where t3.ismodel and t3.schemaname = tbl.schemaname )
;
----Drop all Triggers
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (tbl.schemaname,tbl.tablename,tr.objectname)
format('%s.%s.%s', tbl.schemaname,tbl.tablename,tr.objectname)
,'drop trigger'
,tbl.schemaname
,m_version
,row_number() over (order by tbl.schemaname,tbl.tablename, tr.objectname)
,10
,format($A$do $C$
begin
perform set_config('lock_timeout', '500ms', false);
SET LOCAL statement_timeout = '1s';
drop trigger if exists %1$s on %2$s.%3$s;
end;
$C$
$A$,tr.objectname,tbl.schemaname,tbl.tablename )
from meta.migration_object tr
inner join meta.migration_table tbl on tbl.id_migration_table = tr.rid_migration_table
where tr.isdb
and exists (select 1 from meta.migration_table t3 where t3.ismodel and t3.schemaname = tbl.schemaname and t3.tablename = tbl.tablename )
and tr.objecttype = 'trigger'
and tbl.schemaname not in ('meta','information_schema')
;
---drop constraint
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (tdb.schemaname,tdb.tablename,coalesce(cdb.columnname, cmd.columnname))
format('%s_%s_%s',tdb.schemaname,tdb.tablename,coalesce(cdb.columnname, cmd.columnname))
,'drop constraint'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,11
,format($A$
alter table %1$s.%2$s drop constraint if exists chk_%3$s_%2$s_%4$s;
alter table %1$s.%2$s drop constraint if exists chk_%2$s_%4$s;
$A$,tdb.schemaname,tdb.tablename,tmd.schemaname,coalesce(cdb.columnname, cmd.columnname) )
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.schemaname = tmd.schemaname
and tdb.tablename = tmd.tablename
and tdb.isdb
left outer join meta.migration_column cmd on cmd.rid_migration_table = tmd.id_migration_table
left outer join meta.migration_column cdb on cdb.rid_migration_table = tdb.id_migration_table
and cdb.columnname = cmd.columnname
where tmd.ismodel
and exists (select 1 from meta.migration_table t3 where t3.ismodel and t3.schemaname = tdb.schemaname and t3.tablename = tdb.tablename )
and cdb.columnlen is distinct from cmd.columnlen
and (cdb.id_migration_column > 0 or cmd.id_migration_column > 0)
and tmd.schemaname not in ('meta','information_schema')
and exists (
select cns.conname
from pg_constraint cns
where cns.conname = format('chk_%s_%s', tmd.tablename, coalesce(cdb.columnname, cmd.columnname))
or cns.conname = format('chk_%s_%s_%s', tmd.schemaname,tmd.tablename, coalesce(cdb.columnname, cmd.columnname))
)
;
---drop index / constraint
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s.%s',tdb.schemaname,idx.indexname)
,'drop index ' || case when idx.ispk then 'primary key' when idx.isunique then 'unique' else '' end
,tdb.schemaname
,m_version
,row_number() over (order by tdb.tablename)
,20
,format($A$ alter table %1$s.%2$s drop constraint if exists %3$s cascade;
drop index if exists %1$s.%3$s cascade; $A$,tdb.schemaname,tdb.tablename, idx.indexname)
from meta.migration_index idx
inner join meta.migration_table tdb on idx.rid_migration_table = tdb.id_migration_table
left outer join meta.migration_index idxmd on idxmd.ismodel
and (idxmd.rid_migration_table in (select tmd.id_migration_table from meta.migration_table tmd
where tmd.tablename = tdb.tablename))
and (lower(idxmd.indexname) = lower(idx.indexname)
or idxmd.indexname = format('%s_%s', idx.indexname, tdb.tablename)
)
where idx.isdb
and tdb.schemaname not in ('meta','information_schema')
and exists (select 1
from meta.migration_table t3
where t3.ismodel
and t3.schemaname = tdb.schemaname
and t3.tablename = tdb.tablename
)
and (
not idxmd.ispk and idxmd.isunique and idx.isunique is distinct from idxmd.isunique
or idxmd.ispk and idx.ispk is distinct from idxmd.ispk
--Are there any columns is model not in db and vice versa
or exists (
select 1
from meta.migration_index_col ic
inner join meta.migration_column c1 on c1.id_migration_column = ic.rid_migration_column_parent
where ic.rid_migration_index = idx.id_migration_index
and c1.columnname not in (
select c2.columnname
from meta.migration_index_col icmd
inner join meta.migration_column c2 on c2.id_migration_column = icmd.rid_migration_column_parent
where icmd.rid_migration_index = idxmd.id_migration_index
)
and c1.rid_migration_table in (
select c2.rid_migration_table
from meta.migration_index_col icmd
inner join meta.migration_column c2 on c2.id_migration_column = icmd.rid_migration_column_parent
where icmd.rid_migration_index = idxmd.id_migration_index
)
) or
exists (
select 1
from meta.migration_index_col ic
inner join meta.migration_column c1 on c1.id_migration_column = ic.rid_migration_column_parent
where ic.rid_migration_index = idxmd.id_migration_index
and idxmd.id_migration_index > 0
and c1.columnname not in (
select c2.columnname
from meta.migration_index_col ic2
inner join meta.migration_column c2 on c2.id_migration_column = ic2.rid_migration_column_parent
where ic2.rid_migration_index = idx.id_migration_index
)
)
)
-- and (
-- not idx.ispk
-- or true
-- or idx.ispk
-- and not exists (
-- select 1
-- from meta.migration_table t2
-- inner join meta.migration_column c2 on c2.rid_migration_table = t2.id_migration_table
-- and c2.ispk
-- where t2.tablename = tdb.tablename
-- and t2.schemaname = tdb.schemaname
-- and t2.isdb
-- )
-- )
;
---drop relation
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s',rel.relationname)
,'drop relation'
,tdbp.schemaname
,m_version
,row_number() over (order by tdbp.tablename)
,50
,case when rel.relationname ilike 't_%'
then format($A$
DROP TRIGGER IF EXISTS %3$s on %1$s.%2$s;
$A$,tdbp.schemaname,tdbp.tablename, rel.relationname)
else
format($A$
alter table %1$s.%2$s drop constraint if exists %3$s;
$A$,tdbp.schemaname,tdbp.tablename, rel.relationname)
end
from meta.migration_relation rel
inner join meta.migration_table tdbc on rel.rid_migration_table_child = tdbc.id_migration_table
inner join meta.migration_table tdbp on rel.rid_migration_table_parent = tdbp.id_migration_table
where rel.isdb
and tdbc.schemaname not in ('meta','information_schema')
and exists (select 1 from meta.migration_table t3
where t3.ismodel and (
t3.schemaname = tdbc.schemaname and t3.tablename = tdbc.tablename
or t3.schemaname = tdbp.schemaname and t3.tablename = tdbp.tablename
)
)
and exists (
select 1
from information_schema.tables t
where t.table_schema = tdbp.schemaname
and t.table_name = tdbp.tablename
) and exists (
select 1
from information_schema.triggers tr
where lower(tr.trigger_name) = lower(rel.relationname)
and lower(tr.trigger_name) = lower(tdbp.tablename)
and lower(tr.trigger_schema) = lower(tdbp.schemaname)
)
;
end if;
if p_type in ('renames','rename')
then
/*
--set schema for initial convert
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s',tmd.schemaname,tmd.tablename)
,'set table schema'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,59
,format($A$
create schema if not exists %3$s;;
alter table %1$s.%2$s set SCHEMA %3$s;
$A$,tdb.schemaname,tdb.tablename,tmd.schemaname )
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.tablename = tmd.tablename
and tdb.tablename = tmd.tablename
and tdb.isdb
where tmd.ismodel
and tmd.schemaname <> 'public'
and tdb.schemaname = 'public'
--Don't touch duplicate guid tables.
and not exists (
select 1
from information_schema.tables t
where t.table_schema = tmd.schemaname
and t.table_name = tmd.tablename
)
and not exists (
select a.tablename
from meta.migration_table a
where a.ismodel
and a.tablename = tmd.tablename
and a.schemaname = 'public'
)
;
*/
-- ---set schema
-- insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
-- select format('%s_%s',tmd.schemaname,tmd.tablename)
-- ,'set table schema'
-- ,tmd.schemaname
-- ,m_version
-- ,row_number() over (order by tmd.tablename)
-- ,60
-- ,format($A$
-- alter table %1$s.%2$s set SCHEMA %3$s;
-- $A$,tdb.schemaname,tdb.tablename,tmd.schemaname )
-- from meta.migration_table tmd
-- inner join meta.migration_table tdb on tdb.tablename = tmd.tablename
-- and tdb.guid = tmd.guid
-- and tdb.isdb
-- where tmd.ismodel
-- and tmd.schemaname is distinct from tdb.schemaname
-- --Don't touch duplicate guid tables.
-- and tmd.guid not in (
-- select a.guid
-- from meta.migration_table a
-- inner join meta.migration_table b on b.isdb
-- and a.tablename = b.tablename
-- where a.ismodel
-- group by a.guid
-- having count(1) > 1
-- )
-- ;
---rename table
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s',tdb.schemaname,tdb.tablename)
,'rename table'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,60
,format($A$DO $X$
alter table %1$s.%2$s rename to %4$s;
$A$,tdb.schemaname,tdb.tablename,tmd.schemaname, tmd.tablename )
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.schemaname = tmd.schemaname
and tdb.guid = tmd.guid
and tdb.isdb
where tmd.ismodel
and tmd.tablename is distinct from tdb.tablename
and tmd.schemaname = tdb.schemaname
and not tmd.tablename = format('%s_dropped',tmd.tablename)
-- if there is a table with that guid, don't try to rename
and not (tmd.schemaname = tdb.schemaname
and tmd.guid = tdb.guid
)
--Don't touch duplicate guid tables.
and tmd.tablename not in (
select a.tablename
from meta.migration_table a
inner join meta.migration_table b on b.isdb
and a.tablename = b.tablename
where a.ismodel
group by a.tablename
having count(1) > 1
)
;
---rename column
-- insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
-- select format('%s_%s_%s',tdb.schemaname,tdb.tablename,coalesce(cdb.columnname, cmd.columnname))
-- ,'rename column'
-- ,tmd.schemaname
-- ,m_version
-- ,row_number() over (order by tmd.tablename)
-- ,90
-- ,format($A$
-- alter table %1$s.%2$s rename column %3$s to %4$s ;
-- $A$,tdb.schemaname,tdb.tablename,cdb.columnname, cmd.columnname )
-- from meta.migration_table tmd
-- inner join meta.migration_table tdb on tdb.schemaname = tmd.schemaname
-- and tdb.tablename = tmd.tablename
-- and tdb.isdb
-- inner join meta.migration_column cdb on cdb.rid_migration_table = tdb.id_migration_table
-- inner join meta.migration_column cmd on cmd.rid_migration_table = tmd.id_migration_table
-- where tmd.ismodel
-- and cdb.guid = cmd.guid
-- and cdb.columnname is distinct from cmd.columnname
-- and cdb.columnname not like '%dropped%'
-- and not exists (
-- select 1
-- from meta.migration_script s
-- where s.objecttype in ('rename table','set table schema')
-- and s.objectname = format('%s_%s',tmd.schemaname,tmd.tablename)
-- )
-- ;
---rename dropped table column
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s_%s',tdb.schemaname,tdb.tablename,coldb.columnname)
,'drop rename column'
,tmd.schemaname
,m_version
,row_number() over (order by tdb.tablename, coldb.columnname)
,89
,format($A$
alter table %1$s.%2$s
rename column %4$s to %5$s;
COMMENT ON Column %1$s.%2$s. %5$s is 'dropped';
$A$,tmd.schemaname
, tmd.tablename
, tmd.guid
,coldb.columnname --%4$s
,format('_dropped_%s',coldb.columnname
)
)
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.schemaname = tmd.schemaname
and tdb.tablename = tmd.tablename
and (tdb.tablename not ilike '%_dropped%' or tdb.tablename not ilike '%dropped_%')
and tdb.isdb
inner join meta.migration_column coldb on coldb.rid_migration_table = tdb.id_migration_table
left outer join meta.migration_column colmd on colmd.rid_migration_table = tmd.id_migration_table
and lower(coldb.columnname) = lower(colmd.columnname)
where tmd.ismodel
and coldb.columnname not in ('updatecnt','prefix')
and coldb.columnname not ilike '%\_dropped\_%'
and colmd.id_migration_column is null
and not exists (
select 1
from meta.migration_script s
where s.objecttype in ('rename table','set table schema','drop rename column')
and (s.objectname = format('%s_%s', tmd.schemaname, tmd.tablename)
or s.objectname = format('%s_%s_%s',tdb.schemaname,tdb.tablename,coldb.columnname)
)
)
and not exists (
select 1
from information_schema.columns c
where c.table_schema = tdb.schemaname
and c.table_name = tdb.tablename
and c.column_name = format('_dropped_%s',coldb.columnname)
)
;
end if;
if p_type in ('all','tables')
then
---create table
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s',tmd.schemaname,tmd.tablename)
,'create table'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,100
,format($A$
create table if not exists %1$s.%2$s (
%4$s
);
COMMENT ON TABLE %1$s.%2$s is '%3$s';
%5$s
$A$,tmd.schemaname, tmd.tablename, tmd.guid,
(
select string_agg(
format('%s %s %s',col.columnname, col.columntype
, case when length(coalesce(col.defaultval,'')) > 2 then 'DEFAULT '||col.defaultval else '' end
)
,E', \n')
from meta.migration_column col
where col.rid_migration_table = tmd.id_migration_table
)
,(
select string_agg(
format($A$COMMENT ON Column %1$s.%2$s.%3$s is '%4$s';$A$
,tmd.schemaname
,tmd.tablename
,col.columnname
,col.guid
)
,E' \n')
from meta.migration_column col
where col.rid_migration_table = tmd.id_migration_table
)
)
from meta.migration_table tmd
left outer join meta.migration_table tdb on tdb.schemaname = tmd.schemaname
and tdb.tablename = tmd.tablename
and tdb.isdb
where tmd.ismodel
and tdb.id_migration_table is null
--If we do renames, skip the creation
and not exists (
select 1
from meta.migration_script s
where s.objecttype in ('rename table','set table schema')
and s.objectname = format('%s_%s',tmd.schemaname,tmd.tablename)
)
;
---create table column
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (tdb.schemaname,tdb.tablename,colmd.columnname)
format('%s_%s_%s',tdb.schemaname,tdb.tablename,colmd.columnname)
,'create column'
,tmd.schemaname
,m_version
,row_number() over (order by tdb.tablename, colmd.columnname)
,120
,format($A$
alter table %1$s.%2$s
add column IF NOT EXISTS %4$s %5$s %6$s;
COMMENT ON Column %1$s.%2$s.%4$s is '%7$s';
$A$,tmd.schemaname
, tmd.tablename
, tmd.guid
, colmd.columnname --%4$s
,colmd.columntype
,case when length(coalesce(colmd.defaultval,'')) > 2 then 'DEFAULT '||colmd.defaultval else '' end
, colmd.guid --%7$s
)
from meta.migration_table tmd
inner join meta.migration_table tdb on lower(tdb.schemaname) = lower(tmd.schemaname)
and lower(tdb.tablename) = lower(tmd.tablename)
and tdb.isdb
inner join meta.migration_column colmd on colmd.rid_migration_table = tmd.id_migration_table
left outer join meta.migration_column coldb on coldb.rid_migration_table = tdb.id_migration_table
and lower(coldb.columnname) = lower(colmd.columnname)
where tmd.ismodel
and coldb.id_migration_column is null
and not exists (
select 1
from meta.migration_script s
where s.objecttype in ('rename table','set table schema')
and s.objectname = format('%s_%s',tmd.schemaname,tmd.tablename)
)
;
---alter table column
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s_%s',tdb.schemaname,tdb.tablename,colmd.columnname)
,'alter column'
,tmd.schemaname
,m_version
,row_number() over (order by tdb.tablename, colmd.columnname)
,120
,format($A$
alter table %1$s.%2$s alter column %4$s DROP DEFAULT;
alter table %1$s.%2$s drop constraint if exists chk_%1$s_%2$s_%4$s;
alter table %1$s.%2$s alter column %4$s type %5$s %6$s;
$A$,tmd.schemaname
, tmd.tablename
, tmd.guid
, colmd.columnname --%4$s
,colmd.columntype --%5$s
,(case
when colmd.columntype = 'date' and coldb.columntype in ('integer','smallint') then ' using F_inttodate('||colmd.columnname||')'
when colmd.columntype = 'integer' and coldb.columntype = 'date' then ' using F_datetoint('||colmd.columnname||')'
when colmd.columntype = 'date' and coldb.columntype = 'numeric' then ' using F_inttodate('||colmd.columnname||'::integer)'
when colmd.columntype = 'time' and coldb.columntype = 'integer' then ' using f_inttotm('||colmd.columnname||')'
when colmd.columntype = 'time' and coldb.columntype = 'numeric' then ' using f_inttotm('||colmd.columnname||'::integer)'
when colmd.columntype = 'integer' and coldb.columntype = 'time' then ' using f_tmtoint('||colmd.columnname||')'
when colmd.columntype = 'integer' and coldb.columntype in ('text', 'citext') then ' using case when ifblnk('||colmd.columnname||') = '''' then null else '||colmd.columnname||'::integer end'
when colmd.columntype = 'smallint' and coldb.columntype in ('text', 'citext') then ' using case when ifblnk('||colmd.columnname||') = '''' then null else '||colmd.columnname||'::smallint end'
when colmd.columntype ilike 'numeric%' and coldb.columntype in ('text', 'citext') then ' using case when ifblnk('||colmd.columnname||') = '''' then null else '||colmd.columnname||'::numeric end'
when colmd.columntype = 'bytea' and coldb.columntype in ('text', 'citext') then ' using convert_to('||colmd.columnname||',''utf8'')'
when colmd.columntype in ('text', 'citext') and coldb.columntype = 'bytea' then ' using convert_from('||colmd.columnname||',''utf8'')'
when colmd.columntype in ('json', 'jsonb') and coldb.columntype = 'bytea' then ' using convert_from('||colmd.columnname||',''utf8'')::json'
when colmd.columntype in ('json') and coldb.columntype <> 'jsonb' then ' using '||colmd.columnname||'::jsonb'
when colmd.columntype in ('jsonb') and coldb.columntype <> 'json' then ' using '||colmd.columnname||'::json'
when colmd.columntype = 'timestamp' and coldb.columntype in ('text', 'citext') then ' using _bv('||colmd.columnname||',null)::timestamp'
else ''
end) --%6$s
-- ,case when length(colmd.defaultval) > 1 then colmd.defaultval else 'null' end--%7$s
)
from meta.migration_table tmd
inner join meta.migration_table tdb on lower(tdb.schemaname) = lower(tmd.schemaname)
and lower(tdb.tablename) = lower(tmd.tablename)
and tdb.isdb
inner join meta.migration_column colmd on colmd.rid_migration_table = tmd.id_migration_table
inner join meta.migration_column coldb on coldb.rid_migration_table = tdb.id_migration_table
and lower(coldb.columnname) = lower(colmd.columnname)
where tmd.ismodel
and colmd.columntype is distinct from coldb.columntype
and not exists (
select 1
from meta.migration_script m
where m.objecttype = 'create table'
and m.objectname = format('%s_%s',tmd.schemaname,tmd.tablename)
) and not exists (
select 1
from meta.migration_script s
where s.objecttype in ('rename table','set table schema')
and s.objectname = format('%s_%s',tmd.schemaname,tmd.tablename)
)
;
---alter table column default
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s_%s',tmd.schemaname,tmd.tablename,colmd.columnname)
,'alter column default'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename, colmd.columnname)
,145
,format($A$
alter table %1$s.%2$s
alter column %4$s set DEFAULT %5$s;
$A$,tmd.schemaname
, tmd.tablename
, tmd.guid
,colmd.columnname --%4$s
,colmd.defaultval
)
from meta.migration_table tmd
inner join meta.migration_table tdb on lower(tdb.schemaname) = lower(tmd.schemaname)
and lower(tdb.tablename) = lower(tmd.tablename)
and tdb.isdb
inner join meta.migration_column colmd on colmd.rid_migration_table = tmd.id_migration_table
inner join meta.migration_column coldb on coldb.rid_migration_table = tdb.id_migration_table
and lower(coldb.columnname) = lower(colmd.columnname)
where tmd.ismodel
and (lower(btrim(colmd.defaultval, ' ')) is distinct from lower(btrim(coldb.defaultval, ' '))
or colmd.columntype is distinct from coldb.columntype
)
and length(coalesce(colmd.defaultval,'')) > 2
and not exists (
select 1
from meta.migration_script s
where s.objecttype in ('rename table','set table schema')
and s.objectname = format('%s_%s',tmd.schemaname,tmd.tablename)
)
;
-- select ct.*
-- 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.column_name = 'rid_account'
-- where ct.table_schema = 'core'
-- and ct.constraint_type = 'PRIMARY KEY'
-- and ct.table_name = 'account'
---Create check constraint
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (tmd.schemaname,tmd.tablename,colmd.columnname)
format('%s_%s_%s',tmd.schemaname,tmd.tablename,colmd.columnname)
,'create column chk'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename, colmd.columnname)
,160
,format($A$
alter table %1$s.%2$s
drop constraint if exists %3$s;
alter table %1$s.%2$s
add constraint %3$s CHECK (f_chk_col('%2$s','%4$s',%4$s::citext,%5$s,0::text)) NOT VALID;
$A$,tmd.schemaname
, tmd.tablename
, format('chk_%s_%s_%s',tmd.schemaname,tmd.tablename,colmd.columnname)
,colmd.columnname --%4$s
,colmd.columnlen
)
from meta.migration_table tmd
inner join meta.migration_column colmd on colmd.rid_migration_table = tmd.id_migration_table
left outer join meta.migration_table tdb on tdb.isdb
and tdb.tablename = tmd.tablename
and tdb.schemaname = tmd.schemaname
left outer join meta.migration_column coldb on coldb.rid_migration_table = tdb.id_migration_table
and coldb.columnname = colmd.columnname
left outer join meta.migration_object obj on obj.rid_migration_table = tdb.id_migration_table
and obj.rid_migration_column = coldb.id_migration_column
and obj.objecttype = 'check_constraint'
where tmd.ismodel
and colmd.columnlen > 0
and colmd.columntype in ('string','text','citext')
and (colmd.columnlen is distinct from coldb.columnlen
or obj.id_migration_object is null
)
and colmd.columnlen < coalesce((
select o.value::integer
from meta.migration_option o
where o.name = 'max_constraint'
limit 1
),4096)
;
--Create index
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s_%s',tmd.schemaname,tmd.tablename,idx.indexname)
,'create index ' || case when idx.ispk then 'primary key' when idx.isunique then 'unique' when idx.ispartial then 'partial' else '' end
,tmd.schemaname
,m_version
,row_number() over (order by idx.sequence, tmd.tablename)
,case when idx.ispk then 160 else 180 end
,case when idx.isunique and not idx.ispk
then
format($A$
create unique index if not exists %3$s on %1$s.%2$s
using btree (%4$s)
%5$s
;
$A$,tmd.schemaname
, tmd.tablename
,idx.indexname
,cols.list
,case when idx.ispartial then idx.partialstr else '' end
)
when (idx.ispartial or idx.isduplicate) and not idx.ispk then format($A$
create index if not exists %3$s on %1$s.%2$s
using btree (%4$s)
%5$s
;
$A$,tmd.schemaname
, tmd.tablename
,idx.indexname
,cols.list
,idx.partialstr
)
else format($A$DO $CHKC$
begin
if not exists (
SELECT 1
FROM information_schema.table_constraints
WHERE lower(table_name) = '%2$s'
and lower(table_schema) = '%1$s'
AND lower(constraint_name) = '%3$s'
)
then
%7$s
alter table %1$s.%2$s
add constraint %3$s
%4$s (%5$s);
%6$s
end if;
end;
$CHKC$;
$A$,tmd.schemaname
, tmd.tablename
,idx.indexname
,case when idx.ispk then ' PRIMARY KEY ' else ' UNIQUE ' end
,cols.list --%5$s
,case when idx.ispk
then format('CLUSTER %3$s on %1$s.%2$s;',tmd.schemaname , tmd.tablename,idx.indexname)
else ''
end
--Make sure we drop special types
,case when idx.ispk
then format($S2$
if exists (
SELECT 1
FROM information_schema.table_constraints
WHERE lower(table_name) = lower('%2$s')
and lower(table_schema) = lower('%1$s')
AND lower(constraint_name) = lower('%6$s')
)
then
alter table %1$s.%2$s
RENAME constraint %6$s to %4$s;
return;
end if;
$S2$,tmd.schemaname , tmd.tablename
,replace(replace(idx.indexname,'_'||tmd.schemaname||'_'||tmd.tablename,'')
,tmd.schemaname||'_',''),idx.indexname,(
select tp.prefix
from meta.table_prefix tp
where tp.schemaname = tmd.schemaname
and tp.tablename = tmd.tablename
limit 1
),(
SELECT constraint_name
FROM information_schema.table_constraints
WHERE lower(table_name) = lower(tmd.tablename)
and lower(table_schema) = lower(tmd.schemaname)
and constraint_type = 'PRIMARY KEY'
limit 1
) )
else format('
alter table %1$s.%2$s
drop constraint if exists %3$s;
drop index if exists %1$s.%3$s cascade ;
',tmd.schemaname
,tmd.tablename
,idx.indexname
)
end
)
end
from meta.migration_index idx
inner join meta.migration_table tmd on tmd.id_migration_table = idx.rid_migration_table
and tmd.ismodel
inner join lateral (
select string_agg(col.columnname,',' order by ic.sequence, col.columnname) as list
from meta.migration_index_col ic
inner join meta.migration_column col on col.id_migration_column = ic.rid_migration_column_parent
where ic.rid_migration_index = idx.id_migration_index
) cols on nv(cols.list) <> ''
left outer join meta.migration_table tdb on tdb.isdb
and tdb.schemaname = tmd.schemaname
and tdb.tablename = tmd.tablename
left outer join meta.migration_index dbidx on dbidx.rid_migration_table = tdb.id_migration_table
and (lower(dbidx.indexname) = lower(idx.indexname)
or lower(dbidx.indexname) = lower(format('%s_%s',idx.indexname,tmd.tablename)) )
where tmd.ismodel
and (dbidx.id_migration_index is null
or dbidx.id_migration_index is not null
and (dbidx.isunique is distinct from idx.isunique
and dbidx.ispk is distinct from idx.ispk
and dbidx.ispartial is distinct from idx.ispartial
and dbidx.isduplicate is distinct from idx.isduplicate
)
)
;
--Create Relation
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s',rel.relationname)
,'create relation'
,tmd.schemaname
,m_version
,row_number() over (order by rel.sequence, tmd.tablename)
,195
, format($A$
ALTER TABLE %3$s.%4$s
drop constraint if exists %5$s;
ALTER TABLE %3$s.%4$s
add constraint %5$s
FOREIGN KEY (%6$s)
REFERENCES %1$s.%2$s(%7$s)
ON DELETE %8$s
ON UPDATE %9$s
NOT VALID
DEFERRABLE;
$A$,tmd.schemaname
, tmd.tablename -- %2$s
,tmd2.schemaname
,tmd2.tablename ---%4$s
,rel.relationname -- %5$s
,col_child.list --%6$s
,col_par.list --%7$s
,(case
when upper(rel.deleteconstraint) = 'RESTRICT_SERVER' then 'restrict'
when upper(rel.deleteconstraint) = 'CASCADE_SERVER' then 'cascade'
when upper(rel.deleteconstraint) = 'CLEAR_SERVER' then 'set null'
when upper(rel.deleteconstraint) = 'DEFAULT_SERVER' then 'set default'
else 'no action'
end) --%8$s
,(case
when upper(rel.updateconstraint) = 'RESTRICT_SERVER' then 'restrict'
when upper(rel.updateconstraint) = 'CASCADE_SERVER' then 'cascade'
when upper(rel.updateconstraint) = 'CLEAR_SERVER' then 'set null'
when upper(rel.updateconstraint) = 'DEFAULT_SERVER' then 'set default'
else 'no action'
end) --%9$s
)
from meta.migration_relation rel
inner join meta.migration_table tmd on tmd.id_migration_table = rel.rid_migration_table_parent
and tmd.ismodel
inner join meta.migration_table tmd2 on tmd2.id_migration_table = rel.rid_migration_table_child
and tmd2.ismodel
inner join lateral (
select string_agg(col.columnname,',' order by rcol.sequence, col.columnname) as list
,count(1) as colcnt
from meta.migration_relation_col rcol
inner join meta.migration_column col on col.id_migration_column = rcol.rid_migration_column_parent
and col.rid_migration_table = tmd.id_migration_table
where rcol.rid_migration_relation = rel.id_migration_relation
) col_par on col_par.colcnt > 0
inner join lateral (
select string_agg(col.columnname,',' order by rcol.sequence, col.columnname) as list
,count(1) as colcnt
from meta.migration_relation_col rcol
inner join meta.migration_column col on col.id_migration_column = rcol.rid_migration_column_child
and col.rid_migration_table = tmd2.id_migration_table
where rcol.rid_migration_relation = rel.id_migration_relation
) col_child on col_child.colcnt > 0
left outer join meta.migration_table tdb on tdb.isdb
and tdb.schemaname = tmd.schemaname
and tdb.tablename = tmd.tablename
left outer join meta.migration_table tdbc on tdbc.isdb
and tdbc.schemaname = tmd2.schemaname
and tdbc.tablename = tmd2.tablename
left outer join meta.migration_relation reldb on reldb.isdb
--and reldb.rid_migration_table_parent = tdb.id_migration_table
--and reldb.rid_migration_table_child = tdbc.id_migration_table
and lower(reldb.relationname) = lower(rel.relationname)
where tmd.ismodel
and (rel.deleteconstraint ilike '%server%' or rel.updateconstraint ilike '%server%')
--and reldb.id_migration_relation is null
;
end if;
if p_type in ('all','sequence')
then
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s.identity_%s_%s', t.schemaname,t.tablename,c.columnname)
,'create sequence'
,t.schemaname
,m_version
,row_number() over (order by t.tablename) as seq
,80
,format($B$DO $SEQ$
BEGIN
IF NOT EXISTS (
SELECT 1
FROM pg_class C
inner join pg_namespace ns on ns.oid = c.relnamespace
and lower(ns.nspname) = lower('%4$s')
where c.relname = '%1$s' and lower(relkind) = 's'
)
then
create sequence %4$s.%1$s increment 1 minvalue 1 maxvalue 9223372036 start %2$s cache 1;
comment on sequence %4$s.%1$s is '%3$s';
end if;
END;$SEQ$;
$B$,
format('identity_%s_%s', t.tablename,c.columnname)
,case when c.seqseed > 0 then c.seqseed else 1 end
,format('%s.%s.%s',t.tablename,c.columnname,c.guid)
,t.schemaname
)
from meta.migration_table t
inner join meta.migration_column c on c.rid_migration_table = t.id_migration_table
and c.ispk
left outer join meta.migration_table tdb on tdb.isdb
and lower(tdb.schemaname) = lower(t.schemaname)
and lower(tdb.tablename) = lower(t.tablename)
left outer join meta.migration_column cdb on cdb.rid_migration_table = tdb.id_migration_table
and lower(cdb.columnname) = lower(c.columnname)
where t.ismodel
and c.columntype in ('integer','int','bigint','smallint','real','numeric')
and not exists (
select sq.* ,ns.nspname, seqrelid::regclass::text as name
from pg_sequence sq
inner join pg_class sc on sc.oid = sq.seqrelid
inner join pg_namespace ns on ns.oid = sc.relnamespace
and lower(ns.nspname) = lower(t.schemaname)
where
(
lower(seqrelid::regclass::text) = lower(format('identity_%s_%s', t.tablename, c.columnname))
)
)
;
---Set the max values of the sequences
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s.identity_%s_%s', t.schemaname,t.tablename,c.columnname)
,'set sequence'
,t.schemaname
,m_version
,row_number() over (order by t.tablename) as seq
,200
,format($B$DO $SEQ$
DECLARE
m_cnt bigint;
BEGIN
IF EXISTS (
SELECT 1
FROM pg_class C
inner join pg_namespace ns on ns.oid = c.relnamespace
and lower(ns.nspname) = lower('%4$s')
where c.relname = '%1$s' and lower(relkind) = 's'
)
then
select ( coalesce(max(%5$s.%6$s),0) + 1)::bigint
from %4$s.%5$s
into m_cnt;
perform setval('%4$s.%1$s',m_cnt);
end if;
END;$SEQ$;
$B$,
format('identity_%s_%s', t.tablename,c.columnname)
,case when c.seqseed > 0 then c.seqseed else 1 end
,format('%s.%s.%s',t.tablename,c.columnname,c.guid)
,t.schemaname ---%4$s
,t.tablename
,c.columnname --%6$s
)
from meta.migration_table t
inner join meta.migration_column c on c.rid_migration_table = t.id_migration_table
and c.ispk
left outer join meta.migration_table tdb on tdb.isdb
and lower(tdb.schemaname) = lower(t.schemaname)
and lower(tdb.tablename) = lower(t.tablename)
left outer join meta.migration_column cdb on cdb.rid_migration_table = tdb.id_migration_table
and lower(cdb.columnname) = lower(c.columnname)
where t.ismodel
and c.columntype in ('integer','int','bigint','smallint','real','numeric')
-- and not exists (
-- select sq.* ,ns.nspname, seqrelid::regclass::text as name
-- from pg_sequence sq
-- inner join pg_class sc on sc.oid = sq.seqrelid
-- inner join pg_namespace ns on ns.oid = sc.relnamespace
-- and lower(ns.nspname) = lower(t.schemaname)
-- where
-- (
-- lower(seqrelid::regclass::text) = lower(format('identity_%s_%s', t.tablename, c.columnname))
-- )
-- )
;
end if;
if p_type in ('all','comment')
then
---comment tables
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s',tdb.schemaname,tdb.tablename)
,'COMMENT ON TABLE'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,80
,format($A$
COMMENT ON TABLE %1$s.%2$s IS '%3$s';
$A$,tdb.schemaname,tdb.tablename,tmd.guid )
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.tablename = tmd.tablename
and tdb.schemaname = tmd.schemaname
and tdb.isdb
where tmd.ismodel
and tmd.guid is distinct from tdb.guid
;
---comment columns
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s_%s',tdb.schemaname,tdb.tablename)
,'COMMENT ON COLUMNS'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,80
,str.code
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.tablename = tmd.tablename
and tdb.schemaname = tmd.schemaname
and tdb.isdb
inner join lateral (
select string_agg(
format($A$COMMENT ON Column %1$s.%2$s.%3$s IS '%4$s';$A$, tdb.schemaname, tdb.tablename,colmd.columnname, colmd.guid)
,E' \n') as code
,count(1) as cnt
from meta.migration_column colmd
inner join meta.migration_column coldb on coldb.rid_migration_table = tdb.id_migration_table
and coldb.columnname = colmd.columnname
where colmd.rid_migration_table = tmd.id_migration_table
and colmd.guid is distinct from coldb.guid
) str on str.cnt > 0
where tmd.ismodel
;
---comment sequences
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('%s.identity_%s_%s', t.schemaname,t.tablename,c.columnname)
,'COMMENT ON sequence'
,t.schemaname
,m_version
,row_number() over (order by t.tablename) as seq
,110
,format($B$
comment on sequence %4$s.%1$s is '%3$s';
$B$, format('identity_%s_%s', t.tablename,c.columnname)
,COALESCE(c.seqseed,1)
,format('%s.%s.%s',t.tablename,c.columnname,c.guid)
,t.schemaname
)
from meta.migration_table t
inner join meta.migration_column c on c.id_migration_column = t.id_migration_table
and c.ispk
inner join meta.migration_table tdb on lower(tdb.schemaname) = lower(t.schemaname)
and lower(tdb.tablename) = lower(t.tablename)
and tdb.isdb
inner join meta.migration_column cdb on cdb.rid_migration_table = tdb.id_migration_table
and lower(cdb.columnname) = lower(c.columnname)
and lower(cdb.guid) is distinct from lower(c.guid)
where t.ismodel;
end if;
if p_type in ('all','triggers')
then
--Create Relation Triggers
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('ftpl_del_%s_%s_%s_to_%s_%s',rel.relationname,tmd.schemaname,tmd.tablename,tmdc.schemaname,tmdc.tablename)
,'create relation trigger'
,tmd.schemaname
,m_version
,row_number() over (order by rel.sequence, tmd.tablename)
,195
,case when rel.deleteconstraint = 'RESTRICT'
then format($A$
CREATE OR REPLACE FUNCTION ftpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s() RETURNS TRIGGER
as $TR$
BEGIN
if not exists (
select 1
from %5$s
where (%6$s) = (%7$s)
)
then
raise exception 'Children exits on %3$s';
end if;
return null;
END;
$TR$;
DO $DOSTR$
BEGIN
if not exists (
select 1
from information_schema.triggers t
where lower(t.event_object_table::text) = lower('%3$s')
and lower(t.trigger_schema::text) = lower('%2$s')
and t.trigger_name::citext = lower('ctpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s')
)
then
create trigger ctpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s
after delete
on %2$s.%3$s
for each row
execute procedure ftpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s()
;
end if;
END;
$DOSTR$;
$A$,rel.relationname --%1$s
,tmd.schemaname
,tmd.tablename --%3$s
,tmdc.schemaname --%4$s
,tmdc.tablename --%5$s
,col_child.tlist
,col_par.tlist
)
when rel.deleteconstraint = 'CASCADE'
then format($A$
CREATE OR REPLACE FUNCTION ftpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s() RETURNS TRIGGER
as $TR$
BEGIN
if core.not_triggerable(tg_name, tg_table_schema, tg_table_name,tg_op)
then
return null;
end if;
if exists (
select 1
from %5$s
where (%6$s) = (%7$s)
)
then
delete from %5$s
where (%6$s) = (%7$s)
end if;
return null;
END;
$TR$;
DO $DOSTR$
BEGIN
if not exists (
select 1
from information_schema.triggers t
where lower(t.event_object_table::text) = lower('%3$s')
and lower(t.trigger_schema::text) = lower('%2$s')
and t.trigger_name::citext = lower('ctpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s')
)
then
create trigger ctpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s
after delete
on %2$s.%3$s
for each row
execute procedure ftpl_del_%1$s_%2$s_%3$s_to_%4$s_%5$s()
;
end if;
END;
$DOSTR$;
$A$,rel.relationname --%1$s
,tmd.schemaname
,tmd.tablename --%3$s
,tmdc.schemaname --%4$s
,tmdc.tablename --%5$s
,col_child.tlist
,col_par.tlist
)
else ''
end
from meta.migration_relation rel
inner join meta.migration_table tmd on tmd.id_migration_table = rel.rid_migration_table_parent
and tmd.ismodel
inner join meta.migration_table tmdc on tmdc.id_migration_table = rel.rid_migration_table_child
and tmdc.ismodel
inner join lateral (
select
string_agg(col.columnname,',' order by rcol.sequence, col.columnname) as list
,string_agg(format('%s.%s',tmd.tablename,col.columnname),',' order by rcol.sequence, col.columnname) as tlist
from meta.migration_relation_col rcol
inner join meta.migration_column col on col.id_migration_column = rcol.rid_migration_column_parent
and col.rid_migration_table = tmd.id_migration_table
where rcol.rid_migration_relation = rel.id_migration_relation
) col_par on true
inner join lateral (
select string_agg(format('%s',col.columnname),',' order by rcol.sequence, col.columnname) as list
,string_agg(format('OLD.%s',col.columnname),',' order by rcol.sequence, col.columnname) as tlist
from meta.migration_relation_col rcol
inner join meta.migration_column col on col.id_migration_column = rcol.rid_migration_column_child
and col.rid_migration_table = tmdc.id_migration_table
where rcol.rid_migration_relation = rel.id_migration_relation
) col_child on true
where tmd.ismodel
and rel.deleteconstraint in ('UPDATE','CASCADE')
and not exists (
select 1
from meta.migration_relation dbrel
inner join meta.migration_table tdb on dbrel.rid_migration_table_parent = tdb.id_migration_table
where dbrel.isdb
-- and tdb.schemaname = tmd.schemaname
-- and tdb.tablename = tmd.tablename
and dbrel.relationname = rel.relationname
)
;
--Todo update cascades
-- concurrency triggers
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select format('tf_concurrency_check_%s_%s',tdb.schemaname,tdb.tablename)
,'concurrency trigger function'
,tmd.schemaname
,m_version
,row_number() over (order by tmd.tablename)
,550
,format($F$ CREATE OR REPLACE FUNCTION %1$s.%3$s()
returns trigger
LANGUAGE plpgsql VOLATILE
AS $FI$
DECLARE
--Error Handling--
m_funcname text = '%3$s';
m_errmsg text;
m_errcontext text;
m_errdetail text;
m_errhint text;
m_errstate text;
m_retval integer;
--Error Handling--
BEGIN
if core.not_triggerable(tg_name, tg_table_schema, tg_table_name,tg_op)
then
return NEW;
end if;
if TG_WHEN = 'After'
then
raise exception 'You should not use after triggers. Fix this.';
end if;
if not (
%4$s
)
then
return NEW;
end if;
if nv(NEW.updatecnt) is distinct from nv(OLD.updatecnt)
then
raise E'This record has been changed by another station.\r\nAll values inserted by the other station will now be displayed upon closing this message.\r\nRe-enter changes and save the record in order to update the values.';
end if;
if OLD.updatecnt >= 214748364
then
NEW.updatecnt = 1;
else
NEW.updatecnt = nv(OLD.updatecnt) + 1;
end if;
if exists (
select 1
from information_schema.columns c
where c.table_name = TG_TABLE_NAME::citext
and c.table_schema = TG_TABLE_SCHEMA::citext
and c.column_name = 'prefix'
)
then
if NEW.prefix is null or NEW.prefix = ''
then
NEW.prefix = f_tableprefix(TG_TABLE_NAME,TG_TABLE_SCHEMA);
end if;
end if;
return NEW;
END;
$FI$;
----Create actual trigger
DO $FD$
BEGIN
if not exists (
select 1
from information_schema.triggers t
where t.trigger_schema = '%1$s'
and t.trigger_name = 't_concurrency_%1$s_%2$s'
)
then
CREATE TRIGGER t_concurrency_%1$s_%2$s
before update
on %1$s.%2$s FOR EACH ROW
EXECUTE PROCEDURE %1$s.%3$s();
end if;
END;
$FD$;
$F$
,tdb.schemaname
,tdb.tablename
,format('tf_concurrency_check_%s_%s',tdb.schemaname,tdb.tablename)
,cols.cols
)
from meta.migration_table tmd
inner join meta.migration_table tdb on tdb.tablename = tmd.tablename
and tdb.schemaname = tmd.schemaname
and tdb.isdb
and tmd.tablename not in (select ut.tablename from meta.f_upgrade_table(tmd.schemaname) ut )
inner join lateral (
--cols diff
select string_agg(format('OLD.%s IS DISTINCT FROM NEW.%s',c.columnname,c.columnname),E'\n or ') as cols
,count(1) as cnt
from meta.migration_column c
where c.rid_migration_table = tmd.id_migration_table
and c.columnname not in ('updatecnt')
and (c.columnname not ilike '%_dropped%' or c.columnname not ilike '%dropped_%' )
and coalesce(c.columnname,'') <> ''
) cols on cols.cnt > 0 and coalesce(cols.cols) <> ''
where tmd.ismodel
;
end if;
if p_type in ('all','audit')
and exists (
select ns.nspname
,p.proname
from pg_proc p
inner join pg_namespace ns on ns.oid = p.pronamespace
where p.proname = 'f_audit_build'
and ns.nspname = 'meta'
and pg_get_function_result(p.oid) ilike '%schemaname%'
)
then
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (r.scripttype, r.objectname)
r.objectname
,r.scripttype
,r.schemaname
,m_version
,r.scriptpriority::integer
,200
,r.scriptcode
from meta.f_audit_build(1) r
where not exists (
select 1
from meta.migration_script s
where s.objectname = r.objectname
and s.objecttype = r.scripttype
)
;
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select distinct on (r.scripttype, r.objectname)
r.objectname
,r.scripttype
,r.schemaname
,m_version
,r.scriptpriority::integer
,400
,r.scriptcode
from meta.f_audit_build(2) r
;
end if;
if p_type in ('functions')
then
----Procedures, Functions and objects
insert into meta.migration_script(objectname, objecttype, schema, version, sequence, priority, body)
select o.objectname,o.objecttype,o.schema,o.version,o.sequence,o.priority,o.body
from meta.migration_object o
where o.ismodel
and o.objecttype ilike 'script:%'
;
end if;
perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',2,'objecttype',m_funcname, 'tm',clock_timestamp()::text)::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, 'tm',clock_timestamp()::text)::text);
END;
$$;