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

561 lines
20 KiB
PL/PgSQL

create type "public"."thread_attachment_kind" as enum ('vote', 'emoji');
create type "public"."thread_attachment_vote_direction" as enum ('up', 'down');
alter type "public"."thread_kind" rename to "thread_kind__old_version_to_be_dropped";
create type "public"."thread_kind" as enum ('feed', 'message_feed', 'message', 'post_feed', 'post', 'comment', 'symbolic');
create table "public"."thread_attachment" (
"id" integer generated always as identity not null,
"uid" uuid not null default gen_random_uuid(),
"thread" integer not null,
"kind" thread_attachment_kind not null
);
create table "public"."thread_attachment_audit" (
"thread_attachment" integer not null,
"kind" audit_kind not null,
"actor" integer not null
);
create table "public"."thread_attachment_emoji" (
"id" integer generated always as identity not null,
"uid" uuid not null default gen_random_uuid(),
"thread_attachment" integer not null,
"emoji" text not null
);
create table "public"."thread_attachment_emoji_audit" (
"thread_attachment_emoji" integer not null,
"kind" audit_kind not null,
"actor" integer not null
);
create table "public"."thread_attachment_vote" (
"id" integer generated always as identity not null,
"uid" uuid not null default gen_random_uuid(),
"thread_attachment" integer not null,
"direction" thread_attachment_vote_direction not null
);
create table "public"."thread_attachment_vote_audit" (
"thread_attachment_vote" integer not null,
"kind" audit_kind not null,
"actor" integer not null
);
create table "public"."thread_audit" (
"thread" integer not null,
"kind" audit_kind not null,
"actor" integer not null
);
create table "public"."thread_feed" (
"id" integer generated always as identity not null,
"uid" uuid not null default gen_random_uuid(),
"deleted" boolean not null default false,
"thread" integer not null
);
create table "public"."thread_feed_audit" (
"thread_feed" integer not null,
"kind" audit_kind not null,
"actor" integer not null
);
alter table "public"."thread" alter column kind type "public"."thread_kind" using kind::text::"public"."thread_kind";
drop type "public"."thread_kind__old_version_to_be_dropped";
alter table "public"."thread" add column "deleted" boolean not null default false;
CREATE UNIQUE INDEX thread_attachment_emoji_pkey ON public.thread_attachment_emoji USING btree (id);
CREATE UNIQUE INDEX thread_attachment_pkey ON public.thread_attachment USING btree (id);
CREATE UNIQUE INDEX thread_attachment_vote_pkey ON public.thread_attachment_vote USING btree (id);
CREATE UNIQUE INDEX thread_feed_pkey ON public.thread_feed USING btree (id);
alter table "public"."thread_attachment" add constraint "thread_attachment_pkey" PRIMARY KEY using index "thread_attachment_pkey";
alter table "public"."thread_attachment_emoji" add constraint "thread_attachment_emoji_pkey" PRIMARY KEY using index "thread_attachment_emoji_pkey";
alter table "public"."thread_attachment_vote" add constraint "thread_attachment_vote_pkey" PRIMARY KEY using index "thread_attachment_vote_pkey";
alter table "public"."thread_feed" add constraint "thread_feed_pkey" PRIMARY KEY using index "thread_feed_pkey";
alter table "public"."thread_attachment" add constraint "thread_attachment_thread_fkey" FOREIGN KEY (thread) REFERENCES thread(id) not valid;
alter table "public"."thread_attachment" validate constraint "thread_attachment_thread_fkey";
alter table "public"."thread_attachment_audit" add constraint "thread_attachment_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."thread_attachment_audit" validate constraint "thread_attachment_audit_actor_fkey";
alter table "public"."thread_attachment_audit" add constraint "thread_attachment_audit_thread_attachment_fkey" FOREIGN KEY (thread_attachment) REFERENCES thread_attachment(id) not valid;
alter table "public"."thread_attachment_audit" validate constraint "thread_attachment_audit_thread_attachment_fkey";
alter table "public"."thread_attachment_emoji" add constraint "thread_attachment_emoji_thread_attachment_fkey" FOREIGN KEY (thread_attachment) REFERENCES thread_attachment(id) not valid;
alter table "public"."thread_attachment_emoji" validate constraint "thread_attachment_emoji_thread_attachment_fkey";
alter table "public"."thread_attachment_emoji_audit" add constraint "thread_attachment_emoji_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."thread_attachment_emoji_audit" validate constraint "thread_attachment_emoji_audit_actor_fkey";
alter table "public"."thread_attachment_emoji_audit" add constraint "thread_attachment_emoji_audit_thread_attachment_emoji_fkey" FOREIGN KEY (thread_attachment_emoji) REFERENCES thread_attachment_emoji(id) not valid;
alter table "public"."thread_attachment_emoji_audit" validate constraint "thread_attachment_emoji_audit_thread_attachment_emoji_fkey";
alter table "public"."thread_attachment_vote" add constraint "thread_attachment_vote_thread_attachment_fkey" FOREIGN KEY (thread_attachment) REFERENCES thread_attachment(id) not valid;
alter table "public"."thread_attachment_vote" validate constraint "thread_attachment_vote_thread_attachment_fkey";
alter table "public"."thread_attachment_vote_audit" add constraint "thread_attachment_vote_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."thread_attachment_vote_audit" validate constraint "thread_attachment_vote_audit_actor_fkey";
alter table "public"."thread_attachment_vote_audit" add constraint "thread_attachment_vote_audit_thread_attachment_vote_fkey" FOREIGN KEY (thread_attachment_vote) REFERENCES thread_attachment_vote(id) not valid;
alter table "public"."thread_attachment_vote_audit" validate constraint "thread_attachment_vote_audit_thread_attachment_vote_fkey";
alter table "public"."thread_audit" add constraint "thread_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."thread_audit" validate constraint "thread_audit_actor_fkey";
alter table "public"."thread_audit" add constraint "thread_audit_thread_fkey" FOREIGN KEY (thread) REFERENCES thread(id) not valid;
alter table "public"."thread_audit" validate constraint "thread_audit_thread_fkey";
alter table "public"."thread_feed" add constraint "thread_feed_thread_fkey" FOREIGN KEY (thread) REFERENCES thread(id) not valid;
alter table "public"."thread_feed" validate constraint "thread_feed_thread_fkey";
alter table "public"."thread_feed_audit" add constraint "thread_feed_audit_actor_fkey" FOREIGN KEY (actor) REFERENCES usr(id) not valid;
alter table "public"."thread_feed_audit" validate constraint "thread_feed_audit_actor_fkey";
alter table "public"."thread_feed_audit" add constraint "thread_feed_audit_thread_feed_fkey" FOREIGN KEY (thread_feed) REFERENCES thread_feed(id) not valid;
alter table "public"."thread_feed_audit" validate constraint "thread_feed_audit_thread_feed_fkey";
set check_function_bodies = off;
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.usr_audit
(kind, usr, 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.usr_audit
(kind, usr, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_emoji_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.thread_attachment_emoji.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.thread_attachment_emoji.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.thread_attachment <> NEW.thread_attachment then
raise exception 'public.thread_attachment_emoji.thread_attachment is immutable' using errcode = 'restrict_violation';
elsif OLD.emoji <> NEW.emoji then
raise exception 'public.thread_attachment_emoji.emoji is immutable' using errcode = 'restrict_violation';
end if;
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', 1);
update public.thread_attachment_emoji
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.thread_attachment.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.thread_attachment.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.thread <> NEW.thread then
raise exception 'public.thread_attachment.thread is immutable' using errcode = 'restrict_violation';
elsif OLD.kind <> NEW.kind then
raise exception 'public.thread_attachment.kind is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
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', 1);
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.usr_audit
(kind, usr, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_attachment_vote_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.thread_attachment_vote.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.thread_attachment_vote.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.thread_attachment <> NEW.thread_attachment then
raise exception 'public.thread_attachment_vote.thread_attachment is immutable' using errcode = 'restrict_violation';
elsif OLD.direction <> NEW.direction then
raise exception 'public.thread_attachment_vote.direction is immutable' using errcode = 'restrict_violation';
end if;
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', 1);
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.usr_audit
(kind, usr, 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.usr_audit
(kind, usr, actor )
values
(audit_kind, id, 1);
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_feed_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.thread_feed.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.thread_feed.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.thread <> NEW.thread then
raise exception 'public.thread_feed.thread is immutable' using errcode = 'restrict_violation';
elsif OLD.community <> NEW.community then
raise exception 'public.thread_feed.community is immutable' using errcode = 'restrict_violation';
end if;
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', 1);
update public.thread_feed
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_thread_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.thread.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.thread.uid is immutable' using errcode = 'restrict_violation';
elsif OLD.kind <> NEW.kind then
raise exception 'public.thread.kind is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
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', 1);
update public.thread
set deleted = true
where id = OLD.id;
return null;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_usr_immutable_columns()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
begin
if OLD.id <> NEW.id then
raise exception 'public.usr.id is immutable' using errcode = 'restrict_violation';
elsif OLD.uid <> NEW.uid then
raise exception 'public.usr.uid is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.mark_columns_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 TRIGGER trigger_thread_audit AFTER INSERT OR UPDATE ON public.thread FOR EACH ROW EXECUTE FUNCTION do_thread_audit();
CREATE TRIGGER trigger_thread_immutable_columns BEFORE UPDATE ON public.thread FOR EACH ROW EXECUTE FUNCTION do_thread_immutable_columns();
CREATE TRIGGER trigger_thread_soft_delete BEFORE DELETE ON public.thread FOR EACH ROW EXECUTE FUNCTION do_thread_soft_delete();
CREATE TRIGGER trigger_thread_attachment_audit AFTER INSERT OR UPDATE ON public.thread_attachment FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_audit();
CREATE TRIGGER trigger_thread_attachment_immutable_columns BEFORE UPDATE ON public.thread_attachment FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_immutable_columns();
CREATE TRIGGER trigger_thread_attachment_soft_delete BEFORE DELETE ON public.thread_attachment FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_soft_delete();
CREATE TRIGGER trigger_thread_attachment_emoji_audit AFTER INSERT OR UPDATE ON public.thread_attachment_emoji FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_emoji_audit();
CREATE TRIGGER trigger_thread_attachment_emoji_immutable_columns BEFORE UPDATE ON public.thread_attachment_emoji FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_emoji_immutable_columns();
CREATE TRIGGER trigger_thread_attachment_emoji_soft_delete BEFORE DELETE ON public.thread_attachment_emoji FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_emoji_soft_delete();
CREATE TRIGGER trigger_thread_attachment_vote_audit AFTER INSERT OR UPDATE ON public.thread_attachment_vote FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_vote_audit();
CREATE TRIGGER trigger_thread_attachment_vote_immutable_columns BEFORE UPDATE ON public.thread_attachment_vote FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_vote_immutable_columns();
CREATE TRIGGER trigger_thread_attachment_vote_soft_delete BEFORE DELETE ON public.thread_attachment_vote FOR EACH ROW EXECUTE FUNCTION do_thread_attachment_vote_soft_delete();
CREATE TRIGGER trigger_thread_feed_audit AFTER INSERT OR UPDATE ON public.thread_feed FOR EACH ROW EXECUTE FUNCTION do_thread_feed_audit();
CREATE TRIGGER trigger_thread_feed_immutable_columns BEFORE UPDATE ON public.thread_feed FOR EACH ROW EXECUTE FUNCTION do_thread_feed_immutable_columns();
CREATE TRIGGER trigger_thread_feed_soft_delete BEFORE DELETE ON public.thread_feed FOR EACH ROW EXECUTE FUNCTION do_thread_feed_soft_delete();
CREATE TRIGGER trigger_usr_immutable_columns BEFORE UPDATE ON public.usr FOR EACH ROW EXECUTE FUNCTION do_usr_immutable_columns();