remove table tx_history and use table tx_context instead

This commit is contained in:
Michael Hoennig 2024-08-27 09:48:16 +02:00
parent f973868bf9
commit ac33f99222
3 changed files with 32 additions and 77 deletions

View File

@ -5,25 +5,14 @@ drop view if exists hs_hosting_asset_hv;
drop procedure if exists tx_create_historicization; drop procedure if exists tx_create_historicization;
drop view if exists tx_create_historical_view; drop view if exists tx_create_historical_view;
drop function if exists tx_historicize_tf(); drop function if exists tx_historicize_tf();
drop table if exists tx_history;
drop type if exists tx_operation; drop type if exists tx_operation;
-- ======================================================== -- ========================================================
-- Historization -- 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'); 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() create or replace function tx_historicize_tf()
returns trigger returns trigger
language plpgsql language plpgsql
@ -63,10 +52,6 @@ begin
"alive" := false; "alive" := false;
end if; 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); 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; raise notice 'sql: %', sql;
execute sql using "row"; execute sql using "row";
@ -79,13 +64,13 @@ create or replace procedure tx_create_historical_view(baseTable varchar)
declare declare
createTriggerSQL varchar; createTriggerSQL varchar;
viewName varchar; viewName varchar;
versionsTable varchar; exVersionsTable varchar;
createViewSQL varchar; createViewSQL varchar;
baseCols varchar; baseCols varchar;
begin begin
viewName = quote_ident(format('%s_hv', baseTable)); viewName = quote_ident(format('%s_hv', baseTable));
versionsTable = quote_ident(format('%s_ex', baseTable)); exVersionsTable = quote_ident(format('%s_ex', baseTable));
baseCols = (select string_agg(quote_ident(column_name), ', ') baseCols = (select string_agg(quote_ident(column_name), ', ')
from information_schema.columns from information_schema.columns
where table_schema = 'public' where table_schema = 'public'
@ -99,14 +84,15 @@ begin
' WHERE alive = TRUE' || ' WHERE alive = TRUE' ||
' AND version_id IN' || ' AND version_id IN' ||
' (' || ' (' ||
' SELECT max(vt.version_id) AS history_id' || ' SELECT max(ex.version_id) AS history_id' ||
' FROM %3$s AS vt' || ' FROM %3$s AS ex' ||
' JOIN tx_history as txh ON vt.tx_id = txh.tx_id' || ' JOIN tx_context as txc ON ex.txid = txc.txid' ||
' WHERE txh.tx_timestamp <= current_setting(''hsadminng.timestamp'')::timestamp' || ' WHERE txc.txtimestamp <= current_setting(''hsadminng.tx_history_timestamp'')::timestamp' ||
' OR txc.txid = current_setting(''hsadminng.tx_history_txid'')' ||
' GROUP BY uuid' || ' GROUP BY uuid' ||
' )' || ' )' ||
')', ')',
viewName, baseCols, versionsTable viewName, baseCols, exVersionsTable
); );
raise notice 'sql: %', createViewSQL; raise notice 'sql: %', createViewSQL;
execute createViewSQL; execute createViewSQL;
@ -125,7 +111,7 @@ declare
createHistTableSql varchar; createHistTableSql varchar;
createTriggerSQL varchar; createTriggerSQL varchar;
viewName varchar; viewName varchar;
versionsTable varchar; exVersionsTable varchar;
createViewSQL varchar; createViewSQL varchar;
baseCols varchar; baseCols varchar;
begin begin
@ -134,7 +120,7 @@ begin
createHistTableSql = '' || createHistTableSql = '' ||
'CREATE TABLE ' || baseTable || '_ex (' || 'CREATE TABLE ' || baseTable || '_ex (' ||
' version_id serial PRIMARY KEY,' || ' version_id serial PRIMARY KEY,' ||
' tx_id bigint NOT NULL REFERENCES tx_history(tx_id),' || ' txid bigint NOT NULL REFERENCES tx_context(txid),' ||
' trigger_op tx_operation NOT NULL,' || ' trigger_op tx_operation NOT NULL,' ||
' alive boolean not null,' || ' alive boolean not null,' ||
' LIKE ' || baseTable || ' LIKE ' || baseTable ||
@ -146,7 +132,7 @@ begin
-- create the historical view -- create the historical view
viewName = quote_ident(format('%s_hv', baseTable)); viewName = quote_ident(format('%s_hv', baseTable));
versionsTable = quote_ident(format('%s_ex', baseTable)); exVersionsTable = quote_ident(format('%s_ex', baseTable));
baseCols = (select string_agg(quote_ident(column_name), ', ') baseCols = (select string_agg(quote_ident(column_name), ', ')
from information_schema.columns from information_schema.columns
where table_schema = 'public' where table_schema = 'public'
@ -160,14 +146,14 @@ begin
' WHERE alive = TRUE' || ' WHERE alive = TRUE' ||
' AND version_id IN' || ' AND version_id IN' ||
' (' || ' (' ||
' SELECT max(vt.version_id) AS history_id' || ' SELECT max(ex.version_id) AS history_id' ||
' FROM %3$s AS vt' || ' FROM %3$s AS ex' ||
' JOIN tx_history as txh ON vt.tx_id = txh.tx_id' || ' JOIN tx_context as txc ON ex.txid = txc.txid' ||
' WHERE txh.tx_timestamp <= current_setting(''hsadminng.timestamp'')::timestamp' || ' WHERE txc.txtimestamp <= current_setting(''hsadminng.tx_history_timestamp'')::timestamp' ||
' GROUP BY id' || ' GROUP BY uuid' ||
' )' || ' )' ||
')', ')',
viewName, baseCols, versionsTable viewName, baseCols, exVersionsTable
); );
raise notice 'sql: %', createViewSQL; raise notice 'sql: %', createViewSQL;
execute createViewSQL; execute createViewSQL;
@ -186,58 +172,26 @@ call tx_create_historicization('hs_hosting_asset');
-- and expanded: -- 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; rollback;
begin transaction; begin transaction;
call defineContext('historization testing', null, 'superuser-alex@hostsharing.net', call defineContext('historization testing', null, 'superuser-alex@hostsharing.net',
-- 'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); -- prod+test 'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); -- prod+test
-- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); -- prod -- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); -- prod
'hs_booking_project#D-1000300-mimdefaultproject:ADMIN'); -- test -- '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='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 update hs_hosting_asset set caption='mim00 A ' || now()::text where identifier = 'mim00' and type = 'MANAGED_WEBSPACE'; -- test
update hs_hosting_asset set caption='mim00 B ' || now()::text where identifier = 'mim00' and type = 'MANAGED_WEBSPACE'; -- test
commit; 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 -- single version at point in time
set hsadminng.timestamp to '2024-08-27 04:15:00'; -- UTC -- set hsadminng.tx_history_timestamp to '2024-08-27 07:44:03'; -- UTC
set hsadminng.tx_history_timestamp to '2024-08-27 07:44:03'; -- UTC
select uuid, version, identifier, caption from hs_hosting_asset_hv p where identifier in ('lug00', 'mim00'); select uuid, version, identifier, caption from hs_hosting_asset_hv p where identifier in ('lug00', 'mim00');
-- all versions
select 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 ('lug00', 'mim00');

