244 lines
9.0 KiB
PL/PgSQL
244 lines
9.0 KiB
PL/PgSQL
rollback;
|
|
drop table if exists hs_hosting_asset_versions;
|
|
drop table if exists hs_hosting_asset_ex;
|
|
drop view if exists hs_hosting_asset_hv;
|
|
drop procedure if exists tx_create_historicization;
|
|
drop view if exists tx_create_historical_view;
|
|
drop function if exists tx_historicize_tf();
|
|
drop table if exists tx_history;
|
|
drop type if exists tx_operation;
|
|
|
|
-- ========================================================
|
|
-- Historization
|
|
-- --------------------------------------------------------
|
|
|
|
create table "tx_history"
|
|
(
|
|
"tx_id" bigint not null unique,
|
|
"tx_timestamp" timestamp not null,
|
|
"user" varchar(64) not null, -- references postgres user
|
|
"task" varchar not null
|
|
);
|
|
|
|
create type "tx_operation" as enum ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE');
|
|
|
|
-- see https://www.postgresql.org/docs/current/plpgsql-trigger.html
|
|
|
|
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 tx_history VALUES (txid_current(), now(), %1L, %2L) ON CONFLICT DO NOTHING', currentUser,
|
|
currentTask);
|
|
raise notice 'sql: %', sql;
|
|
execute sql;
|
|
sql := format('INSERT INTO %3$I_ex VALUES (DEFAULT, txid_current(), %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_historical_view(baseTable varchar)
|
|
language plpgsql as $$
|
|
declare
|
|
createTriggerSQL varchar;
|
|
viewName varchar;
|
|
versionsTable varchar;
|
|
createViewSQL varchar;
|
|
baseCols varchar;
|
|
begin
|
|
|
|
viewName = quote_ident(format('%s_hv', baseTable));
|
|
versionsTable = 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' ||
|
|
'(' ||
|
|
' SELECT %2$s' ||
|
|
' FROM %3$s' ||
|
|
' WHERE alive = TRUE' ||
|
|
' AND version_id IN' ||
|
|
' (' ||
|
|
' SELECT max(vt.version_id) AS history_id' ||
|
|
' FROM %3$s AS vt' ||
|
|
' JOIN tx_history as txh ON vt.tx_id = txh.tx_id' ||
|
|
' WHERE txh.tx_timestamp <= current_setting(''hsadminng.timestamp'')::timestamp' ||
|
|
' GROUP BY uuid' ||
|
|
' )' ||
|
|
')',
|
|
viewName, baseCols, versionsTable
|
|
);
|
|
raise notice 'sql: %', createViewSQL;
|
|
execute createViewSQL;
|
|
|
|
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_tx_historicize_tf' ||
|
|
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
|
|
' FOR EACH ROW EXECUTE PROCEDURE tx_historicize_tf()';
|
|
raise notice 'sql: %', createTriggerSQL;
|
|
execute createTriggerSQL;
|
|
|
|
end; $$;
|
|
|
|
create or replace procedure tx_create_historicization(baseTable varchar)
|
|
language plpgsql as $$
|
|
declare
|
|
createHistTableSql varchar;
|
|
createTriggerSQL varchar;
|
|
viewName varchar;
|
|
versionsTable varchar;
|
|
createViewSQL varchar;
|
|
baseCols varchar;
|
|
begin
|
|
|
|
-- create the history table
|
|
createHistTableSql = '' ||
|
|
'CREATE TABLE ' || baseTable || '_ex (' ||
|
|
' version_id serial PRIMARY KEY,' ||
|
|
' tx_id bigint NOT NULL REFERENCES tx_history(tx_id),' ||
|
|
' 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));
|
|
versionsTable = 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' ||
|
|
'(' ||
|
|
' SELECT %2$s' ||
|
|
' FROM %3$s' ||
|
|
' WHERE alive = TRUE' ||
|
|
' AND version_id IN' ||
|
|
' (' ||
|
|
' SELECT max(vt.version_id) AS history_id' ||
|
|
' FROM %3$s AS vt' ||
|
|
' JOIN tx_history as txh ON vt.tx_id = txh.tx_id' ||
|
|
' WHERE txh.tx_timestamp <= current_setting(''hsadminng.timestamp'')::timestamp' ||
|
|
' GROUP BY id' ||
|
|
' )' ||
|
|
')',
|
|
viewName, baseCols, versionsTable
|
|
);
|
|
raise notice 'sql: %', createViewSQL;
|
|
execute createViewSQL;
|
|
|
|
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_tx_historicize_tf' ||
|
|
' 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');
|
|
|
|
-- and expanded:
|
|
|
|
create table hs_hosting_asset_ex
|
|
(
|
|
version_id serial primary key,
|
|
tx_id bigint not null references tx_history (tx_id),
|
|
trigger_op tx_operation not null,
|
|
alive boolean not null,
|
|
like hs_hosting_asset excluding constraints excluding statistics
|
|
);
|
|
|
|
create or replace view hs_hosting_asset_hv as
|
|
(
|
|
select uuid,
|
|
version,
|
|
bookingitemuuid,
|
|
type,
|
|
parentassetuuid,
|
|
assignedtoassetuuid,
|
|
identifier,
|
|
caption,
|
|
config,
|
|
alarmcontactuuid
|
|
from hs_hosting_asset_ex
|
|
where alive = true
|
|
and version_id in (select max(vt.version_id) as history_id
|
|
from hs_hosting_asset_ex as vt
|
|
join tx_history as txh on vt.tx_id = txh.tx_id
|
|
where txh.tx_timestamp <= current_setting('hsadminng.timestamp')::timestamp
|
|
group by uuid)
|
|
);
|
|
|
|
CREATE TRIGGER hs_hosting_asset_tx_historicize_tf
|
|
AFTER INSERT OR DELETE OR UPDATE ON hs_hosting_asset
|
|
FOR EACH ROW EXECUTE PROCEDURE tx_historicize_tf();
|
|
|
|
-- ===========================================================================================
|
|
|
|
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='mim00 d' where identifier = 'mim00' and type = 'MANAGED_WEBSPACE'; -- test
|
|
commit;
|
|
|
|
-- all versions
|
|
select txh.tx_timestamp, txh."user", txh.task, ha.*
|
|
from hs_hosting_asset_ex ha
|
|
join tx_history txh on ha.tx_id=txh.tx_id
|
|
where ha.identifier in ('lug00', 'mim00');
|
|
|
|
-- single version at point in time
|
|
set hsadminng.timestamp to '2024-08-27 04:15:00'; -- UTC
|
|
select uuid, version, identifier, caption from hs_hosting_asset_hv p where identifier in ('lug00', 'mim00');
|