diff --git a/schema/000_audit_and_soft_delete.sql b/schema/000_audit_and_soft_delete.sql index f530123..e91201c 100644 --- a/schema/000_audit_and_soft_delete.sql +++ b/schema/000_audit_and_soft_delete.sql @@ -99,8 +99,8 @@ create function setup_audit_and_soft_delete( schema text create_do_table_audit := concat( create_do_table_audit , E' end if;\n' - , E' insert into public.usr_audit\n' - , E' (kind, usr, actor' + , E' insert into ', audit_table, E'\n' + , ' (kind, ', table_, ', actor' ); foreach col in array tracked_columns loop @@ -216,8 +216,8 @@ create function setup_audit_and_hard_delete( schema text create_do_table_audit := concat( create_do_table_audit , E' end if;\n' - , E' insert into public.usr_audit\n' - , E' (kind, usr, actor' + , E' insert into ', audit_table, E'\n' + , ' (kind, ', table_, ', actor' ); foreach col in array tracked_columns loop diff --git a/schema/020_user.sql b/schema/020_user.sql index 94dd952..7b1f3ab 100644 --- a/schema/020_user.sql +++ b/schema/020_user.sql @@ -9,6 +9,10 @@ create table public.usr , email public.email not null unique ); +insert into public.usr (tag, password, email) +overriding system value +values (usr_tag_of_string('system'), hashed_text_of_string(''), email_of_string('')); + select audit( 'public' , 'usr' , array[ row('tag', 'public.usr_tag') diff --git a/schema/021_community.sql b/schema/021_community.sql index e4e4ecd..3235a9b 100644 --- a/schema/021_community.sql +++ b/schema/021_community.sql @@ -10,7 +10,6 @@ create table public.community select audit( 'public' , 'community' , array[ row('tag', 'public.community_tag') - , row('role_nonmember', 'int') ] :: audited_column[] , soft_delete => true ); @@ -50,6 +49,7 @@ select immutable( 'public' 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 ); @@ -66,6 +66,7 @@ select immutable( 'public' , 'community_member_role' , array[ 'id' , 'uid' + , 'community' ] ); @@ -95,10 +96,11 @@ select immutable( 'public' ); 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) - , role_ int not null references public.community_member_role (id) + ( 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' diff --git a/test.sql b/test.sql new file mode 100644 index 0000000..4798122 --- /dev/null +++ b/test.sql @@ -0,0 +1,87 @@ +create or replace function test_schema() returns void language plpgsql as $$ +declare + usr_id_foo int; + usr_id_bar int; + usr_id_baz int; + comm_id_ask_dnim int; + comm_id_pics int; +begin + insert into public.usr + ( tag -- public.usr_tag + , password -- public.hashed_text + , email -- public.email + ) + values + (usr_tag_of_string('foo'), hash_text('password123'), email_of_string('foo@gmail.com')) + , (usr_tag_of_string('bar'), hash_text('password243'), email_of_string('bar@gmail.com')) + , (usr_tag_of_string('baz'), hash_text('hunter2'), email_of_string('baz@gmail.com')) + ; + + insert into public.community + ( tag -- public.community_tag + ) + values + (community_tag_of_string('ask_dnim')) + , (community_tag_of_string('pics')); + + insert into public.community_member_role (community, title, description) + select comm.id, role_.title, role_.description + from community comm + , ( values ('owner', 'community owner') + , ('member', 'community member') + ) as role_ (title, description) + ; + + insert into public.community_member_role_scope (role_, scope) + select role.id, s.scope + from public.community_member_role as role + , ( values (authz_scope_of_string('threads.read')) + , (authz_scope_of_string('threads.create')) + , (authz_scope_of_string('threads.update')) + , (authz_scope_of_string('threads.delete')) + , (authz_scope_of_string('members.read')) + , (authz_scope_of_string('members.create')) + , (authz_scope_of_string('members.delete')) + , (authz_scope_of_string('roles.read')) + , (authz_scope_of_string('roles.create')) + , (authz_scope_of_string('roles.update')) + , (authz_scope_of_string('roles.delete')) + , (authz_scope_of_string('update')) + , (authz_scope_of_string('delete')) + ) as s (scope) + where role.title = 'owner'; + + insert into public.community_member_role_scope (role_, scope) + select role.id, s.scope + from public.community_member_role as role + , ( values (authz_scope_of_string('threads.read')) + , (authz_scope_of_string('threads.create')) + , (authz_scope_of_string('members.read')) + ) as s (scope) + where role.title = 'member'; + + insert into public.community_member (community, usr, role_) + select comm.id, u.id, role_.id + from community comm + inner join usr u on u.tag = usr_tag_of_string('foo') + inner join community_member_role role_ on role_.community = comm.id and role_.title = 'owner' + where comm.tag = community_tag_of_string('ask_dnim'); + + insert into public.community_member (community, usr, role_) + select comm.id, u.id, role_.id + from community comm + inner join usr u on u.tag = usr_tag_of_string('bar') + inner join community_member_role role_ on role_.community = comm.id and role_.title = 'member' + where comm.tag = community_tag_of_string('ask_dnim'); + + insert into public.community_member (community, usr, role_) + select comm.id, u.id, role_.id + from community comm + inner join usr u on u.tag = usr_tag_of_string('baz') + inner join community_member_role role_ on role_.community = comm.id and role_.title = 'member' + where comm.tag = community_tag_of_string('ask_dnim'); +end; +$$; + +select test_schema(); +drop function test_schema;