drop function if exists "public"."mark_columns_immutable"(schema text, table_ text, columns text[]); drop type "public"."usr_username"; drop function if exists "public"."usr_username_of_string"(val text); drop function if exists "public"."usr_username_to_string"(val usr_username); create table "public"."community" ( "id" integer generated always as identity not null, "uid" uuid not null default gen_random_uuid(), "deleted" boolean not null default false, "tag" community_tag not null ); create table "public"."community_audit" ( "community" integer not null, "kind" audit_kind not null, "actor" integer not null, "prev_tag" community_tag, "prev_role_nonmember" integer ); create table "public"."community_member" ( "id" integer generated always as identity not null, "uid" uuid not null default gen_random_uuid(), "usr" integer not null, "role_" integer not null ); create table "public"."community_member_audit" ( "community_member" integer not null, "kind" audit_kind not null, "actor" integer not null, "prev_usr" integer, "prev_role_" integer ); create table "public"."community_member_role" ( "id" integer generated always as identity not null, "uid" uuid not null default gen_random_uuid(), "title" text not null, "description" text not null ); create table "public"."community_member_role_audit" ( "community_member_role" integer not null, "kind" audit_kind not null, "actor" integer not null, "prev_title" text, "prev_description" text ); create table "public"."community_member_role_scope" ( "id" integer generated always as identity not null, "uid" uuid not null default gen_random_uuid(), "role_" integer not null, "scope" authz_scope not null ); create table "public"."community_member_role_scope_audit" ( "community_member_role_scope" integer not null, "kind" audit_kind not null, "actor" integer not null, "prev_role_" integer, "prev_scope" authz_scope ); create table "public"."community_nonmember_scope" ( "id" integer generated always as identity not null, "uid" uuid not null default gen_random_uuid(), "community" integer not null, "scope" authz_scope not null ); create table "public"."community_nonmember_scope_audit" ( "community_nonmember_scope" integer not null, "kind" audit_kind not null, "actor" integer not null, "prev_community" integer, "prev_scope" authz_scope ); alter table "public"."usr" drop column "username"; alter table "public"."usr" add column "tag" usr_tag not null; alter table "public"."usr_audit" drop column "prev_username"; alter table "public"."usr_audit" add column "prev_tag" usr_tag; CREATE UNIQUE INDEX community_member_pkey ON public.community_member USING btree (id); CREATE UNIQUE INDEX community_member_role_pkey ON public.community_member_role USING btree (id); CREATE UNIQUE INDEX community_member_role_scope_pkey ON public.community_member_role_scope USING btree (id); CREATE UNIQUE INDEX community_member_role_scope_scope_role__key ON public.community_member_role_scope USING btree (scope, role_); CREATE UNIQUE INDEX community_member_role_scope_uid_key ON public.community_member_role_scope USING btree (uid); CREATE UNIQUE INDEX community_member_role_uid_key ON public.community_member_role USING btree (uid); CREATE UNIQUE INDEX community_member_uid_key ON public.community_member USING btree (uid); CREATE UNIQUE INDEX community_nonmember_scope_community_scope_key ON public.community_nonmember_scope USING btree (community, scope); CREATE UNIQUE INDEX community_nonmember_scope_pkey ON public.community_nonmember_scope USING btree (id); CREATE UNIQUE INDEX community_nonmember_scope_uid_key ON public.community_nonmember_scope USING btree (uid); CREATE UNIQUE INDEX community_pkey ON public.community USING btree (id); CREATE UNIQUE INDEX community_uid_key ON public.community USING btree (uid); alter table "public"."community" add constraint "community_pkey" PRIMARY KEY using index "community_pkey"; alter table "public"."community_member" add constraint "community_member_pkey" PRIMARY KEY using index "community_member_pkey"; alter table "public"."community_member_role" add constraint "community_member_role_pkey" PRIMARY KEY using index "community_member_role_pkey"; alter table "public"."community_member_role_scope" add constraint "community_member_role_scope_pkey" PRIMARY KEY using index "community_member_role_scope_pkey"; alter table "public"."community_nonmember_scope" add constraint "community_nonmember_scope_pkey" PRIMARY KEY using index "community_nonmember_scope_pkey"; alter table "public"."community" add constraint "community_uid_key" UNIQUE using index "community_uid_key"; alter table "public"."community_audit" add constraint "community_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid; alter table "public"."community_audit" validate constraint "community_audit_actor_fkey"; alter table "public"."community_audit" add constraint "community_audit_community_fkey" FOREIGN KEY (community) REFERENCES community(id) not valid; alter table "public"."community_audit" validate constraint "community_audit_community_fkey"; alter table "public"."community_member" add constraint "community_member_role__fkey" FOREIGN KEY (role_) REFERENCES community_member_role(id) not valid; alter table "public"."community_member" validate constraint "community_member_role__fkey"; alter table "public"."community_member" add constraint "community_member_uid_key" UNIQUE using index "community_member_uid_key"; alter table "public"."community_member" add constraint "community_member_usr_fkey" FOREIGN KEY (usr) REFERENCES usr(id) not valid; alter table "public"."community_member" validate constraint "community_member_usr_fkey"; alter table "public"."community_member_audit" add constraint "community_member_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid; alter table "public"."community_member_audit" validate constraint "community_member_audit_actor_fkey"; alter table "public"."community_member_audit" add constraint "community_member_audit_community_member_fkey" FOREIGN KEY (community_member) REFERENCES community_member(id) not valid; alter table "public"."community_member_audit" validate constraint "community_member_audit_community_member_fkey"; alter table "public"."community_member_role" add constraint "community_member_role_uid_key" UNIQUE using index "community_member_role_uid_key"; alter table "public"."community_member_role_audit" add constraint "community_member_role_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid; alter table "public"."community_member_role_audit" validate constraint "community_member_role_audit_actor_fkey"; alter table "public"."community_member_role_audit" add constraint "community_member_role_audit_community_member_role_fkey" FOREIGN KEY (community_member_role) REFERENCES community_member_role(id) not valid; alter table "public"."community_member_role_audit" validate constraint "community_member_role_audit_community_member_role_fkey"; alter table "public"."community_member_role_scope" add constraint "community_member_role_scope_role__fkey" FOREIGN KEY (role_) REFERENCES community_member_role(id) not valid; alter table "public"."community_member_role_scope" validate constraint "community_member_role_scope_role__fkey"; alter table "public"."community_member_role_scope" add constraint "community_member_role_scope_scope_role__key" UNIQUE using index "community_member_role_scope_scope_role__key"; alter table "public"."community_member_role_scope" add constraint "community_member_role_scope_uid_key" UNIQUE using index "community_member_role_scope_uid_key"; alter table "public"."community_member_role_scope_audit" add constraint "community_member_role_scope_au_community_member_role_scope_fkey" FOREIGN KEY (community_member_role_scope) REFERENCES community_member_role_scope(id) not valid; alter table "public"."community_member_role_scope_audit" validate constraint "community_member_role_scope_au_community_member_role_scope_fkey"; alter table "public"."community_member_role_scope_audit" add constraint "community_member_role_scope_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid; alter table "public"."community_member_role_scope_audit" validate constraint "community_member_role_scope_audit_actor_fkey"; alter table "public"."community_nonmember_scope" add constraint "community_nonmember_scope_community_fkey" FOREIGN KEY (community) REFERENCES community(id) not valid; alter table "public"."community_nonmember_scope" validate constraint "community_nonmember_scope_community_fkey"; alter table "public"."community_nonmember_scope" add constraint "community_nonmember_scope_community_scope_key" UNIQUE using index "community_nonmember_scope_community_scope_key"; alter table "public"."community_nonmember_scope" add constraint "community_nonmember_scope_uid_key" UNIQUE using index "community_nonmember_scope_uid_key"; alter table "public"."community_nonmember_scope_audit" add constraint "community_nonmember_scope_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid; alter table "public"."community_nonmember_scope_audit" validate constraint "community_nonmember_scope_audit_actor_fkey"; alter table "public"."community_nonmember_scope_audit" add constraint "community_nonmember_scope_audit_community_nonmember_scope_fkey" FOREIGN KEY (community_nonmember_scope) REFERENCES community_nonmember_scope(id) not valid; alter table "public"."community_nonmember_scope_audit" validate constraint "community_nonmember_scope_audit_community_nonmember_scope_fkey"; set check_function_bodies = off; CREATE OR REPLACE FUNCTION public.audit(schema text, table_ text, tracked_columns audited_column[], soft_delete boolean) RETURNS void LANGUAGE plpgsql AS $function$ begin if soft_delete then perform setup_audit_and_soft_delete(schema, table_, tracked_columns); else perform setup_audit_and_hard_delete(schema, table_, tracked_columns); end if; end; $function$ ; create type "public"."authz_scope" as ("str" text); CREATE OR REPLACE FUNCTION public.authz_scope_of_string(val text) RETURNS authz_scope LANGUAGE sql AS $function$select row(val);$function$ ; CREATE OR REPLACE FUNCTION public.authz_scope_to_string(val authz_scope) RETURNS text LANGUAGE sql AS $function$select (val.str);$function$ ; create type "public"."community_tag" as ("str" text); CREATE OR REPLACE FUNCTION public.community_tag_of_string(val text) RETURNS community_tag LANGUAGE sql AS $function$select row(val);$function$ ; CREATE OR REPLACE FUNCTION public.community_tag_to_string(val community_tag) RETURNS text LANGUAGE sql AS $function$select (val.str);$function$ ; 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; prev_role_nonmember int; 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; prev_role_nonmember := OLD.role_nonmember; end if; insert into public.usr_audit (kind, usr, actor, prev_tag, prev_role_nonmember ) values (audit_kind, id, 1, prev_tag, prev_role_nonmember); return NEW; end; $function$ ; CREATE OR REPLACE FUNCTION public.do_community_immutable_columns() RETURNS trigger LANGUAGE plpgsql AS $function$ begin if OLD.id <> NEW.id then raise exception 'public.community.id is immutable' using errcode = 'restrict_violation'; elsif OLD.uid <> NEW.uid then raise exception 'public.community.uid is immutable' using errcode = 'restrict_violation'; end if; 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.usr_audit (kind, usr, 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_immutable_columns() RETURNS trigger LANGUAGE plpgsql AS $function$ begin if OLD.id <> NEW.id then raise exception 'public.community_member.id is immutable' using errcode = 'restrict_violation'; elsif OLD.uid <> NEW.uid then raise exception 'public.community_member.uid is immutable' using errcode = 'restrict_violation'; elsif OLD.usr <> NEW.usr then raise exception 'public.community_member.usr is immutable' using errcode = 'restrict_violation'; end if; 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.usr_audit (kind, usr, 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'; 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.usr_audit (kind, usr, 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_member_role_scope_immutable_columns() RETURNS trigger LANGUAGE plpgsql AS $function$ begin if OLD.id <> NEW.id then raise exception 'public.community_member_role_scope.id is immutable' using errcode = 'restrict_violation'; elsif OLD.uid <> NEW.uid then raise exception 'public.community_member_role_scope.uid is immutable' using errcode = 'restrict_violation'; elsif OLD.role_ <> NEW.role_ then raise exception 'public.community_member_role_scope.role_ is immutable' using errcode = 'restrict_violation'; elsif OLD.scope <> NEW.scope then raise exception 'public.community_member_role_scope.scope is immutable' using errcode = 'restrict_violation'; end if; 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.usr_audit (kind, usr, actor, prev_community, prev_scope ) values (audit_kind, id, 1, prev_community, prev_scope); return NEW; end; $function$ ; CREATE OR REPLACE FUNCTION public.do_community_nonmember_scope_immutable_columns() RETURNS trigger LANGUAGE plpgsql AS $function$ begin if OLD.id <> NEW.id then raise exception 'public.community_nonmember_scope.id is immutable' using errcode = 'restrict_violation'; elsif OLD.uid <> NEW.uid then raise exception 'public.community_nonmember_scope.uid is immutable' using errcode = 'restrict_violation'; elsif OLD.community <> NEW.community then raise exception 'public.community_nonmember_scope.community is immutable' using errcode = 'restrict_violation'; elsif OLD.scope <> NEW.scope then raise exception 'public.community_nonmember_scope.scope is immutable' using errcode = 'restrict_violation'; end if; return NEW; end; $function$ ; CREATE OR REPLACE FUNCTION public.do_community_soft_delete() RETURNS trigger LANGUAGE plpgsql AS $function$ begin insert into public.community_audit (community, kind, actor) values (OLD.id, 'delete', 1); update public.community set deleted = true where id = OLD.id; return null; end; $function$ ; CREATE OR REPLACE FUNCTION public.immutable(schema text, table_ text, columns text[]) RETURNS void LANGUAGE plpgsql AS $function$ declare col text; qualified_name text := concat(schema, '.', table_); do_table_immutable_columns text := concat('do_', table_, '_immutable_columns'); trigger_table_immutable_columns text := concat('trigger_', table_, '_immutable_columns'); create_do_table_immutable_columns text; create_trigger_table_immutable_columns text; begin create_do_table_immutable_columns := concat( create_do_table_immutable_columns , 'create function ', schema, '.', do_table_immutable_columns, E'() returns trigger language plpgsql as \$\$\n' , E'begin\n' , ' if OLD.', columns[1], ' <> NEW.', columns[1], E' then\n' , E' raise exception \'', qualified_name, '.', columns[1], E' is immutable\' using errcode = \'restrict_violation\';\n' ); foreach col in array columns[2:] loop create_do_table_immutable_columns := concat( create_do_table_immutable_columns , E' elsif OLD.', col, ' <> NEW.', col, E' then\n' , E' raise exception \'', qualified_name, '.', col, E' is immutable\' using errcode = \'restrict_violation\';\n' ); end loop; create_do_table_immutable_columns := concat( create_do_table_immutable_columns , E' end if;\n' , E'\n' , E' return NEW;\n' , E'end;\n' , E'\$\$;\n' ); create_trigger_table_immutable_columns := concat( create_trigger_table_immutable_columns , 'create trigger ', trigger_table_immutable_columns, E'\n' , 'before update on ', qualified_name, E'\n' , 'for each row execute function ', do_table_immutable_columns, '();' ); execute create_do_table_immutable_columns; execute create_trigger_table_immutable_columns; 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 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 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 type "public"."usr_tag" as ("str" text); CREATE OR REPLACE FUNCTION public.usr_tag_of_string(val text) RETURNS usr_tag LANGUAGE sql AS $function$select row(val);$function$ ; CREATE OR REPLACE FUNCTION public.usr_tag_to_string(val usr_tag) RETURNS text LANGUAGE sql AS $function$select (val.str);$function$ ; CREATE OR REPLACE FUNCTION public.do_usr_audit() RETURNS trigger LANGUAGE plpgsql AS $function$ declare audit_kind public.audit_kind; id int; prev_tag public.usr_tag; 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_tag := OLD.tag; prev_password := OLD.password; prev_email := OLD.email; end if; insert into public.usr_audit (kind, usr, actor, prev_tag, prev_password, prev_email ) values (audit_kind, id, 1, prev_tag, prev_password, prev_email); return NEW; end; $function$ ; CREATE TRIGGER trigger_community_audit AFTER INSERT OR UPDATE ON public.community FOR EACH ROW EXECUTE FUNCTION do_community_audit(); CREATE TRIGGER trigger_community_immutable_columns BEFORE UPDATE ON public.community FOR EACH ROW EXECUTE FUNCTION do_community_immutable_columns(); CREATE TRIGGER trigger_community_soft_delete BEFORE DELETE ON public.community FOR EACH ROW EXECUTE FUNCTION do_community_soft_delete(); CREATE TRIGGER trigger_community_member_audit AFTER INSERT OR DELETE OR UPDATE ON public.community_member FOR EACH ROW EXECUTE FUNCTION do_community_member_audit(); CREATE TRIGGER trigger_community_member_immutable_columns BEFORE UPDATE ON public.community_member FOR EACH ROW EXECUTE FUNCTION do_community_member_immutable_columns(); CREATE TRIGGER trigger_community_member_role_audit AFTER INSERT OR DELETE OR UPDATE ON public.community_member_role FOR EACH ROW EXECUTE FUNCTION do_community_member_role_audit(); CREATE TRIGGER trigger_community_member_role_immutable_columns BEFORE UPDATE ON public.community_member_role FOR EACH ROW EXECUTE FUNCTION do_community_member_role_immutable_columns(); CREATE TRIGGER trigger_community_member_role_scope_audit AFTER INSERT OR DELETE OR UPDATE ON public.community_member_role_scope FOR EACH ROW EXECUTE FUNCTION do_community_member_role_scope_audit(); CREATE TRIGGER trigger_community_member_role_scope_immutable_columns BEFORE UPDATE ON public.community_member_role_scope FOR EACH ROW EXECUTE FUNCTION do_community_member_role_scope_immutable_columns(); CREATE TRIGGER trigger_community_nonmember_scope_audit AFTER INSERT OR DELETE OR UPDATE ON public.community_nonmember_scope FOR EACH ROW EXECUTE FUNCTION do_community_nonmember_scope_audit(); CREATE TRIGGER trigger_community_nonmember_scope_immutable_columns BEFORE UPDATE ON public.community_nonmember_scope FOR EACH ROW EXECUTE FUNCTION do_community_nonmember_scope_immutable_columns();