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

1203 lines
37 KiB
PL/PgSQL

create type "public"."grp_tag" as ("str" text);
CREATE OR REPLACE FUNCTION public.grp_tag_of_string(val text)
RETURNS grp_tag
LANGUAGE sql
AS $function$select row(val);$function$
;
CREATE OR REPLACE FUNCTION public.grp_tag_to_string(val grp_tag)
RETURNS text
LANGUAGE sql
AS $function$select (val.str);$function$
;
create type "public"."perm_mode" as enum ('-', 'r', 'w');
drop trigger if exists "trigger_community_member_audit" on "public"."community_member";
drop trigger if exists "trigger_community_member_immutable_columns" on "public"."community_member";
drop trigger if exists "trigger_community_member_role_audit" on "public"."community_member_role";
drop trigger if exists "trigger_community_member_role_immutable_columns" on "public"."community_member_role";
drop trigger if exists "trigger_community_member_role_scope_audit" on "public"."community_member_role_scope";
drop trigger if exists "trigger_community_member_role_scope_immutable_columns" on "public"."community_member_role_scope";
drop trigger if exists "trigger_community_nonmember_scope_audit" on "public"."community_nonmember_scope";
drop trigger if exists "trigger_community_nonmember_scope_immutable_columns" on "public"."community_nonmember_scope";
alter table "public"."community_member" drop constraint "community_member_community_fkey";
alter table "public"."community_member" drop constraint "community_member_role__fkey";
alter table "public"."community_member" drop constraint "community_member_uid_key";
alter table "public"."community_member" drop constraint "community_member_usr_fkey";
alter table "public"."community_member_audit" drop constraint "community_member_audit_actor_fkey";
alter table "public"."community_member_audit" drop constraint "community_member_audit_community_member_fkey";
alter table "public"."community_member_role" drop constraint "community_member_role_community_fkey";
alter table "public"."community_member_role" drop constraint "community_member_role_uid_key";
alter table "public"."community_member_role_audit" drop constraint "community_member_role_audit_actor_fkey";
alter table "public"."community_member_role_audit" drop constraint "community_member_role_audit_community_member_role_fkey";
alter table "public"."community_member_role_scope" drop constraint "community_member_role_scope_role__fkey";
alter table "public"."community_member_role_scope" drop constraint "community_member_role_scope_scope_role__key";
alter table "public"."community_member_role_scope" drop constraint "community_member_role_scope_uid_key";
alter table "public"."community_member_role_scope_audit" drop constraint "community_member_role_scope_au_community_member_role_scope_fkey";
alter table "public"."community_member_role_scope_audit" drop constraint "community_member_role_scope_audit_actor_fkey";
alter table "public"."community_nonmember_scope" drop constraint "community_nonmember_scope_community_fkey";
alter table "public"."community_nonmember_scope" drop constraint "community_nonmember_scope_community_scope_key";
alter table "public"."community_nonmember_scope" drop constraint "community_nonmember_scope_uid_key";
alter table "public"."community_nonmember_scope_audit" drop constraint "community_nonmember_scope_audit_actor_fkey";
alter table "public"."community_nonmember_scope_audit" drop constraint "community_nonmember_scope_audit_community_nonmember_scope_fkey";
drop function if exists "public"."do_community_member_audit"();
drop function if exists "public"."do_community_member_immutable_columns"();
drop function if exists "public"."do_community_member_role_audit"();
drop function if exists "public"."do_community_member_role_immutable_columns"();
drop function if exists "public"."do_community_member_role_scope_audit"();
drop function if exists "public"."do_community_member_role_scope_immutable_columns"();
drop function if exists "public"."do_community_nonmember_scope_audit"();
drop function if exists "public"."do_community_nonmember_scope_immutable_columns"();
alter table "public"."community_member" drop constraint "community_member_pkey";
alter table "public"."community_member_role" drop constraint "community_member_role_pkey";
alter table "public"."community_member_role_scope" drop constraint "community_member_role_scope_pkey";
alter table "public"."community_nonmember_scope" drop constraint "community_nonmember_scope_pkey";
drop index if exists "public"."community_member_pkey";
drop index if exists "public"."community_member_role_pkey";
drop index if exists "public"."community_member_role_scope_pkey";
drop index if exists "public"."community_member_role_scope_scope_role__key";
drop index if exists "public"."community_member_role_scope_uid_key";
drop index if exists "public"."community_member_role_uid_key";
drop index if exists "public"."community_member_uid_key";
drop index if exists "public"."community_nonmember_scope_community_scope_key";
drop index if exists "public"."community_nonmember_scope_pkey";
drop index if exists "public"."community_nonmember_scope_uid_key";
drop table "public"."community_member";
drop table "public"."community_member_audit";
drop table "public"."community_member_role";
drop table "public"."community_member_role_audit";
drop table "public"."community_member_role_scope";
drop table "public"."community_member_role_scope_audit";
drop table "public"."community_nonmember_scope";
drop table "public"."community_nonmember_scope_audit";
drop function if exists "public"."authz_scope_of_string"(val text);
drop function if exists "public"."authz_scope_to_string"(val authz_scope);
drop type "public"."authz_scope";
create table "public"."grp" (
"id" integer generated always as identity not null,
"uid" uuid not null default gen_random_uuid(),
"deleted" boolean not null default false,
"tag" grp_tag not null
);
create table "public"."grp_audit" (
"grp" integer not null,
"kind" audit_kind not null,
"actor" integer not null
);
create table "public"."grp_usr" (
"grp" integer not null,
"usr" integer not null
);
create table "public"."perm" (
"id" integer generated always as identity not null,
"uid" uuid not null default gen_random_uuid(),
"owner_user" integer not null,
"owner_group" integer not null,
"owner_user_mode" perm_mode not null,
"owner_group_mode" perm_mode not null,
"everyone_mode" perm_mode not null,
"path" text not null
);
create table "public"."perm_audit" (
"perm" integer not null,
"kind" audit_kind not null,
"actor" integer not null,
"prev_owner_user" integer,
"prev_owner_group" integer,
"prev_owner_user_mode" perm_mode,
"prev_owner_group_mode" perm_mode,
"prev_everyone_mode" perm_mode
);
alter table "public"."usr" add column "discrim" integer not null default 0;
CREATE UNIQUE INDEX grp_pkey ON public.grp USING btree (id);
CREATE UNIQUE INDEX grp_tag_key ON public.grp USING btree (tag);
CREATE UNIQUE INDEX grp_usr_pkey ON public.grp_usr USING btree (grp, usr);
CREATE UNIQUE INDEX perm_path_key ON public.perm USING btree (path);
CREATE UNIQUE INDEX perm_pkey ON public.perm USING btree (id);
CREATE UNIQUE INDEX usr_tag_discrim_key ON public.usr USING btree (tag, discrim);
alter table "public"."grp" add constraint "grp_pkey" PRIMARY KEY using index "grp_pkey";
alter table "public"."grp_usr" add constraint "grp_usr_pkey" PRIMARY KEY using index "grp_usr_pkey";
alter table "public"."perm" add constraint "perm_pkey" PRIMARY KEY using index "perm_pkey";
alter table "public"."grp" add constraint "grp_tag_key" UNIQUE using index "grp_tag_key";
alter table "public"."grp_audit" add constraint "grp_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."grp_audit" validate constraint "grp_audit_actor_fkey";
alter table "public"."grp_audit" add constraint "grp_audit_grp_fkey" FOREIGN KEY (grp) REFERENCES grp(id) not valid;
alter table "public"."grp_audit" validate constraint "grp_audit_grp_fkey";
alter table "public"."grp_usr" add constraint "grp_usr_grp_fkey" FOREIGN KEY (grp) REFERENCES grp(id) not valid;
alter table "public"."grp_usr" validate constraint "grp_usr_grp_fkey";
alter table "public"."grp_usr" add constraint "grp_usr_usr_fkey" FOREIGN KEY (usr) REFERENCES usr(id) not valid;
alter table "public"."grp_usr" validate constraint "grp_usr_usr_fkey";
alter table "public"."perm" add constraint "perm_owner_group_fkey" FOREIGN KEY (owner_group) REFERENCES grp(id) not valid;
alter table "public"."perm" validate constraint "perm_owner_group_fkey";
alter table "public"."perm" add constraint "perm_owner_user_fkey" FOREIGN KEY (owner_user) REFERENCES usr(id) not valid;
alter table "public"."perm" validate constraint "perm_owner_user_fkey";
alter table "public"."perm" add constraint "perm_path_key" UNIQUE using index "perm_path_key";
alter table "public"."perm_audit" add constraint "perm_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."perm_audit" validate constraint "perm_audit_actor_fkey";
alter table "public"."perm_audit" add constraint "perm_audit_perm_fkey" FOREIGN KEY (perm) REFERENCES perm(id) not valid;
alter table "public"."perm_audit" validate constraint "perm_audit_perm_fkey";
alter table "public"."usr" add constraint "usr_tag_discrim_key" UNIQUE using index "usr_tag_discrim_key";
set check_function_bodies = off;
CREATE OR REPLACE FUNCTION public.do_check_usr_tag()
RETURNS trigger
LANGUAGE plpgsql
STABLE
AS $function$
begin
if new.tag = usr_tag_of_string('root') then
raise exception 'invalid tag';
else
return new;
end if;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_grp_add_admins()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
admins int[];
begin
select array_agg(usr.id)
from public.grp_members_admins() as usr
into admins;
perform public.grp_add_members( to_grp => NEW.id
, add_usrs => admins
);
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_grp_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.grp_audit
(kind, grp, actor )
values
(audit_kind, id, (public.get_acting_usr()).id);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_grp_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.grp.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.grp.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.tag <> NEW.tag then
raise exception 'public.grp.tag is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_grp_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.grp_audit
(grp, kind, actor)
values
(OLD.id, 'delete', (select (public.get_acting_usr()).id));
update public.grp
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_insert_community_perm()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
-- TODO: insert some default community groups, use community_XX_admin as group owner
insert into public.perm
(path, owner_user, owner_group, owner_user_mode, owner_group_mode, everyone_mode)
values
('/communities/' || NEW.id || '/posts', (public.get_acting_usr()).id, NEW.id, 'w', 'w', 'r')
, ('/communities/' || NEW.id || '/tag', (public.get_acting_usr()).id, NEW.id, 'w', 'w', 'r')
, ('/communities/' || NEW.id || '/deleted', (public.get_acting_usr()).id, NEW.id, 'w', 'w', '-')
;
return new;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_insert_grp_perm()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.perm
(path, owner_user, owner_group, owner_user_mode, owner_group_mode, everyone_mode)
values
('/groups/' || NEW.id || '/members', (public.get_acting_usr()).id, NEW.id, 'w', 'w', '-')
, ('/groups/' || NEW.id || '/tag', (public.get_acting_usr()).id, NEW.id, 'w', 'w', 'r')
;
return new;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_insert_usr_default_discrim()
RETURNS trigger
LANGUAGE plpgsql
STABLE
AS $function$
begin
if new.discrim is null then
new.discrim := (select count(*) from public.usr u where u.tag = tag);
end if;
return new;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_insert_usr_perm()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
admins int;
begin
select * from public.grp where tag = grp_tag_of_string('admins') into admins;
insert into public.perm
(path, owner_user, owner_group, owner_user_mode, owner_group_mode, everyone_mode)
values
('/users/' || NEW.id || '/tag', NEW.id, admins, 'w', 'w', 'r')
, ('/users/' || NEW.id || '/email', NEW.id, admins, 'w', 'w', '-')
, ('/users/' || NEW.id || '/deleted', NEW.id, admins, 'w', 'w', '-')
;
return new;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_perm_audit()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
audit_kind public.audit_kind;
id int;
prev_owner_user int;
prev_owner_group int;
prev_owner_user_mode public.perm_mode;
prev_owner_group_mode public.perm_mode;
prev_everyone_mode public.perm_mode;
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_owner_user := OLD.owner_user;
prev_owner_group := OLD.owner_group;
prev_owner_user_mode := OLD.owner_user_mode;
prev_owner_group_mode := OLD.owner_group_mode;
prev_everyone_mode := OLD.everyone_mode;
end if;
insert into public.perm_audit
(kind, perm, actor, prev_owner_user, prev_owner_group, prev_owner_user_mode, prev_owner_group_mode, prev_everyone_mode )
values
(audit_kind, id, (public.get_acting_usr()).id, prev_owner_user, prev_owner_group, prev_owner_user_mode, prev_owner_group_mode, prev_everyone_mode);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_perm_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.perm.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.perm.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.path <> NEW.path then
raise exception 'public.perm.path is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_usr_create_default_grp()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
new_grp int;
begin
insert into public.grp (tag)
values (grp_tag_of_string('usr_' || new.uid))
returning id into new_grp;
perform public.grp_add_member(to_grp => new_grp, add_usr => new.id);
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.get_acting_usr()
RETURNS usr
LANGUAGE plpgsql
AS $function$
declare
uid text;
acting_usr public.usr;
begin
if nullif(current_setting('dnim.usr_uid', true), '') is null then
select u.*
from public.usr u
where u.tag = public.usr_tag_of_string('root')
into acting_usr;
else
select u.*
from public.usr u
where u.uid = current_setting('dnim.usr_uid', true) :: uuid
into acting_usr;
end if;
return acting_usr;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.grp_add_member(to_grp integer, add_usr integer)
RETURNS void
LANGUAGE plpgsql
AS $function$
begin
insert into public.grp_usr (grp, usr) values (to_grp, add_usr);
end;
$function$
;
CREATE OR REPLACE FUNCTION public.grp_add_members(to_grp integer, add_usrs integer[])
RETURNS void
LANGUAGE plpgsql
AS $function$
begin
insert into public.grp_usr (grp, usr)
select grp, usr_id
from unnest(add_usrs) usr_id
left join public.grp_usr gu on gu.usr = usr_id and gu.grp = to_grp
where gu is null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.grp_members(of_grp integer)
RETURNS SETOF usr
LANGUAGE plpgsql
STABLE
AS $function$
begin
return query select u.*
from public.usr u
inner join public.grp_usr gu
on gu.usr = u.id and gu.grp = of_grp;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.grp_members_admins()
RETURNS SETOF usr
LANGUAGE plpgsql
STABLE
AS $function$
declare
gid int;
begin
select g.id
from public.grp g
where g.tag = public.grp_tag_of_string('admins')
into gid;
return query select * from public.grp_members(gid);
end;
$function$
;
CREATE OR REPLACE FUNCTION public.grp_rm_member(from_grp integer, rm_usr integer)
RETURNS void
LANGUAGE plpgsql
AS $function$
begin
delete from public.grp_usr gu
where gu.grp = from_grp and gu.usr = rm_usr;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.set_acting_usr(uid text)
RETURNS void
LANGUAGE plpgsql
AS $function$
begin
set session "dnim.usr_uid" = uid;
end;
$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;
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, (public.get_acting_usr()).id, prev_tag);
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', (select (public.get_acting_usr()).id));
update public.community
set deleted = true
where id = OLD.id;
return null;
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, (public.get_acting_usr()).id);
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, (public.get_acting_usr()).id);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_emoji_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.thread_attachment_emoji_audit
(thread_attachment_emoji, kind, actor)
values
(OLD.id, 'delete', (select (public.get_acting_usr()).id));
update public.thread_attachment_emoji
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.thread_attachment_audit
(thread_attachment, kind, actor)
values
(OLD.id, 'delete', (select (public.get_acting_usr()).id));
update public.thread_attachment
set deleted = true
where id = OLD.id;
return null;
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, (public.get_acting_usr()).id);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_vote_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.thread_attachment_vote_audit
(thread_attachment_vote, kind, actor)
values
(OLD.id, 'delete', (select (public.get_acting_usr()).id));
update public.thread_attachment_vote
set deleted = true
where id = OLD.id;
return null;
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, (public.get_acting_usr()).id);
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, (public.get_acting_usr()).id);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_feed_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.thread_feed_audit
(thread_feed, kind, actor)
values
(OLD.id, 'delete', (select (public.get_acting_usr()).id));
update public.thread_feed
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_soft_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
insert into public.thread_audit
(thread, kind, actor)
values
(OLD.id, 'delete', (select (public.get_acting_usr()).id));
update public.thread
set deleted = true
where id = OLD.id;
return null;
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_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, (public.get_acting_usr()).id, prev_tag, 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', (select (public.get_acting_usr()).id));
update public.usr
set deleted = true
where id = OLD.id;
return null;
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, (public.get_acting_usr()).id'
);
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\', (select (public.get_acting_usr()).id));\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, (public.get_acting_usr()).id'
);
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.usr_session_login_validate(tag_or_email usr_tag_or_email, password text)
RETURNS usr
LANGUAGE plpgsql
STABLE
AS $function$
declare
usr_email public.email := public.usr_tag_or_email_to_email(tag_or_email);
usr_tag public.usr_tag := public.usr_tag_or_email_to_tag(tag_or_email);
usr public.usr;
begin
select *
from public.usr as u
where u.email = usr_email
or u.tag = usr_tag
into usr;
if usr.id = 1 or usr.tag = usr_tag_of_string('root') then
raise notice 'root user may not be logged into';
raise exception 'incorrect password for user %', usr_tag_or_email_to_string(tag_or_email);
end if;
if usr is null then
-- prevent email guess bruteforces by raising the same exception
-- for invalid password and user not found
raise notice 'user % not found', usr_tag_or_email_to_string(tag_or_email);
raise exception 'incorrect password for user %', usr_tag_or_email_to_string(tag_or_email);
end if;
if not hashed_text_matches(password, usr.password) then
raise notice 'password does not match for user %', usr_tag_or_email_to_string(tag_or_email);
raise exception 'incorrect password for user %', usr_tag_or_email_to_string(tag_or_email);
end if;
return usr;
end;
$function$
;
CREATE TRIGGER insert_community_perm AFTER INSERT ON public.community FOR EACH ROW EXECUTE FUNCTION do_insert_community_perm();
CREATE TRIGGER grp_add_admins AFTER INSERT ON public.grp FOR EACH ROW EXECUTE FUNCTION do_grp_add_admins();
CREATE TRIGGER insert_grp_perm AFTER INSERT ON public.grp FOR EACH ROW EXECUTE FUNCTION do_insert_grp_perm();
CREATE TRIGGER trigger_grp_audit AFTER INSERT OR UPDATE ON public.grp FOR EACH ROW EXECUTE FUNCTION do_grp_audit();
CREATE TRIGGER trigger_grp_immutable_columns BEFORE UPDATE ON public.grp FOR EACH ROW EXECUTE FUNCTION do_grp_immutable_columns();
CREATE TRIGGER trigger_grp_soft_delete BEFORE DELETE ON public.grp FOR EACH ROW EXECUTE FUNCTION do_grp_soft_delete();
CREATE TRIGGER trigger_perm_audit AFTER INSERT OR DELETE OR UPDATE ON public.perm FOR EACH ROW EXECUTE FUNCTION do_perm_audit();
CREATE TRIGGER trigger_perm_immutable_columns BEFORE UPDATE ON public.perm FOR EACH ROW EXECUTE FUNCTION do_perm_immutable_columns();
CREATE TRIGGER check_usr_tag BEFORE INSERT ON public.usr FOR EACH ROW EXECUTE FUNCTION do_check_usr_tag();
CREATE TRIGGER insert_usr_default_discrim BEFORE INSERT ON public.usr FOR EACH ROW EXECUTE FUNCTION do_insert_usr_default_discrim();
CREATE TRIGGER insert_usr_perm AFTER INSERT ON public.usr FOR EACH ROW EXECUTE FUNCTION do_insert_usr_perm();
CREATE TRIGGER usr_create_default_grp AFTER INSERT ON public.usr FOR EACH ROW EXECUTE FUNCTION do_usr_create_default_grp();