use pg_current_xact_id() and xid8
This commit is contained in:
parent
8a32143d91
commit
0ae08b3714
@ -1,9 +1,9 @@
|
|||||||
rollback;
|
rollback;
|
||||||
drop table if exists hs_hosting_asset_versions;
|
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 view if exists hs_hosting_asset_hv;
|
||||||
|
drop table if exists hs_hosting_asset_ex;
|
||||||
drop procedure if exists tx_create_historicization;
|
drop procedure if exists tx_create_historicization;
|
||||||
drop view if exists tx_create_historical_view;
|
drop trigger if exists hs_hosting_asset_tx_historicize_tg on hs_hosting_asset;
|
||||||
drop function if exists tx_historicize_tf();
|
drop function if exists tx_historicize_tf();
|
||||||
drop type if exists tx_operation;
|
drop type if exists tx_operation;
|
||||||
|
|
||||||
@ -54,59 +54,13 @@ begin
|
|||||||
"alive" := false;
|
"alive" := false;
|
||||||
end if;
|
end if;
|
||||||
|
|
||||||
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, pg_current_xact_id(), %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";
|
||||||
|
|
||||||
return "row";
|
return "row";
|
||||||
end; $$;
|
end; $$;
|
||||||
|
|
||||||
create or replace procedure tx_create_historical_view(baseTable varchar)
|
|
||||||
language plpgsql as $$
|
|
||||||
declare
|
|
||||||
createTriggerSQL varchar;
|
|
||||||
viewName varchar;
|
|
||||||
exVersionsTable varchar;
|
|
||||||
createViewSQL varchar;
|
|
||||||
baseCols varchar;
|
|
||||||
begin
|
|
||||||
|
|
||||||
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' ||
|
|
||||||
'(' ||
|
|
||||||
' 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.txtimestamp <= current_setting(''hsadminng.tx_history_timestamp'')::timestamp' ||
|
|
||||||
' OR txc.txid = current_setting(''hsadminng.tx_history_txid'')' ||
|
|
||||||
' GROUP BY uuid' ||
|
|
||||||
' )' ||
|
|
||||||
')',
|
|
||||||
viewName, baseCols, exVersionsTable
|
|
||||||
);
|
|
||||||
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)
|
create or replace procedure tx_create_historicization(baseTable varchar)
|
||||||
language plpgsql as $$
|
language plpgsql as $$
|
||||||
declare
|
declare
|
||||||
@ -122,7 +76,7 @@ begin
|
|||||||
createHistTableSql = '' ||
|
createHistTableSql = '' ||
|
||||||
'CREATE TABLE ' || baseTable || '_ex (' ||
|
'CREATE TABLE ' || baseTable || '_ex (' ||
|
||||||
' version_id serial PRIMARY KEY,' ||
|
' version_id serial PRIMARY KEY,' ||
|
||||||
' txid bigint NOT NULL REFERENCES tx_context(txid),' ||
|
' txid xid8 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 ||
|
||||||
@ -151,7 +105,7 @@ begin
|
|||||||
' SELECT max(ex.version_id) AS history_id' ||
|
' SELECT max(ex.version_id) AS history_id' ||
|
||||||
' FROM %3$s AS ex' ||
|
' FROM %3$s AS ex' ||
|
||||||
' JOIN tx_context as txc ON ex.txid = txc.txid' ||
|
' JOIN tx_context as txc ON ex.txid = txc.txid' ||
|
||||||
' WHERE txc.txtimestamp <= current_setting(''hsadminng.tx_history_timestamp'')::timestamp' ||
|
' WHERE txc.txid = current_setting(''hsadminng.tx_history_txid'', true)::xid8' ||
|
||||||
' GROUP BY uuid' ||
|
' GROUP BY uuid' ||
|
||||||
' )' ||
|
' )' ||
|
||||||
')',
|
')',
|
||||||
@ -160,7 +114,7 @@ begin
|
|||||||
raise notice 'sql: %', createViewSQL;
|
raise notice 'sql: %', createViewSQL;
|
||||||
execute createViewSQL;
|
execute createViewSQL;
|
||||||
|
|
||||||
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_tx_historicize_tf' ||
|
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_tx_historicize_tg' ||
|
||||||
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
|
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
|
||||||
' FOR EACH ROW EXECUTE PROCEDURE tx_historicize_tf()';
|
' FOR EACH ROW EXECUTE PROCEDURE tx_historicize_tf()';
|
||||||
raise notice 'sql: %', createTriggerSQL;
|
raise notice 'sql: %', createTriggerSQL;
|
||||||
@ -170,12 +124,13 @@ end; $$;
|
|||||||
|
|
||||||
--- ==================================================
|
--- ==================================================
|
||||||
|
|
||||||
call tx_create_historicization('hs_hosting_asset');
|
call tx_create_historicization('hs_hosting_asset'); -- FIXME: move to 7010-hosting-asset.sql
|
||||||
|
|
||||||
-- and expanded:
|
-- and expanded:
|
||||||
|
|
||||||
-- ===========================================================================================
|
-- ===========================================================================================
|
||||||
|
|
||||||
|
|
||||||
rollback;
|
rollback;
|
||||||
begin transaction;
|
begin transaction;
|
||||||
call defineContext('historization testing', null, 'superuser-alex@hostsharing.net',
|
call defineContext('historization testing', null, 'superuser-alex@hostsharing.net',
|
||||||
@ -183,17 +138,19 @@ call defineContext('historization testing', null, 'superuser-alex@hostsharing.ne
|
|||||||
-- '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 A ' || now()::text where identifier = 'mim00' and type = 'MANAGED_WEBSPACE'; -- test
|
update hs_hosting_asset set caption='hsh00 E ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test
|
||||||
update hs_hosting_asset set caption='mim00 B ' || now()::text where identifier = 'mim00' and type = 'MANAGED_WEBSPACE'; -- test
|
update hs_hosting_asset set caption='hsh00 F ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test
|
||||||
commit;
|
commit;
|
||||||
|
|
||||||
-- single version at point in time
|
-- single version at point in time
|
||||||
-- set hsadminng.tx_history_timestamp to '2024-08-27 07:44:03'; -- UTC
|
-- 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_timestamp to '2024-08-27 07:44:03'; -- UTC
|
SELECT set_config('hsadminng.tx_history_txid', (select max(txid)::Text from tx_context where txtimestamp<='2024-08-27 12:13:13.450821'), FALSE);
|
||||||
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 ('hsh00');
|
||||||
|
|
||||||
|
select pg_current_xact_id();
|
||||||
|
|
||||||
-- all versions
|
-- all versions
|
||||||
select txc.txtimestamp, txc.currentUser, txc.currentTask, haex.*
|
select txc.txtimestamp, txc.currentUser, txc.currentTask, haex.*
|
||||||
from hs_hosting_asset_ex haex
|
from hs_hosting_asset_ex haex
|
||||||
join tx_context txc on haex.txid=txc.txid
|
join tx_context txc on haex.txid=txc.txid
|
||||||
where haex.identifier in ('lug00', 'mim00');
|
where haex.identifier in ('hsh00');
|
||||||
|
@ -26,7 +26,7 @@ create table tx_context
|
|||||||
-- FIXME: what whas the purpose of such a hash(task+txid)?
|
-- FIXME: what whas the purpose of such a hash(task+txid)?
|
||||||
-- contextId bigint primary key not null,
|
-- contextId bigint primary key not null,
|
||||||
-- txId bigint not null,
|
-- txId bigint not null,
|
||||||
txId bigint primary key not null,
|
txId xid8 primary key not null,
|
||||||
txTimestamp timestamp not null,
|
txTimestamp timestamp not null,
|
||||||
currentUser varchar(63) not null, -- not the uuid, because users can be deleted
|
currentUser varchar(63) not null, -- not the uuid, because users can be deleted
|
||||||
assumedRoles varchar(1023) not null, -- not the uuids, because roles can be deleted
|
assumedRoles varchar(1023) not null, -- not the uuids, because roles can be deleted
|
||||||
@ -46,7 +46,7 @@ create index on tx_context using brin (txTimestamp);
|
|||||||
create table tx_journal
|
create table tx_journal
|
||||||
(
|
(
|
||||||
-- contextId bigint not null references tx_context (contextId), -- FIXME: this ...
|
-- contextId bigint not null references tx_context (contextId), -- FIXME: this ...
|
||||||
txId bigint not null references tx_context (txId), -- FIXME: ... or that?
|
txId xid8 not null references tx_context (txId), -- FIXME: ... or that?
|
||||||
targetTable text not null,
|
targetTable text not null,
|
||||||
targetUuid uuid not null, -- Assumes that all audited tables have a uuid column.
|
targetUuid uuid not null, -- Assumes that all audited tables have a uuid column.
|
||||||
targetOp operation not null,
|
targetOp operation not null,
|
||||||
@ -81,16 +81,16 @@ create or replace function tx_journal_trigger()
|
|||||||
declare
|
declare
|
||||||
curTask text;
|
curTask text;
|
||||||
-- curContextId bigint; FIXME: needed?
|
-- curContextId bigint; FIXME: needed?
|
||||||
curTxId bigint;
|
curTxId xid8;
|
||||||
begin
|
begin
|
||||||
curTask := currentTask();
|
curTask := currentTask();
|
||||||
-- curContextId := txid_current()+bigIntHash(curTask); FIXME: needed?
|
-- curContextId := pg_current_xact_id()+bigIntHash(curTask); FIXME: needed?
|
||||||
curTxId := txid_current();
|
curTxId := pg_current_xact_id();
|
||||||
|
|
||||||
insert
|
insert
|
||||||
-- FIXME
|
-- FIXME
|
||||||
-- into tx_context (contextId, txId, txTimestamp, currentUser, assumedRoles, currentTask, currentRequest)
|
-- into tx_context (contextId, txId, txTimestamp, currentUser, assumedRoles, currentTask, currentRequest)
|
||||||
-- values (curContextId, txid_current(), now(),
|
-- values (curContextId, pg_current_xact_id(), now(),
|
||||||
-- currentUser(), assumedRoles(), curTask, currentRequest())
|
-- currentUser(), assumedRoles(), curTask, currentRequest())
|
||||||
into tx_context (txId, txTimestamp, currentUser, assumedRoles, currentTask, currentRequest)
|
into tx_context (txId, txTimestamp, currentUser, assumedRoles, currentTask, currentRequest)
|
||||||
values ( curTxId, now(),
|
values ( curTxId, now(),
|
||||||
|
Loading…
Reference in New Issue
Block a user