db/49bed63_to_7a4d728.sql
2023-07-17 14:14:01 -04:00

203 lines
7.8 KiB
PL/PgSQL

alter table "public"."usr" drop constraint "usr_username_key";
alter table "public"."usr_audit" drop constraint "fk_usr_audit_actor";
alter table "public"."usr_audit" drop constraint "fk_usr_audit_usr";
drop index if exists "public"."usr_username_key";
alter table "public"."usr_audit" add constraint "usr_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."usr_audit" validate constraint "usr_audit_actor_fkey";
alter table "public"."usr_audit" add constraint "usr_audit_usr_fkey" FOREIGN KEY (usr) REFERENCES usr(id) not valid;
alter table "public"."usr_audit" validate constraint "usr_audit_usr_fkey";
set check_function_bodies = off;
create type "public"."audited_column" as ("column_" text, "type_" text);
CREATE OR REPLACE FUNCTION public.setup_audit_and_soft_delete(schema text, table_ text, tracked_columns audited_column[])
RETURNS void
LANGUAGE plpgsql
AS $function$
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;
$function$
;
CREATE OR REPLACE FUNCTION public.do_usr_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_username public.usr_username;
prev_password public.hashed_text;
prev_email public.email;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
prev_username := OLD.username;
prev_password := OLD.password;
prev_email := OLD.email;
end if;
insert into public.usr_audit
(kind, usr, actor, prev_username, prev_password, prev_email )
values
(audit_kind, id, 1, prev_username, prev_password, prev_email);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_usr_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.usr_audit
(usr, kind, actor)
values
(OLD.id, 'delete', 1);
update public.usr
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;