1
0

initial audit-log implementation

This commit is contained in:
Michael Hoennig
2022-08-24 12:01:54 +02:00
parent cb641eb8c6
commit e880a1c2c8
5 changed files with 122 additions and 5 deletions

View File

@ -0,0 +1,98 @@
--liquibase formatted sql
-- ============================================================================
--changeset audit-OPERATION-TYPE:1 endDelimiter:--//
-- ----------------------------------------------------------------------------
/*
A type representing a DML operation.
*/
do $$
begin
if not exists(select 1 from pg_type where typname = 'operation') then
create type "operation" as enum ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE');
end if;
--more types here...
end $$;
--//
-- ============================================================================
--changeset audit-TABLE-TX-AUDIT-LOG:1 endDelimiter:--//
-- ----------------------------------------------------------------------------
/*
A table storing the transaction audit log for all target tables.
*/
create table "tx_audit_log"
(
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
);
create index on tx_audit_log using brin (txTimestamp);
create index on tx_audit_log (targetTable, targetUuid);
--//
-- ============================================================================
--changeset audit-TX-AUDIT-TRIGGER:1 endDelimiter:--//
-- ----------------------------------------------------------------------------
/*
Trigger function for transaction audit log.
*/
create or replace function tx_audit_log_trigger()
returns trigger
language plpgsql as $$
begin
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;
return null;
end; $$;
--//
-- ============================================================================
--changeset audit-CREATE-AUDIT-LOG:1 endDelimiter:--//
-- ----------------------------------------------------------------------------
/*
Trigger function for transaction audit log.
*/
create or replace procedure create_audit_log(targetTable varchar)
language plpgsql as $$
declare
createTriggerSQL varchar;
begin
createTriggerSQL = 'CREATE TRIGGER ' || targetTable || '_audit_log' ||
' AFTER INSERT OR UPDATE OR DELETE ON ' || targetTable ||
' FOR EACH ROW EXECUTE PROCEDURE tx_audit_log_trigger()';
raise notice 'sql: %', createTriggerSQL;
execute createTriggerSQL;
end; $$;
--//

View File

@ -26,7 +26,6 @@ begin
end if;
return expectedType;
end; $$;
--//
-- ============================================================================
@ -41,6 +40,8 @@ create table RbacUser
name varchar(63) not null unique
);
call create_audit_log('RbacUser');
create or replace function createRbacUser(userName varchar)
returns uuid
returns null on null input
@ -119,6 +120,8 @@ create table RbacObject
unique (objectTable, uuid)
);
call create_audit_log('RbacObject');
create or replace function createRbacObject()
returns trigger
language plpgsql
@ -144,8 +147,6 @@ begin
raise exception 'invalid usage of TRIGGER AFTER INSERT';
end if;
end; $$;
--//
-- ============================================================================
@ -165,6 +166,8 @@ create table RbacRole
unique (objectUuid, roleType)
);
call create_audit_log('RbacRole');
create type RbacRoleDescriptor as
(
objectTable varchar(63), -- TODO: needed? remove?
@ -284,6 +287,8 @@ create table RbacPermission
unique (objectUuid, op)
);
call create_audit_log('RbacPermission');
create or replace function permissionExists(forObjectUuid uuid, forOp RbacOp)
returns bool
language sql as $$
@ -353,15 +358,17 @@ $$;
*/
create table RbacGrants
(
uuid uuid primary key default uuid_generate_v4(),
grantedByRoleUuid uuid references RbacRole (uuid) on delete cascade,
ascendantUuid uuid references RbacReference (uuid) on delete cascade,
descendantUuid uuid references RbacReference (uuid) on delete cascade,
assumed boolean not null default true, -- auto assumed (true) vs. needs assumeRoles (false)
primary key (ascendantUuid, descendantUuid)
unique (ascendantUuid, descendantUuid)
);
create index on RbacGrants (ascendantUuid);
create index on RbacGrants (descendantUuid);
call create_audit_log('RbacGrants');
create or replace function findGrantees(grantedId uuid)
returns setof RbacReference

View File

@ -11,6 +11,8 @@ databaseChangeLog:
file: db/changelog/005-uuid-ossp-extension.sql
- include:
file: db/changelog/010-context.sql
- include:
file: db/changelog/020-audit-log.sql
- include:
file: db/changelog/050-rbac-base.sql
- include: