db/2cf11bc_to_65b6f0f.sql
2023-07-18 21:32:10 -05:00

548 lines
18 KiB
PL/PgSQL

alter table "public"."community_audit" drop column "prev_role_nonmember";
alter table "public"."community_member" add column "community" integer not null;
alter table "public"."community_member_role" add column "community" integer not null;
alter table "public"."community_member" add constraint "community_member_community_fkey" FOREIGN KEY (community) REFERENCES community(id) not valid;
alter table "public"."community_member" validate constraint "community_member_community_fkey";
alter table "public"."community_member_role" add constraint "community_member_role_community_fkey" FOREIGN KEY (community) REFERENCES community(id) not valid;
alter table "public"."community_member_role" validate constraint "community_member_role_community_fkey";
set check_function_bodies = off;
CREATE OR REPLACE FUNCTION public.do_community_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_tag public.community_tag;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
prev_tag := OLD.tag;
end if;
insert into public.community_audit
(kind, community, actor, prev_tag )
values
(audit_kind, id, 1, prev_tag);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_community_member_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_usr int;
prev_role_ int;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'DELETE') then
id := OLD.id;
audit_kind := 'delete';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
prev_usr := OLD.usr;
prev_role_ := OLD.role_;
end if;
insert into public.community_member_audit
(kind, community_member, actor, prev_usr, prev_role_ )
values
(audit_kind, id, 1, prev_usr, prev_role_);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_community_member_role_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_title text;
prev_description text;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'DELETE') then
id := OLD.id;
audit_kind := 'delete';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
prev_title := OLD.title;
prev_description := OLD.description;
end if;
insert into public.community_member_role_audit
(kind, community_member_role, actor, prev_title, prev_description )
values
(audit_kind, id, 1, prev_title, prev_description);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_community_member_role_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.community_member_role.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.community_member_role.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.community <> NEW.community then
raise exception 'public.community_member_role.community is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_community_member_role_scope_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_role_ int;
prev_scope public.authz_scope;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'DELETE') then
id := OLD.id;
audit_kind := 'delete';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
prev_role_ := OLD.role_;
prev_scope := OLD.scope;
end if;
insert into public.community_member_role_scope_audit
(kind, community_member_role_scope, actor, prev_role_, prev_scope )
values
(audit_kind, id, 1, prev_role_, prev_scope);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_community_nonmember_scope_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_community int;
prev_scope public.authz_scope;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'DELETE') then
id := OLD.id;
audit_kind := 'delete';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
prev_community := OLD.community;
prev_scope := OLD.scope;
end if;
insert into public.community_nonmember_scope_audit
(kind, community_nonmember_scope, actor, prev_community, prev_scope )
values
(audit_kind, id, 1, prev_community, prev_scope);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
end if;
insert into public.thread_attachment_audit
(kind, thread_attachment, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_emoji_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
end if;
insert into public.thread_attachment_emoji_audit
(kind, thread_attachment_emoji, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_vote_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
end if;
insert into public.thread_attachment_vote_audit
(kind, thread_attachment_vote, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
end if;
insert into public.thread_audit
(kind, thread, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_feed_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
begin
if (TG_OP = 'INSERT') then
id := NEW.id;
audit_kind := 'create';
elsif (TG_OP = 'UPDATE') then
id := OLD.id;
audit_kind := 'modify';
end if;
insert into public.thread_feed_audit
(kind, thread_feed, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.setup_audit_and_hard_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_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 = \'DELETE\') then\n'
, E' id := OLD.id;\n'
, E' audit_kind := \'delete\';\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 ', audit_table, E'\n'
, ' (kind, ', table_, ', 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 or delete on ', schema, '.', table_, E'\n'
, 'for each row execute function ', do_table_audit, '();'
);
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.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 ', audit_table, E'\n'
, ' (kind, ', table_, ', 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$
;