From 258f8b1f66e001522966abdbf39e8d1c6e316f12 Mon Sep 17 00:00:00 2001 From: Michael Hoennig Date: Wed, 24 Aug 2022 12:52:28 +0200 Subject: [PATCH] split tx_audit_log into tx_context and tx_journal --- .../rbac/rbacuser/RbacUserController.java | 3 - .../resources/db/changelog/020-audit-log.sql | 107 ++++++++++-------- .../resources/db/changelog/050-rbac-base.sql | 10 +- 3 files changed, 65 insertions(+), 55 deletions(-) diff --git a/src/main/java/net/hostsharing/hsadminng/rbac/rbacuser/RbacUserController.java b/src/main/java/net/hostsharing/hsadminng/rbac/rbacuser/RbacUserController.java index ce268d6a..9165f59c 100644 --- a/src/main/java/net/hostsharing/hsadminng/rbac/rbacuser/RbacUserController.java +++ b/src/main/java/net/hostsharing/hsadminng/rbac/rbacuser/RbacUserController.java @@ -23,9 +23,6 @@ public class RbacUserController implements RbacusersApi { @Autowired private Context context; - @Autowired - private EntityManager em; - @Autowired private RbacUserRepository rbacUserRepository; diff --git a/src/main/resources/db/changelog/020-audit-log.sql b/src/main/resources/db/changelog/020-audit-log.sql index eb38d6bb..f3a129d0 100644 --- a/src/main/resources/db/changelog/020-audit-log.sql +++ b/src/main/resources/db/changelog/020-audit-log.sql @@ -16,82 +16,95 @@ do $$ --// -- ============================================================================ ---changeset audit-TABLE-TX-AUDIT-LOG:1 endDelimiter:--// +--changeset audit-TX-CONTEXT-TABLE:1 endDelimiter:--// -- ---------------------------------------------------------------------------- /* - A table storing the transaction audit log for all target tables. + A table storing transactions with context data. */ -create table "tx_audit_log" +create table tx_context ( - txId bigint not null, - txTimestamp timestamp not null, - currentUser varchar(63) not null, -- TODO.SPEC: Keep user name or uuid in audit-log? - assumedRoles varchar not null, -- TODO.SPEC: Store role names or uuids in audit-log? - currentTask varchar not null, - targetTable text not null, - targetUuid uuid not null, -- TODO.SPEC: All audited tables have a uuid column. - targetOp operation not null, - targetDelta jsonb + txId bigint primary key not null, + txTimestamp timestamp not null, + currentUser varchar(63) not null, -- not the uuid, because users can be deleted + assumedRoles varchar not null, -- not the uuids, because roles can be deleted + currentTask varchar not null ); -create index on tx_audit_log using brin (txTimestamp); -create index on tx_audit_log (targetTable, targetUuid); +create index on tx_context using brin (txTimestamp); --// -- ============================================================================ ---changeset audit-TX-AUDIT-TRIGGER:1 endDelimiter:--// +--changeset audit-TX-JOURNAL-TABLE:1 endDelimiter:--// -- ---------------------------------------------------------------------------- /* - Trigger function for transaction audit log. + A table storing the transaction audit journal for all target tables it's configured for. */ -create or replace function tx_audit_log_trigger() +create table tx_journal +( + txId bigint not null references tx_context (txId), + targetTable text not null, + targetUuid uuid not null, -- Assumes that all audited tables have a uuid column. + targetOp operation not null, + targetDelta jsonb +); + +create index on tx_journal (targetTable, targetUuid); +--// + +-- ============================================================================ +--changeset audit-TX-JOURNAL-TRIGGER:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- +/* + Trigger function for transaction audit journal. + */ +create or replace function tx_journal_trigger() returns trigger language plpgsql as $$ begin + + insert + into tx_context + values (txid_current(), now(), + currentUser(), assumedRoles(), currentTask()) + on conflict do nothing; + case tg_op - when 'INSERT' then - insert - into tx_audit_log - values (txid_current(), now(), - currentUser(), assumedRoles(), currentTask(), - tg_table_name, new.uuid, tg_op::operation, - to_jsonb(new)); - when 'UPDATE' then - insert - into tx_audit_log - values (txid_current(), now(), - currentUser(), assumedRoles(), currentTask(), - tg_table_name, old.uuid, tg_op::operation, - jsonb_changes_delta(to_jsonb(old), to_jsonb(new))); - when 'DELETE' then - insert - into tx_audit_log - values (txid_current(), now(), - currentUser(), assumedRoles(), currentTask(), - tg_table_name, old.uuid, 'DELETE'::operation, - null::jsonb); - else - raise exception 'Trigger op % not supported for %.', tg_op, tg_table_name; - end case; + when 'INSERT' then insert + into tx_journal + values (txid_current(), + tg_table_name, new.uuid, tg_op::operation, + to_jsonb(new)); + when 'UPDATE' then insert + into tx_journal + values (txid_current(), + tg_table_name, old.uuid, tg_op::operation, + jsonb_changes_delta(to_jsonb(old), to_jsonb(new))); + when 'DELETE' then insert + into tx_journal + values (txid_current(), + tg_table_name, old.uuid, 'DELETE'::operation, + null::jsonb); + else raise exception 'Trigger op % not supported for %.', tg_op, tg_table_name; + end case; return null; end; $$; --// -- ============================================================================ ---changeset audit-CREATE-AUDIT-LOG:1 endDelimiter:--// +--changeset audit-CREATE-JOURNAL-LOG:1 endDelimiter:--// -- ---------------------------------------------------------------------------- /* - Trigger function for transaction audit log. + Trigger function for transaction audit journal. */ -create or replace procedure create_audit_log(targetTable varchar) +create or replace procedure create_journal(targetTable varchar) language plpgsql as $$ declare - createTriggerSQL varchar; + createTriggerSQL varchar; begin - createTriggerSQL = 'CREATE TRIGGER ' || targetTable || '_audit_log' || + createTriggerSQL = 'CREATE TRIGGER ' || targetTable || '_journal' || ' AFTER INSERT OR UPDATE OR DELETE ON ' || targetTable || - ' FOR EACH ROW EXECUTE PROCEDURE tx_audit_log_trigger()'; + ' FOR EACH ROW EXECUTE PROCEDURE tx_journal_trigger()'; raise notice 'sql: %', createTriggerSQL; execute createTriggerSQL; end; $$; diff --git a/src/main/resources/db/changelog/050-rbac-base.sql b/src/main/resources/db/changelog/050-rbac-base.sql index ac082b59..ddbdb596 100644 --- a/src/main/resources/db/changelog/050-rbac-base.sql +++ b/src/main/resources/db/changelog/050-rbac-base.sql @@ -40,7 +40,7 @@ create table RbacUser name varchar(63) not null unique ); -call create_audit_log('RbacUser'); +call create_journal('RbacUser'); create or replace function createRbacUser(userName varchar) returns uuid @@ -120,7 +120,7 @@ create table RbacObject unique (objectTable, uuid) ); -call create_audit_log('RbacObject'); +call create_journal('RbacObject'); create or replace function createRbacObject() returns trigger @@ -166,7 +166,7 @@ create table RbacRole unique (objectUuid, roleType) ); -call create_audit_log('RbacRole'); +call create_journal('RbacRole'); create type RbacRoleDescriptor as ( @@ -287,7 +287,7 @@ create table RbacPermission unique (objectUuid, op) ); -call create_audit_log('RbacPermission'); +call create_journal('RbacPermission'); create or replace function permissionExists(forObjectUuid uuid, forOp RbacOp) returns bool @@ -368,7 +368,7 @@ create table RbacGrants create index on RbacGrants (ascendantUuid); create index on RbacGrants (descendantUuid); -call create_audit_log('RbacGrants'); +call create_journal('RbacGrants'); create or replace function findGrantees(grantedId uuid) returns setof RbacReference