-- ======================================================== -- Historization -- -------------------------------------------------------- drop PROCEDURE if exists tx_create_historical_view; drop procedure if exists tx_create_historicization; drop view if exists hs_hosting_asset_hv; drop table if exists hs_hosting_asset_ex; drop trigger if exists hs_hosting_asset_historicize_tg on hs_hosting_asset; drop procedure if exists tx_historicize_tf; drop type "tx_operation"; CREATE TYPE "tx_operation" AS ENUM ('INSERT', 'UPDATE', 'DELETE'); CREATE OR REPLACE FUNCTION tx_historicize_tf() RETURNS trigger LANGUAGE plpgsql STRICT AS $$ DECLARE currentTask VARCHAR(127); curContextId bigint; "row" RECORD; "alive" BOOLEAN; "sql" varchar; BEGIN -- 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; curContextId := txid_current()+bigIntHash(currentTask); sql := format('INSERT INTO %3$I_ex ' || ' VALUES (DEFAULT, curContextId, %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.historical_timestamp'')::timestamp' || ' GROUP BY id' || ' )' || ')', viewName, baseCols, versionsTable ); RAISE NOTICE 'sql: %', createViewSQL; EXECUTE createViewSQL; createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_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; $$; -- ------ 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,' || ' context_id bigint NOT NULL REFERENCES tx_context(contextid),' || ' trigger_op tx_operation NOT NULL,' || ' alive boolean not null,' || -- followed by all columns of the original table ' 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_context as txc ON vt.context_id = txc.contextid' || ' WHERE txc.txtimestamp <= current_setting(''hsadminng.historical_timestamp'')::timestamp' || ' GROUP BY context_id' || ' )' || ')', viewName, baseCols, versionsTable ); RAISE NOTICE 'sql: %', createViewSQL; EXECUTE createViewSQL; createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_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'); ROLLBACK; BEGIN TRANSACTION; call defineContext('historization testing', null, 'superuser-alex@hostsharing.net', 'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); -- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); update hs_hosting_asset set caption='lug00 a' where identifier='lug00' and type='MANAGED_WEBSPACE'; COMMIT; SET hsadminng.historical_timestamp TO '2022-07-12 11:38:27.723315'; SELECT * FROM hs_hosting_asset_ex p WHERE identifier = 'lug00';