db/migrations/devel@8b08d9f_to_devel@0.0.3.sql
2023-07-15 23:07:03 -04:00

288 lines
9.7 KiB
PL/PgSQL

create schema if not exists "human_uuid";
create table "human_uuid"."object" (
"id" integer generated always as identity not null,
"word" text
);
create table "human_uuid"."predicate" (
"id" integer generated always as identity not null,
"word" text
);
create table "human_uuid"."used" (
"huid" text not null
);
create type "human_uuid"."huid" as ("str" text);
CREATE OR REPLACE FUNCTION human_uuid.huid()
RETURNS human_uuid.huid
LANGUAGE plpgsql
AS $function$
declare
tries int := 0;
uniq bool := false;
uuid bytea;
uuid_bits int[] := array[] :: int[];
pred_1_int int;
pred_2_int int;
pred_3_int int;
object_int int;
pred_1 text;
pred_2 text;
pred_3 text;
object text;
huid_text text;
begin
while not uniq loop
if tries > 1000 then
raise exception 'failed to find uniq huid after 1000 attempts';
end if;
tries := tries + 1;
uuid := decode(replace(gen_random_uuid() :: text, '-', ''), 'hex');
for b in 0..(bit_length(uuid) - 1) loop
uuid_bits := uuid_bits || get_bit(uuid, b);
end loop;
pred_1_int := (lpad(array_to_string(uuid_bits[1:10], ''), 32, '0') :: bit(32)) :: int;
pred_1_int := pred_1_int + (lpad(array_to_string(uuid_bits[11:14], ''), 32, '0') :: bit(32)) :: int;
pred_2_int := (lpad(array_to_string(uuid_bits[15:24], ''), 32, '0') :: bit(32)) :: int;
pred_2_int := pred_2_int + (lpad(array_to_string(uuid_bits[25:27], ''), 32, '0') :: bit(32)) :: int;
pred_3_int := (lpad(array_to_string(uuid_bits[28:37], ''), 32, '0') :: bit(32)) :: int;
pred_3_int := pred_3_int + (lpad(array_to_string(uuid_bits[38:40], ''), 32, '0') :: bit(32)) :: int;
object_int := (lpad(array_to_string(uuid_bits[41:51], ''), 32, '0') :: bit(32)) :: int;
select word from human_uuid.predicate where id = pred_1_int into pred_1;
select word from human_uuid.predicate where id = pred_2_int into pred_2;
select word from human_uuid.predicate where id = pred_3_int into pred_3;
select word from human_uuid.object where id = object_int into object;
huid_text := pred_1 || '-' || pred_2 || '-' || pred_3 || '-' || object;
uniq := (select count(*) from human_uuid.used where huid = huid_text) = 0;
end loop;
return human_uuid.huid_of_string(huid_text);
end;
$function$
;
CREATE OR REPLACE FUNCTION human_uuid.huid_of_string(val text)
RETURNS human_uuid.huid
LANGUAGE sql
AS $function$select row(val);$function$
;
CREATE OR REPLACE FUNCTION human_uuid.huid_to_string(val human_uuid.huid)
RETURNS text
LANGUAGE sql
AS $function$select (val.str);$function$
;
alter table "public"."community" alter column "uid" set default human_uuid.huid();
alter table "public"."community" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."grp" alter column "uid" set default human_uuid.huid();
alter table "public"."grp" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."perm" alter column "uid" set default human_uuid.huid();
alter table "public"."perm" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."thread" alter column "uid" set default human_uuid.huid();
alter table "public"."thread" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."thread_attachment" alter column "uid" set default human_uuid.huid();
alter table "public"."thread_attachment" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."thread_attachment_emoji" alter column "uid" set default human_uuid.huid();
alter table "public"."thread_attachment_emoji" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."thread_attachment_vote" alter column "uid" set default human_uuid.huid();
alter table "public"."thread_attachment_vote" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."thread_feed" alter column "uid" set default human_uuid.huid();
alter table "public"."thread_feed" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
alter table "public"."usr" alter column "uid" set default human_uuid.huid();
alter table "public"."usr" alter column "uid" set data type human_uuid.huid using "uid"::human_uuid.huid;
CREATE UNIQUE INDEX object_pkey ON human_uuid.object USING btree (id);
CREATE UNIQUE INDEX object_word_key ON human_uuid.object USING btree (word);
CREATE UNIQUE INDEX predicate_pkey ON human_uuid.predicate USING btree (id);
CREATE UNIQUE INDEX predicate_word_key ON human_uuid.predicate USING btree (word);
CREATE UNIQUE INDEX used_pkey ON human_uuid.used USING btree (huid);
CREATE UNIQUE INDEX grp_uid_key ON public.grp USING btree (uid);
CREATE UNIQUE INDEX perm_uid_key ON public.perm USING btree (uid);
CREATE UNIQUE INDEX thread_attachment_emoji_uid_key ON public.thread_attachment_emoji USING btree (uid);
CREATE UNIQUE INDEX thread_attachment_uid_key ON public.thread_attachment USING btree (uid);
CREATE UNIQUE INDEX thread_attachment_vote_uid_key ON public.thread_attachment_vote USING btree (uid);
CREATE UNIQUE INDEX thread_feed_uid_key ON public.thread_feed USING btree (uid);
CREATE UNIQUE INDEX thread_uid_key ON public.thread USING btree (uid);
CREATE UNIQUE INDEX usr_uid_key ON public.usr USING btree (uid);
alter table "human_uuid"."object" add constraint "object_pkey" PRIMARY KEY using index "object_pkey";
alter table "human_uuid"."predicate" add constraint "predicate_pkey" PRIMARY KEY using index "predicate_pkey";
alter table "human_uuid"."used" add constraint "used_pkey" PRIMARY KEY using index "used_pkey";
alter table "human_uuid"."object" add constraint "object_word_key" UNIQUE using index "object_word_key";
alter table "human_uuid"."predicate" add constraint "predicate_word_key" UNIQUE using index "predicate_word_key";
alter table "public"."grp" add constraint "grp_uid_key" UNIQUE using index "grp_uid_key";
alter table "public"."perm" add constraint "perm_uid_key" UNIQUE using index "perm_uid_key";
alter table "public"."thread" add constraint "thread_uid_key" UNIQUE using index "thread_uid_key";
alter table "public"."thread_attachment" add constraint "thread_attachment_uid_key" UNIQUE using index "thread_attachment_uid_key";
alter table "public"."thread_attachment_emoji" add constraint "thread_attachment_emoji_uid_key" UNIQUE using index "thread_attachment_emoji_uid_key";
alter table "public"."thread_attachment_vote" add constraint "thread_attachment_vote_uid_key" UNIQUE using index "thread_attachment_vote_uid_key";
alter table "public"."thread_feed" add constraint "thread_feed_uid_key" UNIQUE using index "thread_feed_uid_key";
alter table "public"."usr" add constraint "usr_uid_key" UNIQUE using index "usr_uid_key";
set check_function_bodies = off;
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/' || human_uuid.huid_to_string(NEW.uid) || '/posts', (public.get_acting_usr()).id, NEW.id, 'w', 'w', 'r')
, ('/communities/' || human_uuid.huid_to_string(NEW.uid) || '/tag', (public.get_acting_usr()).id, NEW.id, 'w', 'w', 'r')
, ('/communities/' || human_uuid.huid_to_string(NEW.uid) || '/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/' || human_uuid.huid_to_string(NEW.uid) || '/members', (public.get_acting_usr()).id, NEW.id, 'w', 'w', '-')
, ('/groups/' || human_uuid.huid_to_string(NEW.uid) || '/tag', (public.get_acting_usr()).id, NEW.id, 'w', 'w', 'r')
;
return new;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.do_insert_usr_perm()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
declare
admins int;
begin
admins := (public.grp_admins()).id;
insert into public.perm
(path, owner_user, owner_group, owner_user_mode, owner_group_mode, everyone_mode)
values
('/users/' || human_uuid.huid_to_string(NEW.uid) || '/tag', NEW.id, admins, 'w', 'w', 'r')
, ('/users/' || human_uuid.huid_to_string(NEW.uid) || '/email', NEW.id, admins, 'w', 'w', '-')
, ('/users/' || human_uuid.huid_to_string(NEW.uid) || '/deleted', NEW.id, admins, 'w', 'w', '-')
, ('/users/' || human_uuid.huid_to_string(NEW.uid) || '/password', NEW.id, admins, 'w', 'w', '-')
;
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);
update public.perm
set owner_user = (public.usr_root()).id
, owner_group = (public.grp_admins()).id
where path = '/groups/' || new_grp || '/members'
or path = '/groups/' || new_grp || '/tag';
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
acting_usr := public.usr_root();
else
select u.*
from public.usr u
where u.uid = human_uuid.huid_of_string(current_setting('dnim.usr_uid', true))
into acting_usr;
end if;
return acting_usr;
end;
$function$
;