hs.hsadmin.ng/sql/historization.sql
2024-08-27 20:03:03 +02:00

183 lines
7.1 KiB
PL/PgSQL

rollback;
drop table if exists hs_hosting_asset_versions;
drop view if exists hs_hosting_asset_hv;
drop table if exists hs_hosting_asset_ex;
drop procedure if exists tx_create_historicization;
drop trigger if exists hs_hosting_asset_tx_historicize_tg on hs_hosting_asset;
drop function if exists tx_historicize_tf();
drop type if exists tx_operation;
-- ========================================================
-- Historization
-- --------------------------------------------------------
-- FIXME: Liquibase-integration
create type "tx_operation" as enum ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE');
create or replace function tx_history_txid()
returns xid8 stable
language plpgsql as $$
declare
historicalTxIdSetting text;
historicalTxId xid8;
historicalTimestamp timestamp;
begin
select current_setting('hsadminng.tx_history_txid', true) into historicalTxIdSetting;
raise notice 'tx_history_txid(): historicalTxIdSetting=%', historicalTxIdSetting;
if historicalTxIdSetting is null or historicalTxIdSetting = '' then
select current_setting('hsadminng.tx_history_timestamp', true)::timestamp into historicalTimestamp;
raise notice 'tx_history_txid(): historicalTimestamp=%', historicalTimestamp;
select max(txc.txid) from tx_context txc where txc.txtimestamp <= historicalTimestamp into historicalTxId;
raise notice 'tx_history_txid(): historicalTxId=%', historicalTxId;
else
historicalTxId = historicalTxIdSetting::xid8;
end if;
return historicalTxId;
end; $$;
create or replace function tx_historicize_tf()
returns trigger
language plpgsql
strict as $$
declare
currentUser varchar(63);
currentTask varchar(127);
"row" record;
"alive" boolean;
"sql" varchar;
begin
-- determine user_id
begin
currentUser := current_setting('hsadminng.currentUser');
exception
when others then
currentUser := null;
end;
if (currentUser is null or currentUser = '') then
raise exception 'hsadminng.currentUser must be defined, please use "SET LOCAL ...;"';
end if;
raise notice 'currentUser: %', currentUser;
-- determine task
currentTask = current_setting('hsadminng.currentTask');
assert currentTask is not null and length(currentTask) >= 12,
format('hsadminng.currentTask (%s) must be defined and min 12 characters long, please use "SET LOCAL ...;"',
currentTask);
assert length(currentTask) <= 127,
format('hsadminng.currentTask (%s) must not be longer than 127 characters"', currentTask);
if (TG_OP = 'INSERT') or (TG_OP = 'UPDATE') then
"row" := NEW;
"alive" := true;
else -- DELETE or TRUNCATE
"row" := OLD;
"alive" := false;
end if;
sql := format('INSERT INTO %3$I_ex VALUES (DEFAULT, pg_current_xact_id(), %1$L, %2$L, $1.*)', TG_OP, alive, TG_TABLE_NAME);
raise notice 'sql: %', sql;
execute sql using "row";
return "row";
end; $$;
create or replace procedure tx_create_historicization(baseTable varchar)
language plpgsql as $$
declare
createHistTableSql varchar;
createTriggerSQL varchar;
viewName varchar;
exVersionsTable varchar;
createViewSQL varchar;
baseCols varchar;
begin
-- create the history table
createHistTableSql = '' ||
'CREATE TABLE ' || baseTable || '_ex (' ||
' version_id serial PRIMARY KEY,' ||
' txid xid8 NOT NULL REFERENCES tx_context(txid),' ||
' trigger_op tx_operation NOT NULL,' ||
' alive boolean not null,' ||
' LIKE ' || baseTable ||
' EXCLUDING CONSTRAINTS' ||
' EXCLUDING STATISTICS' ||
')';
raise notice 'sql: %', createHistTableSql;
execute createHistTableSql;
-- create the historical view
viewName = quote_ident(format('%s_hv', baseTable));
exVersionsTable = quote_ident(format('%s_ex', baseTable));
baseCols = (select string_agg(quote_ident(column_name), ', ')
from information_schema.columns
where table_schema = 'public'
and table_name = baseTable);
createViewSQL = format(
'CREATE OR REPLACE VIEW %1$s AS' ||
'(' ||
-- make sure the function is only called once, not for every matching row in tx_context
' WITH txh AS (SELECT tx_history_txid() AS txid) ' ||
' SELECT %2$s' ||
' FROM %3$s' ||
' WHERE alive = TRUE' ||
' AND version_id IN' ||
' (' ||
' SELECT max(ex.version_id) AS history_id' ||
' FROM %3$s AS ex' ||
' JOIN tx_context as txc ON ex.txid = txc.txid' ||
' WHERE txc.txid <= (SELECT txid FROM txh)' ||
' GROUP BY uuid' ||
' )' ||
')',
viewName, baseCols, exVersionsTable
);
raise notice 'sql: %', createViewSQL;
execute createViewSQL;
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_tx_historicize_tg' ||
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
' FOR EACH ROW EXECUTE PROCEDURE tx_historicize_tf()';
raise notice 'sql: %', createTriggerSQL;
execute createTriggerSQL;
end; $$;
--- ==================================================
call tx_create_historicization('hs_hosting_asset'); -- FIXME: move to 7010-hosting-asset.sql
-- ===========================================================================================
rollback;
begin transaction;
call defineContext('historization testing', null, 'superuser-alex@hostsharing.net',
'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); -- prod+test
-- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); -- prod
-- 'hs_booking_project#D-1000300-mimdefaultproject:ADMIN'); -- test
-- update hs_hosting_asset set caption='lug00 b' where identifier = 'lug00' and type = 'MANAGED_WEBSPACE'; -- prod
update hs_hosting_asset set caption='hsh00 C ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test
update hs_hosting_asset set caption='hsh00 D ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test
commit;
-- single version at point in time
-- set hsadminng.tx_history_txid to (select max(txid) from tx_context where txtimestamp<='2024-08-27 12:13:13.450821');
set hsadminng.tx_history_txid to '3249';
--set hsadminng.tx_history_timestamp to '2024-08-27 17:52:07.755407';
-- all versions
select tx_history_txid(), txc.txtimestamp, txc.currentUser, txc.currentTask, haex.*
from hs_hosting_asset_ex haex
join tx_context txc on haex.txid=txc.txid
where haex.identifier in ('hsh00', 'mim00');
select uuid, version, identifier, caption from hs_hosting_asset_hv p where identifier in ('hsh00', 'mim00');
select pg_current_xact_id();