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)
This commit is contained in:
Christoph Lienhard 2020-02-02 12:18:23 +01:00 committed by Christoph Lienhard
parent cce047a060
commit 02845e65db
14 changed files with 286 additions and 71 deletions

2
.env
View File

@ -2,4 +2,4 @@ COMPOSE_FILE=docker-compose.dev.yml
COMPOSE_PROJECT_NAME=candymat
#Postgraphile vars
DATABASE_URL=postgres://candymat:postgres!dev@postgres:5432/candymat_db
DATABASE_URL=postgres://candymat_postgraphile:postgres!dev@postgres:5432/candymat_db

View File

@ -1,4 +0,0 @@
POSTGRES_PASSWORD=postgres!dev
POSTGRES_USER=candymat
POSTGRES_DB=candymat_db
POSTGRES_SCHEMA=candymat_data

View File

@ -1,6 +0,0 @@
FROM postgres:11.5
COPY ./sql/* /docker-entrypoint-initdb.d/
RUN localedef -i de_DE -c -f UTF-8 -A /usr/share/locale/locale.alias de_DE.UTF-8
ENV LANG de_DE.utf8

8
backend/backend.env Normal file
View File

@ -0,0 +1,8 @@
# Postgres database setup
POSTGRES_PASSWORD=postgres!dev
POSTGRES_USER=candymat_postgraphile
POSTGRES_DB=candymat_db
POSTGRES_SCHEMA=candymat_data
# postgraphile setup
JWT_SECRET=asdfasdfasdf

View File

@ -0,0 +1,34 @@
## Basic security
Testing the security of the backend is substantial for obvious reasons. Write automated penetration tests.
There should be testcases for
| table | editor | candidate | user(v) | user | other |
|------------|--------|-----------|---------|------|-------|
| person | sdU | sDU | sDU | | |
| account | S | S | S | S | | not sure about this
| answer | s | sDUI | s | | |
| question | sdui | s | s | | |
| categories | sdui | s | s | | |
| function | editor | candidate | user(v) | user | other |
|--------------|--------|-----------|---------|------|-------|
| register | | | | | E |
| authenticate | E | E | E | E | |
| change pw | E | E | E | | |
| change role | e | | | | |
where
* s: select
* d: delete
* u: update
* i: insert
* e: execute
An uppercase version of the above letters means that the operation is only possible on rows directly related to the user id, e.g. a candidate can only delete, update and insert the own answer(s).
## Passwords
DO NOT LOG THE PASSWORDS
postgres logging conf may need adoption to NOT log passwords in plain text.

View File

@ -1,57 +0,0 @@
\connect candymat_db
-- Create schema for candymat_data
CREATE SCHEMA candymat_data;
-- Create table for users
CREATE TABLE candymat_data."user"
(
login character varying(8) primary key,
name character varying(300),
surname character varying(300),
email character varying(320)
);
-- Create table for user groups
CREATE TABLE candymat_data."group"
(
id serial primary key,
name character varying(300) UNIQUE,
access_right character varying(1000)
);
-- Create table for relation of users and groups
CREATE TABLE candymat_data.user_group
(
group_id integer REFERENCES candymat_data."group" (id) ON UPDATE CASCADE ON DELETE CASCADE,
user_login character varying(8) REFERENCES candymat_data."user" (login) ON UPDATE CASCADE ON DELETE CASCADE,
primary key (group_id, user_login)
);
-- Create table for categories
CREATE TABLE candymat_data.category
(
id serial primary key,
title character varying(300) UNIQUE NOT NULL,
description character varying(5000)
);
-- Create table for questions
CREATE TABLE candymat_data.question
(
id serial primary key,
category_id integer REFERENCES candymat_data."category" (id) ON UPDATE CASCADE ON DELETE SET NULL,
text character varying(3000) NOT NULL,
description character varying(5000)
);
-- Create table for answers
CREATE TABLE candymat_data.answer
(
question_id integer REFERENCES candymat_data."question" (id) ON UPDATE CASCADE ON DELETE CASCADE,
user_login character varying(8) REFERENCES candymat_data."user" ON UPDATE CASCADE ON DELETE CASCADE,
position integer NOT NULL,
text character varying(5000),
primary key (question_id, user_login)
);

View File

@ -0,0 +1,28 @@
\connect candymat_db
-- Create schema for candymat_data
create SCHEMA candymat_data;
create SCHEMA candymat_data_privat;
-- create roles
create role candymat_person;
create role candymat_anonymous;
create role candymat_editor;
create role candymat_candidate;
grant candymat_editor to candymat_postgraphile;
grant candymat_candidate to candymat_postgraphile;
grant candymat_person to candymat_postgraphile, candymat_candidate, candymat_editor;
grant candymat_anonymous to candymat_postgraphile;
create type candymat_data.role as enum (
'candymat_editor',
'candymat_candidate',
'candymat_person'
);
-- set table wide permissions
grant usage on schema candymat_data to candymat_anonymous, candymat_person;
-- make functions non executeable w/o further checks
alter default privileges revoke execute on functions from public;

View File

@ -0,0 +1,34 @@
-- create table for users
create table candymat_data.person
(
id serial primary key,
first_name character varying(200),
last_name character varying(200),
about character varying(2000),
created_at timestamp default now(),
role candymat_data.role not null default 'candymat_person'
);
grant select, update, delete on table candymat_data.person to candymat_person;
-- the following is only necessary as long as anonymous should be able to view candidates and editors
grant select on table candymat_data.person to candymat_anonymous;
-- create table for accounts
create table candymat_data_privat.person_account
(
person_id integer primary key references candymat_data.person (id) on delete cascade,
email character varying(320) not null unique check (email ~* '^.+@.+\..+$'),
password_hash character varying(256) not null
);
alter table candymat_data.person
enable row level security;
create policy update_person on candymat_data.person for update to candymat_person
with check (id = nullif(current_setting('jwt.claims.person_id', true), '')::integer);
create policy delete_person on candymat_data.person for delete to candymat_person
using (id = nullif(current_setting('jwt.claims.person_id', true), '')::integer);
-- The following enables viewing candidates and editors information for every person.
-- This may be changed to only enable registered (and verified) persons.
create policy select_person_public
on candymat_data.person
for select
to candymat_anonymous, candymat_person -- maybe change to candymat_person only in the future
using (role in ('candymat_editor', 'candymat_candidate'));

View File

@ -0,0 +1,51 @@
-- create table for categories
create table candymat_data.category
(
id serial primary key,
title character varying(300) UNIQUE NOT NULL,
description character varying(5000)
);
grant select on table candymat_data.category to candymat_person;
-- the following line is only necessary as long as the candymat should be publicly accessible
grant select on table candymat_data.category to candymat_anonymous;
grant insert, update, delete on table candymat_data.category to candymat_editor;
grant usage on sequence candymat_data.category_id_seq to candymat_editor;
-- create table for questions
create table candymat_data.question
(
id serial primary key,
category_id integer REFERENCES candymat_data.category (id) ON UPDATE CASCADE ON DELETE SET NULL,
text character varying(3000) NOT NULL,
description character varying(5000)
);
grant select on table candymat_data.question to candymat_person;
-- the following line is only necessary as long as the candymat should be publicly accessible
grant select on table candymat_data.question to candymat_anonymous;
grant insert, update, delete on table candymat_data.question to candymat_editor;
grant usage on sequence candymat_data.question_id_seq to candymat_editor;
-- create table for answers
create table candymat_data.answer
(
question_id integer REFERENCES candymat_data.question (id) ON UPDATE CASCADE ON DELETE CASCADE,
person_id integer REFERENCES candymat_data.person (id) ON UPDATE CASCADE ON DELETE CASCADE,
position integer NOT NULL,
text character varying(5000),
created_at timestamp default now(),
primary key (question_id, person_id)
);
grant select on table candymat_data.answer to candymat_person;
-- the following line is only necessary as long as the candymat should be publicly accessible
grant select on table candymat_data.answer to candymat_anonymous;
grant insert, update, delete on table candymat_data.answer to candymat_candidate;
alter table candymat_data.answer
enable row level security;
create policy change_answer on candymat_data.answer to candymat_candidate
using (person_id = nullif(current_setting('jwt.claims.person_id', true), '')::integer);
create policy select_answer
on candymat_data.answer
for select
to candymat_anonymous, candymat_person -- maybe change to candymat_person only in the future
using (true);

View File

@ -0,0 +1,80 @@
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;

View File

@ -0,0 +1,30 @@
select candymat_data.register_person(
'Erika',
'Mustermann',
'erika@mustermann.de',
'password'
);
select candymat_data.change_role(
1,
'candymat_editor'
);
select candymat_data.register_person(
'Max',
'Mustermann',
'max@mustermann.de',
'password'
);
select candymat_data.change_role(
2,
'candymat_candidate'
);
select candymat_data.register_person(
'Happy',
'User',
'happy@user.de',
'password'
);
select candymat_data.change_role(
3,
'candymat_person'
);

View File

@ -0,0 +1,5 @@
insert into candymat_data.category (title, description) values
('Umwelt', 'Themen rund um Naturschutz usw.');
insert into candymat_data.question (category_id, text, description) values
(1, 'Was sagen Sie zur 10H Regel?', 'In Bayern dürfen Windräder nur ...');

View File

@ -28,7 +28,7 @@ services:
build:
dockerfile: ./Dockerfile
context: ./backend/
env_file: ./backend/.env-backend
env_file: ./backend/backend.env
ports:
- "5432:5432"
restart: always
@ -42,9 +42,21 @@ services:
image: graphile/postgraphile
depends_on:
- postgres
env_file: ./backend/backend.env
ports:
- "5433:5000"
command: ["--connection", $DATABASE_URL, "--host", "0.0.0.0", "--port", "5000", "--schema", "candymat_data", "--watch"]
command: [
"--connection", $DATABASE_URL,
"--host", "0.0.0.0",
"--port", "5000",
"--schema", "candymat_data",
"--default-role", "candymat_anonymous",
"--jwt-token-identifier", "candymat_data.jwt_token",
"--jwt-secret", $JWT_SECRET,
"--watch",
"--retry-on-init-fail",
"--enhance-graphiql"
]
networks:
- frontend
- backend

View File

@ -6,7 +6,7 @@ import { CustomAppBar } from 'components/CustomAppBar/CustomAppBar';
import { Overview } from 'components/Overview/Overview';
export const dataApi = '/api'
export const dataApi = 'http://localhost:5000/graphql'
const styles = createStyles({