kandimat/backend/db/sql/03_create_content_tables.sql
2021-06-13 14:24:52 +02:00

52 lines
2.5 KiB
SQL

-- create table for categories
create table candymat_data.category
(
row_id serial primary key,
title character varying(300) UNIQUE NOT NULL check ( title <> '' ),
description character varying(15000)
);
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_row_id_seq to candymat_editor;
-- create table for questions
create table candymat_data.question
(
row_id serial primary key,
category_row_id integer REFERENCES candymat_data.category (row_id) ON UPDATE CASCADE ON DELETE SET NULL,
title character varying(3000) UNIQUE NOT NULL check ( title <> '' ),
description character varying(15000)
);
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_row_id_seq to candymat_editor;
-- create table for answers
create table candymat_data.answer
(
question_row_id integer REFERENCES candymat_data.question (row_id) ON UPDATE CASCADE ON DELETE CASCADE,
person_row_id integer REFERENCES candymat_data.person (row_id) ON UPDATE CASCADE ON DELETE CASCADE,
position integer NOT NULL check (position between 0 and 3),
text character varying(15000),
created_at timestamp default now(),
primary key (question_row_id, person_row_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_row_id = nullif(current_setting('jwt.claims.person_row_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);