./migrations/0b9c597_to_0502154.sql

This commit is contained in:
Orion Kindel 2023-07-17 14:18:47 -04:00
parent 60b0e8d02b
commit d337517f1a
Signed by untrusted user who does not match committer: orion
GPG Key ID: 6D4165AE4C928719

192
0b9c597_to_0502154.sql Normal file
View File

@ -0,0 +1,192 @@
create type "public"."usr_session_device" as enum ('linux', 'macos', 'win', 'android', 'ios', 'other');
create table "public"."usr_session" (
"id" integer generated always as identity not null,
"key" usr_session_key not null default usr_session_key_gen(),
"expired" boolean not null default false,
"expires_at" timestamp without time zone not null,
"usr" integer not null,
"location" text,
"device" usr_session_device,
"ip" inet
);
CREATE UNIQUE INDEX usr_session_key_key ON public.usr_session USING btree (key);
CREATE UNIQUE INDEX usr_session_pkey ON public.usr_session USING btree (id);
alter table "public"."usr_session" add constraint "usr_session_pkey" PRIMARY KEY using index "usr_session_pkey";
alter table "public"."usr_session" add constraint "usr_session_key_key" UNIQUE using index "usr_session_key_key";
alter table "public"."usr_session" add constraint "usr_session_usr_fkey" FOREIGN KEY (usr) REFERENCES usr(id) not valid;
alter table "public"."usr_session" validate constraint "usr_session_usr_fkey";
set check_function_bodies = off;
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 'public.usr_session.id is immutable' using errcode = 'restrict_violation';
elsif OLD.key <> NEW.key then
raise exception 'public.usr_session.key is immutable' using errcode = 'restrict_violation';
elsif OLD.expires_at <> NEW.expires_at then
raise exception 'public.usr_session.expires_at is immutable' using errcode = 'restrict_violation';
elsif OLD.usr <> NEW.usr then
raise exception 'public.usr_session.usr is immutable' using errcode = 'restrict_violation';
elsif OLD.location <> NEW.location then
raise exception 'public.usr_session.location is immutable' using errcode = 'restrict_violation';
elsif OLD.device <> NEW.device then
raise exception 'public.usr_session.device is immutable' using errcode = 'restrict_violation';
elsif OLD.ip <> NEW.ip then
raise exception 'public.usr_session.ip is immutable' using errcode = 'restrict_violation';
end if;
return NEW;
end;
$function$
;
create type "public"."usr_session_key" as ("str" text);
CREATE OR REPLACE FUNCTION public.usr_session_key_gen()
RETURNS usr_session_key
LANGUAGE sql
AS $function$
select usr_session_key_of_string(
md5(extract(epoch from now()) || gen_random_bytes(32) :: text)
);
$function$
;
CREATE OR REPLACE FUNCTION public.usr_session_key_of_string(val text)
RETURNS usr_session_key
LANGUAGE sql
AS $function$select row(val);$function$
;
CREATE OR REPLACE FUNCTION public.usr_session_key_to_string(val usr_session_key)
RETURNS text
LANGUAGE sql
AS $function$select (val.str);$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;
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
(expires_at, usr, location, device, ip)
values
(expires_at, usr.id, location, device, ip)
returning usr_session.key
into key;
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('system') then
raise notice 'system user may not be logged into';
raise exception 'incorrect password for user %', usr_tag_or_email_to_string(tag_or_email);
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 for user %', usr_tag_or_email_to_string(tag_or_email);
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 for user %', usr_tag_or_email_to_string(tag_or_email);
end if;
return usr;
end;
$function$
;
create type "public"."usr_tag_or_email" as ("str" text);
CREATE OR REPLACE FUNCTION public.usr_tag_or_email_of_string(val text)
RETURNS usr_tag_or_email
LANGUAGE sql
AS $function$select row(val);$function$
;
CREATE OR REPLACE FUNCTION public.usr_tag_or_email_to_email(toe usr_tag_or_email)
RETURNS email
LANGUAGE plpgsql
IMMUTABLE
AS $function$
begin
if position('@' in usr_tag_or_email_to_string(toe)) > 0 then
return email_of_string(usr_tag_or_email_to_string(toe));
else
return null;
end if;
end;
$function$
;
CREATE OR REPLACE FUNCTION public.usr_tag_or_email_to_string(val usr_tag_or_email)
RETURNS text
LANGUAGE sql
AS $function$select (val.str);$function$
;
CREATE OR REPLACE FUNCTION public.usr_tag_or_email_to_tag(toe usr_tag_or_email)
RETURNS usr_tag
LANGUAGE plpgsql
IMMUTABLE
AS $function$
begin
if usr_tag_or_email_to_email(toe) is null then
return usr_tag_of_string(usr_tag_or_email_to_string(toe));
else
return null;
end if;
end;
$function$
;
CREATE TRIGGER trigger_usr_session_immutable_columns BEFORE UPDATE ON public.usr_session FOR EACH ROW EXECUTE FUNCTION do_usr_session_immutable_columns();