feat: community
This commit is contained in:
parent
9bec5eadd8
commit
2cf11bcb2b
@ -1,5 +1,17 @@
|
|||||||
create type audited_column as (column_ text, type_ text);
|
create type audited_column as (column_ text, type_ text);
|
||||||
|
|
||||||
|
create function audit(schema text, table_ text, tracked_columns audited_column[], soft_delete boolean)
|
||||||
|
returns void
|
||||||
|
language plpgsql as $$
|
||||||
|
begin
|
||||||
|
if soft_delete then
|
||||||
|
perform setup_audit_and_soft_delete(schema, table_, tracked_columns);
|
||||||
|
else
|
||||||
|
perform setup_audit_and_hard_delete(schema, table_, tracked_columns);
|
||||||
|
end if;
|
||||||
|
end;
|
||||||
|
$$;
|
||||||
|
|
||||||
create function setup_audit_and_soft_delete( schema text
|
create function setup_audit_and_soft_delete( schema text
|
||||||
, table_ text
|
, table_ text
|
||||||
, tracked_columns audited_column[]
|
, tracked_columns audited_column[]
|
||||||
@ -132,3 +144,116 @@ create function setup_audit_and_soft_delete( schema text
|
|||||||
execute create_trigger_table_soft_delete;
|
execute create_trigger_table_soft_delete;
|
||||||
end;
|
end;
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
create function setup_audit_and_hard_delete( schema text
|
||||||
|
, table_ text
|
||||||
|
, tracked_columns audited_column[]
|
||||||
|
)
|
||||||
|
returns void
|
||||||
|
language plpgsql as $$
|
||||||
|
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 public.usr_audit\n'
|
||||||
|
, E' (kind, usr, 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, 1'
|
||||||
|
);
|
||||||
|
|
||||||
|
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;
|
||||||
|
$$;
|
||||||
|
@ -1,4 +1,4 @@
|
|||||||
create function mark_columns_immutable(schema text, table_ text, columns text[])
|
create function immutable(schema text, table_ text, columns text[])
|
||||||
returns void
|
returns void
|
||||||
language plpgsql
|
language plpgsql
|
||||||
as $$
|
as $$
|
||||||
|
1
schema/010_scope.sql
Normal file
1
schema/010_scope.sql
Normal file
@ -0,0 +1 @@
|
|||||||
|
select create_newtype_text('public.authz_scope');
|
@ -1,25 +1,26 @@
|
|||||||
select create_newtype_text('public.usr_username');
|
select create_newtype_text('public.usr_tag');
|
||||||
|
|
||||||
create table public.usr
|
create table public.usr
|
||||||
( id int not null primary key generated always as identity
|
( id int not null primary key generated always as identity
|
||||||
, uid uuid not null default gen_random_uuid()
|
, uid uuid not null default gen_random_uuid()
|
||||||
, deleted boolean not null default false
|
, deleted boolean not null default false
|
||||||
, username public.usr_username not null
|
, tag public.usr_tag not null
|
||||||
, password public.hashed_text not null
|
, password public.hashed_text not null
|
||||||
, email public.email not null unique
|
, email public.email not null unique
|
||||||
);
|
);
|
||||||
|
|
||||||
select setup_audit_and_soft_delete( 'public'
|
select audit( 'public'
|
||||||
, 'usr'
|
, 'usr'
|
||||||
, array[ row('username', 'public.usr_username')
|
, array[ row('tag', 'public.usr_tag')
|
||||||
, row('password', 'public.hashed_text')
|
, row('password', 'public.hashed_text')
|
||||||
, row('email', 'public.email')
|
, row('email', 'public.email')
|
||||||
] :: audited_column[]
|
] :: audited_column[]
|
||||||
);
|
, soft_delete => true
|
||||||
|
);
|
||||||
|
|
||||||
select mark_columns_immutable( 'public'
|
select immutable( 'public'
|
||||||
, 'usr'
|
, 'usr'
|
||||||
, array[ 'id'
|
, array[ 'id'
|
||||||
, 'uid'
|
, 'uid'
|
||||||
]
|
]
|
||||||
);
|
);
|
||||||
|
119
schema/021_community.sql
Normal file
119
schema/021_community.sql
Normal file
@ -0,0 +1,119 @@
|
|||||||
|
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')
|
||||||
|
, row('role_nonmember', 'int')
|
||||||
|
] :: 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()
|
||||||
|
, 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'
|
||||||
|
]
|
||||||
|
);
|
||||||
|
|
||||||
|
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)
|
||||||
|
, 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'
|
||||||
|
]
|
||||||
|
);
|
||||||
|
|
@ -15,8 +15,8 @@ create table public.thread
|
|||||||
, kind public.thread_kind not null
|
, kind public.thread_kind not null
|
||||||
);
|
);
|
||||||
|
|
||||||
select setup_audit_and_soft_delete('public', 'thread', array[] :: audited_column[]);
|
select audit('public', 'thread', array[] :: audited_column[], soft_delete => true);
|
||||||
select mark_columns_immutable('public', 'thread', array['id', 'uid', 'kind']);
|
select immutable('public', 'thread', array['id', 'uid', 'kind']);
|
||||||
|
|
||||||
create table public.thread_feed
|
create table public.thread_feed
|
||||||
( id int not null primary key generated always as identity
|
( id int not null primary key generated always as identity
|
||||||
@ -26,8 +26,8 @@ create table public.thread_feed
|
|||||||
-- , community int not null references public.community(id)
|
-- , community int not null references public.community(id)
|
||||||
);
|
);
|
||||||
|
|
||||||
select setup_audit_and_soft_delete('public', 'thread_feed', array[] :: audited_column[]);
|
select audit('public', 'thread_feed', array[] :: audited_column[], soft_delete => true);
|
||||||
select mark_columns_immutable('public', 'thread_feed', array['id', 'uid', 'thread', 'community']);
|
select immutable('public', 'thread_feed', array['id', 'uid', 'thread', 'community']);
|
||||||
|
|
||||||
create type public.thread_attachment_kind as enum
|
create type public.thread_attachment_kind as enum
|
||||||
( 'vote'
|
( 'vote'
|
||||||
@ -46,8 +46,8 @@ create table public.thread_attachment
|
|||||||
, kind public.thread_attachment_kind not null
|
, kind public.thread_attachment_kind not null
|
||||||
);
|
);
|
||||||
|
|
||||||
select setup_audit_and_soft_delete('public', 'thread_attachment', array[] :: audited_column[]);
|
select audit('public', 'thread_attachment', array[] :: audited_column[], soft_delete => true);
|
||||||
select mark_columns_immutable('public', 'thread_attachment', array['id', 'uid', 'thread', 'kind']);
|
select immutable('public', 'thread_attachment', array['id', 'uid', 'thread', 'kind']);
|
||||||
|
|
||||||
create table public.thread_attachment_emoji
|
create table public.thread_attachment_emoji
|
||||||
( id int not null primary key generated always as identity
|
( id int not null primary key generated always as identity
|
||||||
@ -56,8 +56,8 @@ create table public.thread_attachment_emoji
|
|||||||
, emoji text not null
|
, emoji text not null
|
||||||
);
|
);
|
||||||
|
|
||||||
select setup_audit_and_soft_delete('public', 'thread_attachment_emoji', array[] :: audited_column[]);
|
select audit('public', 'thread_attachment_emoji', array[] :: audited_column[], soft_delete => true);
|
||||||
select mark_columns_immutable('public', 'thread_attachment_emoji', array['id', 'uid', 'thread_attachment', 'emoji']);
|
select immutable('public', 'thread_attachment_emoji', array['id', 'uid', 'thread_attachment', 'emoji']);
|
||||||
|
|
||||||
create table public.thread_attachment_vote
|
create table public.thread_attachment_vote
|
||||||
( id int not null primary key generated always as identity
|
( id int not null primary key generated always as identity
|
||||||
@ -66,5 +66,5 @@ create table public.thread_attachment_vote
|
|||||||
, direction public.thread_attachment_vote_direction not null
|
, direction public.thread_attachment_vote_direction not null
|
||||||
);
|
);
|
||||||
|
|
||||||
select setup_audit_and_soft_delete('public', 'thread_attachment_vote', array[] :: audited_column[]);
|
select audit('public', 'thread_attachment_vote', array[] :: audited_column[], soft_delete => true);
|
||||||
select mark_columns_immutable('public', 'thread_attachment_vote', array['id', 'uid', 'thread_attachment', 'direction']);
|
select immutable('public', 'thread_attachment_vote', array['id', 'uid', 'thread_attachment', 'direction']);
|
||||||
|
Loading…
Reference in New Issue
Block a user