diff --git a/schema/000_audit_and_soft_delete.sql b/schema/000_audit_and_soft_delete.sql new file mode 100644 index 0000000..b0db63a --- /dev/null +++ b/schema/000_audit_and_soft_delete.sql @@ -0,0 +1,134 @@ +create type audited_column as (column_ text, type_ text); + +create function setup_audit_and_soft_delete( schema text + , table_ text + , tracked_columns audited_column[] + ) + returns void + language plpgsql as $$ + declare + col audited_column; + audit_table text := concat(schema, '.', table_, '_audit'); + do_table_audit text := concat(schema, '.do_', table_, '_audit'); + do_table_soft_delete text := concat(schema, '.do_', table_, '_soft_delete'); + create_audit_table text := ''; + create_do_table_audit text := ''; + create_do_table_soft_delete text := ''; + create_trigger_table_audit text := ''; + create_trigger_table_soft_delete text := ''; + begin + -- create table X_audit() >>> + create_audit_table := concat( create_audit_table + , 'create table ', audit_table, E'\n' + , ' ( ', table_, ' int not null references ', table_, '(id)', E'\n' + , ' , kind public.audit_kind not null', E'\n' + , ' , actor int not null references public.usr (id)', E'\n' + ); + + foreach col in array tracked_columns loop + create_audit_table := concat( create_audit_table + , E' , prev_', (col.column_), ' ', (col.type_), E' null\n' + ); + end loop; + + create_audit_table := concat( create_audit_table + , ' );' + ); + -- <<< create table X_audit() + + -- create function do_X_soft_delete() >>> + create_do_table_soft_delete := concat( create_do_table_soft_delete + , 'create function ', do_table_soft_delete, E'() returns trigger language plpgsql as \$\$\n' + , E'begin\n' + , E' insert into ', audit_table, E'\n' + , E' (', table_, E', kind, actor)\n' + , E' values\n' + , E' (OLD.id, \'delete\', 1);\n' + , E'\n' + , E' update ', schema, '.', table_, E'\n' + , E' set deleted = true\n' + , E' where id = OLD.id;\n' + , E'\n' + , E' return null;\n' + , E'end;\n' + , E'\$\$;' + ); + -- <<< create function do_X_soft_delete() + + -- create function do_X_audit() >>> + create_do_table_audit := concat( create_do_table_audit + , 'create function ', do_table_audit, E'() returns trigger language plpgsql as \$\$\n' + , E'declare\n' + , E' audit_kind public.audit_kind;\n' + , E' id int;\n' + ); + + foreach col in array tracked_columns loop + create_do_table_audit := concat( create_do_table_audit + , 'prev_', (col.column_), ' ', (col.type_), E';\n' + ); + end loop; + + create_do_table_audit := concat( create_do_table_audit + , E'begin\n' + , E' if (TG_OP = \'INSERT\') then\n' + , E' id := NEW.id;\n' + , E' audit_kind := \'create\';\n' + , E' elsif (TG_OP = \'UPDATE\') then\n' + , E' id := OLD.id;\n' + , E' audit_kind := \'modify\';\n' + ); + + foreach col in array tracked_columns loop + create_do_table_audit := concat( create_do_table_audit + , ' prev_', (col.column_), ' := OLD.', (col.column_), E';\n' + ); + end loop; + + create_do_table_audit := concat( create_do_table_audit + , E' end if;\n' + , E' insert into public.usr_audit\n' + , E' (kind, usr, actor' + ); + + foreach col in array tracked_columns loop + create_do_table_audit := concat( create_do_table_audit + , ', prev_', (col.column_) + ); + end loop; + + create_do_table_audit := concat( create_do_table_audit + , E' )\n' + , E' values\n' + , E' (audit_kind, id, 1' + ); + + foreach col in array tracked_columns loop + create_do_table_audit := concat( create_do_table_audit + , ', prev_', (col.column_) + ); + end loop; + + create_do_table_audit := concat( create_do_table_audit + , E');\n' + , E' return NEW;\n' + , E'end;\n' + , E'\$\$;' + ); + -- <<< create function do_X_audit() + + create_trigger_table_audit := concat( 'create trigger trigger_', table_, E'_audit\n' + , 'after insert or update on ', schema, '.', table_, E'\n' + , 'for each row execute function ', do_table_audit, '();' + ); + create_trigger_table_soft_delete := concat( 'create trigger trigger_', table_, E'_soft_delete\n' + , 'before delete on ', schema, '.', table_, E'\n' + , 'for each row execute function ', do_table_soft_delete, '();' + ); + execute create_audit_table; + execute create_do_table_audit; + execute create_do_table_soft_delete; + execute create_trigger_table_audit; + execute create_trigger_table_soft_delete; + end; +$$; diff --git a/schema/020_user.sql b/schema/020_user.sql index b07eade..fd1b8df 100644 --- a/schema/020_user.sql +++ b/schema/020_user.sql @@ -1,87 +1,18 @@ select create_newtype_text('public.usr_username'); -create table public.usr_audit - ( usr int not null - , kind public.audit_kind not null - , actor int not null - , prev_username public.usr_username null - , prev_password public.hashed_text null - , prev_email public.email null - ); - create table public.usr ( id int not null primary key generated always as identity , uid uuid not null default gen_random_uuid() , deleted boolean not null default false - , username public.usr_username not null unique + , username public.usr_username not null , password public.hashed_text not null , email public.email not null unique ); -alter table public.usr_audit - add constraint fk_usr_audit_usr - foreign key (usr) - references public.usr (id) -, add constraint fk_usr_audit_actor - foreign key (actor) - references public.usr (id) -; - -create function public.do_usr_audit() - returns trigger - language plpgsql as $$ - declare - audit_kind public.audit_kind; - usr_id int; - prev_username public.usr_username := null; - prev_password public.hashed_text := null; - prev_email public.email := null; - begin - if (TG_OP = 'UPDATE') then - usr_id := OLD.id; - audit_kind := 'modify'; - prev_username := OLD.username; - prev_password := OLD.password; - prev_email := OLD.email; - elsif (TG_OP = 'INSERT') then - usr_id := NEW.id; - audit_kind := 'create'; - end if; - - insert into public.usr_audit - (kind, usr, actor, prev_username, prev_email, prev_password ) - values - -- TODO actor - (audit_kind, usr_id, usr_id, prev_username, prev_email, prev_password ); - - return NEW; - end; -$$; - -create function public.do_usr_soft_delete() - returns trigger - language plpgsql as $$ - declare - audit_id int; - begin - insert into public.usr_audit - (kind, usr, actor) - values - -- TODO actor - ('delete' :: public.audit_kind, OLD.id, OLD.id); - - update public.usr - set deleted = true - where id = OLD.id; - - return null; - end; -$$; - -create trigger trigger_usr_audit - after insert or update on public.usr - for each row execute function public.do_usr_audit(); - -create trigger trigger_usr_soft_delete - before delete on public.usr - for each row execute function public.do_usr_soft_delete(); +select setup_audit_and_soft_delete( 'public' + , 'usr' + , array[ row('username', 'public.usr_username') + , row('password', 'public.hashed_text') + , row('email', 'public.email') + ] :: audited_column[] + );