From 2f198664fa4f0c4f33691886427850f257aa7ee3 Mon Sep 17 00:00:00 2001 From: Michael Hoennig Date: Tue, 27 Aug 2024 20:03:03 +0200 Subject: [PATCH] extract tx_history_txid() into a CTE-query --- sql/historization.sql | 50 ++++++++++++++++++++++++++++++++----------- 1 file changed, 38 insertions(+), 12 deletions(-) diff --git a/sql/historization.sql b/sql/historization.sql index af902a17..37c266e1 100644 --- a/sql/historization.sql +++ b/sql/historization.sql @@ -15,6 +15,30 @@ drop type if exists tx_operation; create type "tx_operation" as enum ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE'); + +create or replace function tx_history_txid() + returns xid8 stable + language plpgsql as $$ +declare + historicalTxIdSetting text; + historicalTxId xid8; + historicalTimestamp timestamp; +begin + select current_setting('hsadminng.tx_history_txid', true) into historicalTxIdSetting; + raise notice 'tx_history_txid(): historicalTxIdSetting=%', historicalTxIdSetting; + if historicalTxIdSetting is null or historicalTxIdSetting = '' then + select current_setting('hsadminng.tx_history_timestamp', true)::timestamp into historicalTimestamp; + raise notice 'tx_history_txid(): historicalTimestamp=%', historicalTimestamp; + select max(txc.txid) from tx_context txc where txc.txtimestamp <= historicalTimestamp into historicalTxId; + raise notice 'tx_history_txid(): historicalTxId=%', historicalTxId; + else + historicalTxId = historicalTxIdSetting::xid8; + end if; + return historicalTxId; +end; $$; + + + create or replace function tx_historicize_tf() returns trigger language plpgsql @@ -97,6 +121,8 @@ begin createViewSQL = format( 'CREATE OR REPLACE VIEW %1$s AS' || '(' || + -- make sure the function is only called once, not for every matching row in tx_context + ' WITH txh AS (SELECT tx_history_txid() AS txid) ' || ' SELECT %2$s' || ' FROM %3$s' || ' WHERE alive = TRUE' || @@ -105,7 +131,7 @@ begin ' 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.txid = current_setting(''hsadminng.tx_history_txid'', true)::xid8' || + ' WHERE txc.txid <= (SELECT txid FROM txh)' || ' GROUP BY uuid' || ' )' || ')', @@ -126,8 +152,6 @@ end; $$; call tx_create_historicization('hs_hosting_asset'); -- FIXME: move to 7010-hosting-asset.sql --- and expanded: - -- =========================================================================================== @@ -138,19 +162,21 @@ call defineContext('historization testing', null, 'superuser-alex@hostsharing.ne -- '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='hsh00 E ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test -update hs_hosting_asset set caption='hsh00 F ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test +update hs_hosting_asset set caption='hsh00 C ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test +update hs_hosting_asset set caption='hsh00 D ' || now()::text where identifier = 'hsh00' and type = 'MANAGED_WEBSPACE'; -- test commit; -- single version at point in time -- set hsadminng.tx_history_txid to (select max(txid) from tx_context where txtimestamp<='2024-08-27 12:13:13.450821'); -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 ('hsh00'); +set hsadminng.tx_history_txid to '3249'; +--set hsadminng.tx_history_timestamp to '2024-08-27 17:52:07.755407'; +-- all versions +select tx_history_txid(), 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 ('hsh00', 'mim00'); + +select uuid, version, identifier, caption from hs_hosting_asset_hv p where identifier in ('hsh00', 'mim00'); select pg_current_xact_id(); --- 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 ('hsh00');