View File

@ -610,7 +610,7 @@ public abstract class BaseOfficeDataImport extends CsvDataImport {
deleteTestDataFromHsOfficeTables(); deleteTestDataFromHsOfficeTables();
resetHsOfficeSequences(); resetHsOfficeSequences();
deleteFromTestTables(); deleteFromTestTables();
deleteFromRbacTables(); deleteFromCommonTables();
jpaAttempt.transacted(() -> { jpaAttempt.transacted(() -> {
context(rbacSuperuser); context(rbacSuperuser);

View File

@ -249,6 +249,7 @@ public class CsvDataImport extends ContextBasedTest {
context(rbacSuperuser); context(rbacSuperuser);
// TODO.perf: could we instead skip creating test-data based on an env var? // TODO.perf: could we instead skip creating test-data based on an env var?
em.createNativeQuery("delete from hs_hosting_asset where true").executeUpdate(); em.createNativeQuery("delete from hs_hosting_asset where true").executeUpdate();
// FIXME em.createNativeQuery("delete from hs_hosting_asset_ex where true").executeUpdate();
em.createNativeQuery("delete from hs_booking_item where true").executeUpdate(); em.createNativeQuery("delete from hs_booking_item where true").executeUpdate();
em.createNativeQuery("delete from hs_booking_project where true").executeUpdate(); em.createNativeQuery("delete from hs_booking_project where true").executeUpdate();
em.createNativeQuery("delete from hs_office_coopassetstransaction where true").executeUpdate(); em.createNativeQuery("delete from hs_office_coopassetstransaction where true").executeUpdate();
@ -292,7 +293,7 @@ public class CsvDataImport extends ContextBasedTest {
}).assertSuccessful(); }).assertSuccessful();
} }
protected void deleteFromRbacTables() { protected void deleteFromCommonTables() {
jpaAttempt.transacted(() -> { jpaAttempt.transacted(() -> {
context(rbacSuperuser); context(rbacSuperuser);
em.createNativeQuery("delete from rbacuser_rv where name not like 'superuser-%'").executeUpdate(); em.createNativeQuery("delete from rbacuser_rv where name not like 'superuser-%'").executeUpdate();