Files
relspecgo/examples/pgsql_meta_upgrade/migration_init.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

369 lines
12 KiB
PL/PgSQL

select * from dropall('migration_init','meta');
CREATE OR REPLACE FUNCTION meta.migration_init(
p_version text default ''
,INOUT p_info jsonb default null
,OUT p_retval integer
,OUT p_errmsg text
)
LANGUAGE plpgsql VOLATILE
SECURITY DEFINER
AS
$$
DECLARE
m_except _except_type;
m_dblink_conn TEXT;
m_dblink_login TEXT;
m_pid integer;
m_result text;
m_gotemplate text;
m_qry text;
m_id_model integer;
BEGIN
m_except.func_name = 'migration_init';
p_retval = 0;
p_errmsg = '';
m_dblink_conn := 'dblink_migration_boot';
m_pid = pg_backend_pid();
perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',1,'objecttype',m_except.func_name, 'tm',clock_timestamp()::text)::text);
if p_info is null
then
p_info = jsonb_build_object();
end if;
select f.id_migration_model
from meta.migration_model f
where f.version = p_version
or coalesce(p_version,'') = ''
order by f.changedat desc
limit 1
into m_id_model;
if coalesce(m_id_model,0) = 0
then
raise exception 'Model/File does not exist for version %',p_version;
end if;
-- delete from meta.migration_script s
-- where s.rid_migration_model = m_id_model or s.rid_migration_model is null;
--
-- delete from meta.migration_relation s
-- where s.rid_migration_model = m_id_model or s.rid_migration_model is null;
--
-- delete from meta.migration_index s
-- where s.rid_migration_model = m_id_model or s.rid_migration_model is null;
--
-- delete from meta.migration_table s
-- where s.rid_migration_model = m_id_model or s.rid_migration_model is null;
m_gotemplate = $CQl$do $M$
declare
m_retval integer;
m_errmsg text;
m_info jsonb;
m_file bytea;
m_version text;
m_rid_model integer;
begin
m_version = $CQl$ || quote_literal(p_version) || $CQl$;
m_rid_model = $CQl$ ||m_id_model || $CQl$;
perform log_event($CQl$ || quote_literal(m_except.func_name) || $CQl$ ,'[message]',bt_enum('eventlog','upgrade'),1);
[proc]
end;
$M$;
$CQl$;
select 'host=127.0.0.1 dbname='||r.dbname||' port=' || r.port || ' user='|| r.loginuser ||' password=' || r.password
from f_get_local_conn('migration') r
into m_dblink_login;
if not exists (SELECT T.text from unnest(dblink_get_connections()) T where T.text = m_dblink_conn)
then
PERFORM dblink_connect(m_dblink_conn, m_dblink_login);
end if;
perform log_event(m_except.func_name,format('migrations init with connection %s',m_dblink_conn),bt_enum('eventlog','upgrade'));
PERFORM dblink_exec(m_dblink_conn, format($S$set application_name to 'MIGRATION:%s'; $S$, m_pid), true);
m_qry = replace(replace(m_gotemplate,'[message]','Reading migration models'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_read(m_rid_model) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to read model: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
-- raise notice 'Status - Reading migration models: % Qry:%', m_result , m_qry;
---Prime old upgrades
m_qry = replace(replace(m_gotemplate,'[message]','Inspecting database'),'[proc]',$CQl$
if exists (
select 1
from information_schema.tables t
where
t.table_name = 'upgrades'
and t.table_schema = 'public'
)
then
insert into public.upgrades(dbversion,status)
select m.version, 0
from meta.migration_model m
where m.id_migration_model = m_rid_model
and not exists (select 1 from public.upgrades s2 where s2.dbversion = m.version)
;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
--inspect
m_qry = replace(replace(m_gotemplate,'[message]','Inspecting database'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_inspect(m_rid_model,$CQl$ || quote_literal(p_info::text) || $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to inspect database: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
-- raise notice 'Status - Inspecting database: % Qry:%', m_result, m_qry;
--Drops
m_qry = replace(replace(m_gotemplate,'[message]','Build Differential (Drops)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_build(m_rid_model,'drop',$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to build differential: % ', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
--Run Drops
m_qry = replace(replace(m_gotemplate,'[message]','Running Migration Scripts (Drops)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_run(m_rid_model,0,200,$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to run differentials: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
--Renames
m_qry = replace(replace(m_gotemplate,'[message]','Inspecting database (Renames)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_inspect(m_rid_model,$CQl$ || quote_literal(p_info::text) || $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to inspect database: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
-- raise notice 'Status - Inspecting database: % Qry:%', m_result, m_qry;
--Run rename
m_qry = replace(replace(m_gotemplate,'[message]','Build Differential (Renames)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_build(m_rid_model,'rename',$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to build differential: % ', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
--Functions
m_qry = replace(replace(m_gotemplate,'[message]','Build Differential (Renames)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_build(m_rid_model,'functions',$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to build differential: % ', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
m_qry = replace(replace(m_gotemplate,'[message]','Update legacy'),'[proc]',$CQl$
if exists (
select 1
from information_schema.tables t
where
t.table_name = 'upgrades'
and t.table_schema = 'public'
)
then
update public.upgrades s
set totalscripts = r.total
,failedscripts = r.error
,scriptsdone = r.done
from (
select count(1) filter (where s.status <> 4) as total
, count(1) filter (where s.status = 3) as error
, count(1) filter (where s.status = 2 ) as done
from meta.migration_script s
where s.rid_migration_model = m_rid_model
) r
where s.dbversion in (select m.version
from meta.migration_model m
where m.id_migration_model = m_rid_model
);
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
--Run Functions
m_qry = replace(replace(m_gotemplate,'[message]','Running Migration Scripts (Renames)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_run(m_rid_model,0,200,$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to run differentials: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
---Rest
m_qry = replace(replace(m_gotemplate,'[message]','Inspecting database (2nd)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_inspect(m_rid_model,$CQl$ || quote_literal(p_info::text) || $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to inspect database: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
-- Rest
m_qry = replace(replace(m_gotemplate,'[message]','Build Differential (All)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_build(m_rid_model,'all',$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to build differential: % ', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
-- Run Rest
m_qry = replace(replace(m_gotemplate,'[message]','Running Migration Scripts (2nd)'),'[proc]',$CQl$
select r.p_retval, r.p_errmsg, r.p_info
from meta.migration_run(m_rid_model,0,10000,$CQl$ || quote_literal(p_info::text)|| $CQl$::jsonb) r
into m_retval, m_errmsg,m_info;
if m_retval > 0
then
raise exception 'Failed to run differentials: %', m_errmsg;
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
m_qry = replace(replace(m_gotemplate,'[message]','Update legacy'),'[proc]',$CQl$
if exists (
select 1
from information_schema.tables t
where
t.table_name = 'upgrades'
and t.table_schema = 'public'
)
then
update public.upgrades s
set totalscripts = r.total
,failedscripts = r.error
,scriptsdone = r.done
from (
select count(1) filter (where s.status <> 4) as total
, count(1) filter (where s.status = 3) as error
, count(1) filter (where s.status = 2 ) as done
from meta.migration_script s
where s.rid_migration_model = m_rid_model
) r
where s.dbversion in (select m.version
from meta.migration_model m
where m.id_migration_model = m_rid_model
);
end if;
$CQl$);
m_result = dblink_exec(m_dblink_conn, m_qry, true);
--raise notice 'Status - Running Migration Scripts: % Qry:%', m_result, m_qry;
perform dblink_disconnect(m_dblink_conn);
perform log_event(m_except.func_name,'Migration process completed. Check the scripts status for errors',bt_enum('eventlog','upgrade'));
perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',2,'objecttype',m_except.func_name, 'tm',clock_timestamp()::text)::text);
EXCEPTION
WHEN others THEN
GET STACKED DIAGNOSTICS
m_except.message_text = MESSAGE_TEXT
, m_except.pg_exception_context = PG_EXCEPTION_CONTEXT
, m_except.pg_exception_detail = PG_EXCEPTION_DETAIL
, m_except.pg_exception_hint = PG_EXCEPTION_HINT
, m_except.returned_sqlstate = RETURNED_SQLSTATE
, m_except.schema_name = SCHEMA_NAME
, m_except.table_name = TABLE_NAME
, m_except.pg_datatype_name = PG_DATATYPE_NAME
, m_except.constraint_name = CONSTRAINT_NAME
, m_except.column_name = COLUMN_NAME
;
p_errmsg = _except(m_except);
p_retval = 1;
perform log_event(m_except.func_name,format('Migration error: %s',p_errmsg),bt_enum('eventlog','upgrade'));
if exists (SELECT T.text from unnest(dblink_get_connections()) T where T.text = m_dblink_conn)
then
perform dblink_disconnect(m_dblink_conn);
end if;
perform pg_notify('upgrade.events', json_build_object('type','upgrade','status',3,'error',p_errmsg,'objecttype',m_except.func_name, 'tm',clock_timestamp()::text)::text);
END;
$$;