diff --git a/.run/ImportHostingAssets into local.run.xml b/.run/ImportHostingAssets into local.run.xml new file mode 100644 index 00000000..d3c7f2da --- /dev/null +++ b/.run/ImportHostingAssets into local.run.xml @@ -0,0 +1,37 @@ + + + + + + + + false + true + + + + false + true + + + \ No newline at end of file diff --git a/.run/ImportHostingAssets.run.xml b/.run/ImportHostingAssets.run.xml index 2a7b71f6..bedd7143 100644 --- a/.run/ImportHostingAssets.run.xml +++ b/.run/ImportHostingAssets.run.xml @@ -33,37 +33,4 @@ true - - - - - - - false - true - - - - false - true - - \ No newline at end of file diff --git a/sql/examples.sql b/sql/examples.sql deleted file mode 100644 index 13219654..00000000 --- a/sql/examples.sql +++ /dev/null @@ -1,53 +0,0 @@ --- ======================================================== --- First Example Entity with History --- -------------------------------------------------------- - -CREATE TABLE IF NOT EXISTS customer ( - "id" SERIAL PRIMARY KEY, - "reference" int not null unique, -- 10000-99999 - "prefix" character(3) unique - ); - -CALL create_historicization('customer'); - - --- ======================================================== --- Second Example Entity with History --- -------------------------------------------------------- - -CREATE TABLE IF NOT EXISTS package_type ( - "id" serial PRIMARY KEY, - "name" character varying(8) - ); - -CALL create_historicization('package_type'); - --- ======================================================== --- Third Example Entity with History --- -------------------------------------------------------- - -CREATE TABLE IF NOT EXISTS package ( - "id" serial PRIMARY KEY, - "name" character varying(5), - "customer_id" INTEGER REFERENCES customer(id) - ); - -CALL create_historicization('package'); - - --- ======================================================== --- query historical data --- -------------------------------------------------------- - - -ABORT; -BEGIN TRANSACTION; -SET LOCAL hsadminng.currentUser TO 'mih42_customer_aaa'; -SET LOCAL hsadminng.currentTask TO 'adding customer_aaa'; -INSERT INTO package (customer_id, name) VALUES (10000, 'aaa00'); -COMMIT; --- Usage: - -SET hsadminng.timestamp TO '2022-07-12 08:53:27.723315'; -SET hsadminng.timestamp TO '2022-07-12 11:38:27.723315'; -SELECT * FROM customer_hv p WHERE prefix = 'aaa'; diff --git a/sql/historization-ng.sql b/sql/historization-ng.sql new file mode 100644 index 00000000..d9d3e98c --- /dev/null +++ b/sql/historization-ng.sql @@ -0,0 +1,174 @@ + +-- ======================================================== +-- 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'; diff --git a/sql/historization.sql b/sql/historization.sql index 1bd0db44..b414b95c 100644 --- a/sql/historization.sql +++ b/sql/historization.sql @@ -1,143 +1,158 @@ +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 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 "operation" AS ENUM ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE'); +create type "tx_operation" as enum ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE'); -- see https://www.postgresql.org/docs/current/plpgsql-trigger.html -CREATE OR REPLACE FUNCTION historicize() - RETURNS trigger - LANGUAGE plpgsql STRICT AS $$ -DECLARE - currentUser VARCHAR(63); - currentTask VARCHAR(127); - "row" RECORD; - "alive" BOOLEAN; - "sql" varchar; -BEGIN +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 + 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; + 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 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 + if (TG_OP = 'INSERT') or (TG_OP = 'UPDATE') then "row" := NEW; - "alive" := TRUE; - ELSE -- DELETE or TRUNCATE - "row" := OLD; - "alive" := FALSE; - END IF; + "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_versions VALUES (DEFAULT, txid_current(), %1$L, %2$L, $1.*)', TG_OP, alive, TG_TABLE_NAME); - RAISE NOTICE 'sql: %', sql; - EXECUTE sql USING "row"; + 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; $$; + return "row"; +end; $$; -CREATE OR REPLACE PROCEDURE create_historical_view(baseTable varchar) - LANGUAGE plpgsql AS $$ -DECLARE -createTriggerSQL varchar; - viewName varchar; - versionsTable varchar; - createViewSQL varchar; - baseCols varchar; -BEGIN +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_versions', baseTable)); - baseCols = (SELECT string_agg(quote_ident(column_name), ', ') - FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 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; + '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 || '_historicize' || - ' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable || - ' FOR EACH ROW EXECUTE PROCEDURE historicize()'; - RAISE NOTICE 'sql: %', createTriggerSQL; -EXECUTE createTriggerSQL; + 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; $$; +end; $$; -CREATE OR REPLACE PROCEDURE create_historicization(baseTable varchar) - LANGUAGE plpgsql AS $$ -DECLARE +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 + createTriggerSQL varchar; + viewName varchar; + versionsTable varchar; + createViewSQL varchar; + baseCols varchar; +begin -- create the history table createHistTableSql = '' || - 'CREATE TABLE ' || baseTable || '_versions (' || - ' version_id serial PRIMARY KEY,' || - ' tx_id bigint NOT NULL REFERENCES tx_history(tx_id),' || - ' trigger_op operation NOT NULL,' || - ' alive boolean not null,' || - - ' LIKE ' || baseTable || - ' EXCLUDING CONSTRAINTS' || - ' EXCLUDING STATISTICS' || - ')'; - RAISE NOTICE 'sql: %', createHistTableSql; - EXECUTE 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_versions', baseTable)); - baseCols = (SELECT string_agg(quote_ident(column_name), ', ') - FROM information_schema.columns - WHERE table_schema = 'public' AND table_name = 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( + createViewSQL = format( 'CREATE OR REPLACE VIEW %1$s AS' || '(' || ' SELECT %2$s' || @@ -153,14 +168,76 @@ BEGIN ' )' || ')', viewName, baseCols, versionsTable - ); - RAISE NOTICE 'sql: %', createViewSQL; - EXECUTE createViewSQL; + ); + raise notice 'sql: %', createViewSQL; + execute createViewSQL; - createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_historicize' || - ' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable || - ' FOR EACH ROW EXECUTE PROCEDURE historicize()'; - RAISE NOTICE 'sql: %', createTriggerSQL; - EXECUTE createTriggerSQL; + 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; $$; +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');