441 lines
14 KiB
PL/PgSQL
441 lines
14 KiB
PL/PgSQL
alter table "public"."usr_session" drop column "expired";
|
|
|
|
alter table "public"."usr_session" add column "remembered" boolean not null default false;
|
|
|
|
set check_function_bodies = off;
|
|
|
|
CREATE OR REPLACE FUNCTION public.usr_session_touch(session usr_session_key)
|
|
RETURNS usr
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
declare
|
|
session public.usr_session;
|
|
session_usr public.usr;
|
|
new_exp timestamp;
|
|
begin
|
|
select s
|
|
from public.usr_session s
|
|
where s.key = session
|
|
into session;
|
|
|
|
if session is null then
|
|
raise exception 'usr_session_invalid';
|
|
end if;
|
|
|
|
if session.expires_at <= now() then
|
|
raise exception 'usr_session_expired';
|
|
end if;
|
|
|
|
if session.remembered then
|
|
new_exp := now() + interval '1 week';
|
|
else
|
|
new_exp := now() + interval '1 hour';
|
|
end if;
|
|
|
|
update public.usr_session s
|
|
set s.expires_at = new_exp
|
|
where s.id = session.id;
|
|
|
|
select u.*
|
|
from public.usr u
|
|
where u.id = session.usr
|
|
into session_usr;
|
|
|
|
return session_usr;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.do_check_usr_tag()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
STABLE
|
|
AS $function$
|
|
begin
|
|
if new.tag = usr_tag_of_string('root') then
|
|
raise exception 'tag_invalid';
|
|
else
|
|
return new;
|
|
end if;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.do_community_immutable_columns()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
begin
|
|
if OLD.id <> NEW.id then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.community.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.community.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.do_grp_immutable_columns()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
begin
|
|
if OLD.id <> NEW.id then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.grp.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.grp.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.tag <> NEW.tag then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.grp.tag is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.do_perm_immutable_columns()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
begin
|
|
if OLD.id <> NEW.id then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.perm.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.perm.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.path <> NEW.path then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.perm.path is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
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 'immutable_field'
|
|
using detail = 'public.thread_attachment_emoji.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment_emoji.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.thread_attachment <> NEW.thread_attachment then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment_emoji.thread_attachment is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.emoji <> NEW.emoji then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment_emoji.emoji is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
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 'immutable_field'
|
|
using detail = 'public.thread_attachment.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.thread <> NEW.thread then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment.thread is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.kind <> NEW.kind then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment.kind is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
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 'immutable_field'
|
|
using detail = 'public.thread_attachment_vote.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment_vote.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.thread_attachment <> NEW.thread_attachment then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment_vote.thread_attachment is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.direction <> NEW.direction then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_attachment_vote.direction is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
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 'immutable_field'
|
|
using detail = 'public.thread_feed.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_feed.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.thread <> NEW.thread then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_feed.thread is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.community <> NEW.community then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread_feed.community is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
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 'immutable_field'
|
|
using detail = 'public.thread.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.kind <> NEW.kind then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.thread.kind is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
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 'immutable_field'
|
|
using detail = 'public.usr.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.uid <> NEW.uid then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr.uid is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.do_usr_session_immutable_columns()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
begin
|
|
if OLD.id <> NEW.id then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.id is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.key <> NEW.key then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.key is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.expires_at <> NEW.expires_at then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.expires_at is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.usr <> NEW.usr then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.usr is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.location <> NEW.location then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.location is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.device <> NEW.device then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.device is immutable',
|
|
errcode = 'restrict_violation';
|
|
elsif OLD.ip <> NEW.ip then
|
|
raise exception 'immutable_field'
|
|
using detail = 'public.usr_session.ip is immutable',
|
|
errcode = 'restrict_violation';
|
|
end if;
|
|
|
|
return NEW;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.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 \'immutable_field\'\n'
|
|
, E' using detail = \'', qualified_name, '.', columns[1], E' is immutable\',\n'
|
|
, E' 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 \'immutable_field\'\n'
|
|
, E' using detail = \'', qualified_name, '.', col, E' is immutable\',\n'
|
|
, E' 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 OR REPLACE FUNCTION public.usr_session_login(tag_or_email usr_tag_or_email, password text, remember boolean DEFAULT false, location text DEFAULT NULL::text, device usr_session_device DEFAULT NULL::usr_session_device, ip inet DEFAULT NULL::inet)
|
|
RETURNS usr_session_key
|
|
LANGUAGE plpgsql
|
|
AS $function$
|
|
declare
|
|
usr public.usr;
|
|
key public.usr_session_key := usr_session_key_gen();
|
|
expires_at timestamp;
|
|
begin
|
|
usr := public.usr_session_login_validate(tag_or_email, password);
|
|
|
|
if remember then
|
|
expires_at := now() + interval '1 week';
|
|
else
|
|
expires_at := now() + interval '1 hour';
|
|
end if;
|
|
|
|
insert into public.usr_session
|
|
(key, expires_at, usr, remembered, location, device, ip)
|
|
values
|
|
(key, expires_at, usr.id, remember, location, device, ip);
|
|
|
|
return key;
|
|
end;
|
|
$function$
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION public.usr_session_login_validate(tag_or_email usr_tag_or_email, password text)
|
|
RETURNS usr
|
|
LANGUAGE plpgsql
|
|
STABLE
|
|
AS $function$
|
|
declare
|
|
usr_email public.email := public.usr_tag_or_email_to_email(tag_or_email);
|
|
usr_tag public.usr_tag := public.usr_tag_or_email_to_tag(tag_or_email);
|
|
usr public.usr;
|
|
begin
|
|
select *
|
|
from public.usr as u
|
|
where u.email = usr_email
|
|
or u.tag = usr_tag
|
|
into usr;
|
|
|
|
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';
|
|
end if;
|
|
|
|
if usr is null then
|
|
-- prevent email guess bruteforces by raising the same exception
|
|
-- for invalid password and user not found
|
|
raise notice 'user % not found', usr_tag_or_email_to_string(tag_or_email);
|
|
raise exception 'incorrect_password';
|
|
end if;
|
|
|
|
if not hashed_text_matches(password, usr.password) then
|
|
raise notice 'password does not match for user %', usr_tag_or_email_to_string(tag_or_email);
|
|
raise exception 'incorrect_password';
|
|
end if;
|
|
|
|
return usr;
|
|
end;
|
|
$function$
|
|
;
|