kandimat/backend/sql/04_setup_authentication.sql
Christoph Lienhard 02845e65db Introduce JWT Authentication
Added features:
* register
* authenticate
* RLS as summarized in security_considerations.md

Improve
* Use enhanced graphiql version to be able to set authentication headers

Remove:
* docker-compose.prod.yml since it is not updated for now (and we do not have a production env)
2020-05-31 14:29:17 +02:00

81 lines
2.5 KiB
PL/PgSQL

create extension if not exists "pgcrypto";
-- Define JWT claim structure
create type candymat_data.jwt_token as (
role text,
person_id integer,
exp bigint
);
create function candymat_data.current_person() returns candymat_data.person as $$
select *
from candymat_data.person
where id = nullif(current_setting('jwt.claims.person_id', true), '')::integer
$$ language sql stable;
grant execute on function candymat_data.current_person() to candymat_person;
create function candymat_data.register_person(
first_name text,
last_name text,
email text,
password text
) returns candymat_data.person as $$
declare
person candymat_data.person;
begin
insert into candymat_data.person (first_name, last_name)
values ($1, $2)
returning * into person;
insert into candymat_data_privat.person_account (person_id, email, password_hash)
values (person.id, $3, crypt($4, gen_salt('bf')));
return person;
end;
$$ language plpgsql strict security definer;
grant execute on function candymat_data.register_person(text, text, text, text) to candymat_anonymous;
create function candymat_data.authenticate(
email text,
password text
) returns candymat_data.jwt_token as $$
declare
account candymat_data_privat.person_account;
declare person candymat_data.person;
begin
select a.*
into account
from candymat_data_privat.person_account as a
where a.email = $1;
select p.*
into person
from candymat_data.person as p
where p.id = account.person_id;
if account.password_hash = crypt(password, account.password_hash) then
return (person.role, account.person_id,
extract(epoch from (now() + interval '2 days')))::candymat_data.jwt_token;
else
return null;
end if;
end;
$$ language plpgsql strict security definer;
grant execute on function candymat_data.authenticate(text, text) to candymat_anonymous, candymat_person;
create function candymat_data.change_role(
person_id integer,
new_role candymat_data.role
) returns table(first_name text, last_name text, role candymat_data.role) as $$
begin
update candymat_data.person
set role = new_role
where candymat_data.person.id = $1;
return query select candymat_data.person.first_name::text, candymat_data.person.last_name::text, new_role
from candymat_data.person
where person.id = person_id;
end;
$$ language plpgsql;
grant execute on function candymat_data.change_role(integer, candymat_data.role) to candymat_editor;