kandimat/backend/sql/03_create_content_tables.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

52 lines
2.4 KiB
SQL

-- 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);