diff --git a/schema/000_extensions.sql b/schema/0000_extensions.sql similarity index 100% rename from schema/000_extensions.sql rename to schema/0000_extensions.sql diff --git a/schema/000_revision.sql b/schema/0001_migrations.sql similarity index 100% rename from schema/000_revision.sql rename to schema/0001_migrations.sql diff --git a/schema/000_audit_and_soft_delete.sql b/schema/0010_audit_and_soft_delete.sql similarity index 96% rename from schema/000_audit_and_soft_delete.sql rename to schema/0010_audit_and_soft_delete.sql index e91201c..b5f185e 100644 --- a/schema/000_audit_and_soft_delete.sql +++ b/schema/0010_audit_and_soft_delete.sql @@ -1,3 +1,9 @@ +create type public.audit_kind as enum + ( 'modify' + , 'delete' + , 'create' + ); + create type audited_column as (column_ text, type_ text); create function audit(schema text, table_ text, tracked_columns audited_column[], soft_delete boolean) @@ -55,7 +61,7 @@ create function setup_audit_and_soft_delete( schema text , E' insert into ', audit_table, E'\n' , E' (', table_, E', kind, actor)\n' , E' values\n' - , E' (OLD.id, \'delete\', 1);\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' @@ -112,7 +118,7 @@ create function setup_audit_and_soft_delete( schema text create_do_table_audit := concat( create_do_table_audit , E' )\n' , E' values\n' - , E' (audit_kind, id, 1' + , E' (audit_kind, id, (public.get_acting_usr()).id' ); foreach col in array tracked_columns loop @@ -229,7 +235,7 @@ create function setup_audit_and_hard_delete( schema text create_do_table_audit := concat( create_do_table_audit , E' )\n' , E' values\n' - , E' (audit_kind, id, 1' + , E' (audit_kind, id, (public.get_acting_usr()).id' ); foreach col in array tracked_columns loop diff --git a/schema/000_immutable.sql b/schema/0011_immutable.sql similarity index 100% rename from schema/000_immutable.sql rename to schema/0011_immutable.sql diff --git a/schema/000_newtype.sql b/schema/0012_newtype.sql similarity index 100% rename from schema/000_newtype.sql rename to schema/0012_newtype.sql diff --git a/schema/010_email.sql b/schema/0013_email.sql similarity index 100% rename from schema/010_email.sql rename to schema/0013_email.sql diff --git a/schema/010_hashed_text.sql b/schema/0014_hashed_text.sql similarity index 100% rename from schema/010_hashed_text.sql rename to schema/0014_hashed_text.sql diff --git a/schema/020_usr.sql b/schema/0100_usr.sql similarity index 63% rename from schema/020_usr.sql rename to schema/0100_usr.sql index 56390f0..255b614 100644 --- a/schema/020_usr.sql +++ b/schema/0100_usr.sql @@ -33,21 +33,52 @@ create table public.usr , uid uuid not null default gen_random_uuid() , deleted boolean not null default false , tag public.usr_tag not null - , discrim int not null + , discrim int not null default 0 , password public.hashed_text not null , email public.email not null unique , unique (tag, discrim) ); -create function public.usr_tag_count(tag public.usr_tag) returns int language sql stable as $$ - select count(*) from public.usr u where u.tag = tag; +create function public.do_insert_usr_default_discrim() +returns trigger +stable +language plpgsql +as $$ +begin + if new.discrim is null then + new.discrim := (select count(*) from public.usr u where u.tag = tag); + end if; + + return new; +end; $$; -alter table public.usr -alter column discrim set default public.usr_tag_count(tag); +create trigger insert_usr_default_discrim +before insert on public.usr +for each row execute function public.do_insert_usr_default_discrim(); -insert into public.usr (tag, password, email) -values (usr_tag_of_string('system'), hashed_text_of_string(''), email_of_string('')); +insert into public.usr + (tag, password, email) +values + (usr_tag_of_string('root'), hashed_text_of_string(''), email_of_string('')); + +create function public.do_check_usr_tag() +returns trigger +stable +language plpgsql +as $$ +begin + if new.tag = usr_tag_of_string('root') then + raise exception 'invalid tag'; + else + return new; + end if; +end; +$$; + +create trigger check_usr_tag +before insert on public.usr +for each row execute function public.do_check_usr_tag(); select audit( 'public' , 'usr' diff --git a/schema/0101_acting_usr.sql b/schema/0101_acting_usr.sql new file mode 100644 index 0000000..e535900 --- /dev/null +++ b/schema/0101_acting_usr.sql @@ -0,0 +1,34 @@ +create function public.set_acting_usr(uid text) + returns void + language plpgsql + volatile + as $$ +begin + set session "dnim.usr_uid" = uid; +end; +$$; + +create function public.get_acting_usr() + returns public.usr + language plpgsql + volatile +as $$ +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; +$$; diff --git a/schema/021_usr_session.sql b/schema/0102_usr_session.sql similarity index 96% rename from schema/021_usr_session.sql rename to schema/0102_usr_session.sql index ca59aa1..6152e1f 100644 --- a/schema/021_usr_session.sql +++ b/schema/0102_usr_session.sql @@ -60,8 +60,8 @@ begin or u.tag = usr_tag into usr; - if usr.id = 1 or usr.tag = usr_tag_of_string('system') then - raise notice 'system user may not be logged into'; + 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; diff --git a/schema/010_scope.sql b/schema/010_scope.sql deleted file mode 100644 index 7c39d7c..0000000 --- a/schema/010_scope.sql +++ /dev/null @@ -1 +0,0 @@ -select create_newtype_text('public.authz_scope'); diff --git a/schema/0200_community.sql b/schema/0200_community.sql new file mode 100644 index 0000000..238c04b --- /dev/null +++ b/schema/0200_community.sql @@ -0,0 +1,22 @@ +select create_newtype_text('public.community_tag'); + +create table public.community + ( id int not null primary key generated always as identity + , uid uuid not null unique default gen_random_uuid() + , deleted boolean not null default false + , tag public.community_tag not null + ); + +select audit( 'public' + , 'community' + , array[ row('tag', 'public.community_tag') + ] :: audited_column[] + , soft_delete => true + ); + +select immutable( 'public' + , 'community' + , array[ 'id' + , 'uid' + ] + ); diff --git a/schema/021_thread.sql b/schema/0201_thread.sql similarity index 100% rename from schema/021_thread.sql rename to schema/0201_thread.sql diff --git a/schema/020_audit.sql b/schema/020_audit.sql deleted file mode 100644 index 35c5239..0000000 --- a/schema/020_audit.sql +++ /dev/null @@ -1,5 +0,0 @@ -create type public.audit_kind as enum - ( 'modify' - , 'delete' - , 'create' - ); diff --git a/schema/021_community.sql b/schema/021_community.sql deleted file mode 100644 index 0a5e068..0000000 --- a/schema/021_community.sql +++ /dev/null @@ -1,120 +0,0 @@ -select create_newtype_text('public.community_tag'); - -create table public.community - ( id int not null primary key generated always as identity - , uid uuid not null unique default gen_random_uuid() - , deleted boolean not null default false - , tag public.community_tag not null - ); - -select audit( 'public' - , 'community' - , array[ row('tag', 'public.community_tag') - ] :: audited_column[] - , soft_delete => true - ); - -select immutable( 'public' - , 'community' - , array[ 'id' - , 'uid' - ] - ); - -create table public.community_nonmember_scope - ( id int not null primary key generated always as identity - , uid uuid not null unique default gen_random_uuid() - , community int not null references public.community (id) - , scope public.authz_scope not null - , unique (community, scope) - ); - -select audit( 'public' - , 'community_nonmember_scope' - , array[ row('community', 'int') - , row('scope', 'public.authz_scope') - ] :: audited_column[] - , soft_delete => false - ); - -select immutable( 'public' - , 'community_nonmember_scope' - , array[ 'id' - , 'uid' - , 'community' - , 'scope' - ] - ); - -create table public.community_member_role - ( id int not null primary key generated always as identity - , uid uuid not null unique default gen_random_uuid() - , community int not null references public.community (id) - , title text not null - , description text not null - ); - -select audit( 'public' - , 'community_member_role' - , array[ row('title', 'text') - , row('description', 'text') - ] :: audited_column[] - , soft_delete => false - ); - -select immutable( 'public' - , 'community_member_role' - , array[ 'id' - , 'uid' - , 'community' - ] - ); - -create table public.community_member_role_scope - ( id int not null primary key generated always as identity - , uid uuid not null unique default gen_random_uuid() - , role_ int not null references public.community_member_role (id) - , scope public.authz_scope not null - , unique (scope, role_) - ); - -select audit( 'public' - , 'community_member_role_scope' - , array[ row('role_', 'int') - , row('scope', 'public.authz_scope') - ] :: audited_column[] - , soft_delete => false - ); - -select immutable( 'public' - , 'community_member_role_scope' - , array[ 'id' - , 'uid' - , 'role_' - , 'scope' - ] - ); - -create table public.community_member - ( id int not null primary key generated always as identity - , uid uuid not null unique default gen_random_uuid() - , usr int not null references public.usr (id) - , community int not null references public.community (id) - , role_ int not null references public.community_member_role (id) - ); - -select audit( 'public' - , 'community_member' - , array[ row('usr', 'int') - , row('role_', 'int') - ] :: audited_column[] - , soft_delete => false - ); - -select immutable( 'public' - , 'community_member' - , array[ 'id' - , 'uid' - , 'usr' - ] - ); diff --git a/schema/0300_grp.sql b/schema/0300_grp.sql new file mode 100644 index 0000000..36969f7 --- /dev/null +++ b/schema/0300_grp.sql @@ -0,0 +1,50 @@ +select create_newtype_text('public.grp_tag'); + +create table public.grp + ( id int not null primary key generated always as identity + , uid uuid not null default gen_random_uuid() + , deleted boolean not null default false + , tag public.grp_tag not null unique + ); + +insert into public.grp (tag) +values (grp_tag_of_string('admins')); + +create function public.do_grp_add_admins() + returns trigger + volatile + language plpgsql + as $$ +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; +$$; + +create trigger grp_add_admins +after insert on public.grp +for each row +execute function public.do_grp_add_admins(); + +select audit( 'public' + , 'grp' + , array[] :: audited_column[] + , soft_delete => true + ); + +select immutable( 'public' + , 'grp' + , array[ 'id' + , 'uid' + , 'tag' + ] + ); diff --git a/schema/0301_grp_usr.sql b/schema/0301_grp_usr.sql new file mode 100644 index 0000000..aa4d054 --- /dev/null +++ b/schema/0301_grp_usr.sql @@ -0,0 +1,70 @@ +create table public.grp_usr + ( grp int not null references public.grp(id) + , usr int not null references public.usr(id) + , primary key (grp, usr) + ); + +create function public.grp_add_member(to_grp int, add_usr int) + returns void + volatile + language plpgsql + as $$ +begin + insert into public.grp_usr (grp, usr) values (to_grp, add_usr); +end; +$$; + +create function public.grp_add_members(to_grp int, add_usrs int[]) + returns void + volatile + language plpgsql + as $$ +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; +$$; + +create function public.grp_members(of_grp int) + returns setof public.usr + stable + language plpgsql + as $$ +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; +$$; + +create function public.grp_members_admins() + returns setof public.usr + stable + language plpgsql + as $$ +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; +$$; + +create function public.grp_rm_member(from_grp int, rm_usr int) + returns void + volatile + language plpgsql + as $$ +begin + delete from public.grp_usr gu + where gu.grp = from_grp and gu.usr = rm_usr; +end; +$$; diff --git a/schema/0302_default_grps.sql b/schema/0302_default_grps.sql new file mode 100644 index 0000000..2d45743 --- /dev/null +++ b/schema/0302_default_grps.sql @@ -0,0 +1,22 @@ +create function public.do_usr_create_default_grp() + returns trigger + volatile + language plpgsql + as $$ +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; +$$; + +create trigger usr_create_default_grp +after insert on public.usr +for each row +execute function public.do_usr_create_default_grp(); diff --git a/schema/0400_perm.sql b/schema/0400_perm.sql new file mode 100644 index 0000000..b8935de --- /dev/null +++ b/schema/0400_perm.sql @@ -0,0 +1,110 @@ +create type public.perm_mode as enum ('-', 'r', 'w'); + +create table public.perm + ( id int not null primary key generated always as identity + , uid uuid not null default gen_random_uuid() + , owner_user int not null references public.usr(id) + , owner_group int not null references public.grp(id) + , owner_user_mode public.perm_mode not null + , owner_group_mode public.perm_mode not null + , everyone_mode public.perm_mode not null + , path text not null unique + ); + +do language plpgsql $$ +declare + root int; + admins int; +begin + select * from public.usr where tag = usr_tag_of_string('root') into root; + 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 + ('/communities/', root, admins, 'w', 'w', 'r') + , ('/users/', root, admins, 'w', 'w', 'w') + , ('/groups/', root, admins, 'w', 'w', 'w') + ; +end; +$$; + +create function do_insert_usr_perm() returns trigger language plpgsql as $$ +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; +$$; + +create trigger insert_usr_perm +after insert on public.usr +for each row execute function do_insert_usr_perm(); + +create function do_insert_grp_perm() returns trigger language plpgsql as $$ +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; +$$; + +create trigger insert_grp_perm +after insert on public.grp +for each row +execute function do_insert_grp_perm(); + +create function do_insert_community_perm() returns trigger language plpgsql as $$ +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; +$$; + +create trigger insert_community_perm +after insert on public.community +for each row +execute function do_insert_community_perm(); + +select audit( 'public' + , 'perm' + , array[ row('owner_user', 'int') + , row('owner_group', 'int') + , row('owner_user_mode', 'public.perm_mode') + , row('owner_group_mode', 'public.perm_mode') + , row('everyone_mode', 'public.perm_mode') + ] :: audited_column[] + , soft_delete => false + ); + +select immutable( 'public' + , 'perm' + , array[ 'id' + , 'uid' + , 'path' + ] + );