158 lines
4.0 KiB
PL/PgSQL
158 lines
4.0 KiB
PL/PgSQL
select create_newtype_text('public.usr_session_key');
|
|
|
|
create function usr_session_key_gen()
|
|
returns public.usr_session_key
|
|
volatile
|
|
language sql as $$
|
|
select usr_session_key_of_string(
|
|
md5(extract(epoch from now()) || gen_random_bytes(32) :: text)
|
|
);
|
|
$$;
|
|
|
|
create type usr_session_device as enum
|
|
( 'linux'
|
|
, 'macos'
|
|
, 'win'
|
|
, 'android'
|
|
, 'ios'
|
|
, 'other'
|
|
);
|
|
|
|
create table public.usr_session
|
|
( id int not null primary key generated always as identity
|
|
, key public.usr_session_key not null unique
|
|
, expires_at timestamp not null
|
|
, usr int not null references public.usr (id)
|
|
, remembered boolean not null default false
|
|
, location text null
|
|
, device usr_session_device null
|
|
, ip inet null
|
|
);
|
|
|
|
select immutable( 'public'
|
|
, 'usr_session'
|
|
, array[ 'id'
|
|
, 'key'
|
|
, 'usr'
|
|
, 'location'
|
|
, 'device'
|
|
, 'ip'
|
|
]
|
|
);
|
|
|
|
create function public.usr_session_touch(touch_key public.usr_session_key)
|
|
returns public.usr
|
|
language plpgsql
|
|
volatile
|
|
as $$
|
|
declare
|
|
session public.usr_session;
|
|
session_usr public.usr;
|
|
new_exp timestamp;
|
|
begin
|
|
select s.*
|
|
from public.usr_session s
|
|
where s.key = touch_key
|
|
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 as s
|
|
set 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;
|
|
$$;
|
|
|
|
create function public.usr_session_login_validate
|
|
( tag_or_email public.usr_tag_or_email
|
|
, password text
|
|
)
|
|
returns public.usr
|
|
language plpgsql
|
|
stable
|
|
as $$
|
|
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;
|
|
$$;
|
|
|
|
create function public.usr_session_login
|
|
( tag_or_email public.usr_tag_or_email
|
|
, password text
|
|
, remember boolean default false
|
|
, location text default null
|
|
, device public.usr_session_device default null
|
|
, ip inet default null
|
|
)
|
|
returns public.usr_session_key
|
|
language plpgsql
|
|
volatile
|
|
as $$
|
|
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, coalesce(remember, false), location, device, ip);
|
|
|
|
return key;
|
|
end;
|
|
$$;
|