diff --git a/app/dbConfig.js b/app/dbConfig.js new file mode 100644 index 0000000..5325e92 --- /dev/null +++ b/app/dbConfig.js @@ -0,0 +1,9 @@ +const config = { + database: process.env.POSTGRES_DB, + user: process.env.POSTGRES_USER, + password: process.env.POSTGRES_PASSWORD, + host: process.env.POSTGRES_HOST, + port: parseInt(process.env.POSTGRES_PORT) +}; + +export default config; diff --git a/app/migrate.js b/app/migrate.js index e75207b..4f932ea 100644 --- a/app/migrate.js +++ b/app/migrate.js @@ -1,17 +1,10 @@ const { createDb, migrate } = require('postgres-migrations'); - -const config = { - database: process.env.POSTGRES_DB, - user: process.env.POSTGRES_USER, - password: process.env.POSTGRES_PASSWORD, - host: process.env.POSTGRES_HOST, - port: parseInt(process.env.POSTGRES_PORT), -}; +const config = require('./dbConfig'); async function doMigration() { await createDb(process.env.POSTGRES_DB, { ...config, - defaultDatabase: process.env.POSTGRES_DB, + defaultDatabase: process.env.POSTGRES_DB }); await migrate(config, '/app/migrations'); } diff --git a/app/migrations/0001-subzero.sql b/app/migrations/0001-subzero.sql new file mode 100644 index 0000000..ce18554 --- /dev/null +++ b/app/migrations/0001-subzero.sql @@ -0,0 +1,170 @@ +-- adapted from https://github.com/subzerocloud/subzero-starter-kit + + +drop schema if exists request cascade; +create schema request; +grant usage on schema request to public; + +create or replace function request.env_var(v text) returns text as $$ + select current_setting(v, true); +$$ stable language sql; + +create or replace function request.jwt_claim(c text) returns text as $$ + select request.env_var('request.jwt.claim.' || c); +$$ stable language sql; + +create or replace function request.cookie(c text) returns text as $$ + select request.env_var('request.cookie.' || c); +$$ stable language sql; + +create or replace function request.header(h text) returns text as $$ + select request.env_var('request.header.' || h); +$$ stable language sql; + +create or replace function request.user_id() returns int as $$ + select + case coalesce(request.jwt_claim('user_id'),'') + when '' then 0 + else request.jwt_claim('user_id')::int + end +$$ stable language sql; + +create or replace function request.user_role() returns text as $$ + select request.jwt_claim('role')::text; +$$ stable language sql; + +drop schema if exists response cascade; +create schema response; +grant usage on schema response to public; + + +create or replace function response.get_cookie_string(name text, value text, expires_after int, path text) returns text as $$ + with vars as ( + select + case + when expires_after > 0 + then current_timestamp + (expires_after::text||' seconds')::interval + else timestamp 'epoch' + end as expires_on + ) + select + name ||'=' || value || '; ' || + 'Expires=' || to_char(expires_on, 'Dy, DD Mon YYYY HH24:MI:SS GMT') || '; ' || + 'Max-Age=' || expires_after::text || '; ' || + 'Path=' ||path|| '; HttpOnly' + from vars; +$$ stable language sql; + +create or replace function response.set_header(name text, value text) returns void as $$ + select set_config( + 'response.headers', + jsonb_insert( + (case coalesce(current_setting('response.headers',true),'') + when '' then '[]' + else current_setting('response.headers') + end)::jsonb, + '{0}'::text[], + jsonb_build_object(name, value))::text, + true + ); +$$ stable language sql; + +create or replace function response.set_cookie(name text, value text, expires_after int, path text) returns void as $$ + select response.set_header('Set-Cookie', response.get_cookie_string(name, value, expires_after, path)); +$$ stable language sql; + +create or replace function response.delete_cookie(name text) returns void as $$ + select response.set_header('Set-Cookie', response.get_cookie_string(name, 'deleted', 0 ,'/')); +$$ stable language sql; + +-- addapted from https://github.com/michelp/pgjwt +-- license follows + +-- The MIT License (MIT) + +-- Copyright (c) 2016 Michel Pelletier + +-- Permission is hereby granted, free of charge, to any person obtaining a copy +-- of this software and associated documentation files (the "Software"), to deal +-- in the Software without restriction, including without limitation the rights +-- to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +-- copies of the Software, and to permit persons to whom the Software is +-- furnished to do so, subject to the following conditions: + +-- The above copyright notice and this permission notice shall be included in all +-- copies or substantial portions of the Software. + +-- THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +-- IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +-- FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +-- AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +-- LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +-- OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE +-- SOFTWARE. + + +create extension if not exists pgcrypto; +drop schema if exists pgjwt cascade; +create schema pgjwt; +set search_path to pgjwt, public; + +CREATE OR REPLACE FUNCTION url_encode(data bytea) RETURNS text LANGUAGE sql AS $$ + SELECT translate(encode(data, 'base64'), E'+/=\n', '-_'); +$$; + + +CREATE OR REPLACE FUNCTION url_decode(data text) RETURNS bytea LANGUAGE sql AS $$ +WITH t AS (SELECT translate(data, '-_', '+/')), + rem AS (SELECT length((SELECT * FROM t)) % 4) -- compute padding size + SELECT decode( + (SELECT * FROM t) || + CASE WHEN (SELECT * FROM rem) > 0 + THEN repeat('=', (4 - (SELECT * FROM rem))) + ELSE '' END, + 'base64'); +$$; + + +CREATE OR REPLACE FUNCTION algorithm_sign(signables text, secret text, algorithm text) +RETURNS text LANGUAGE sql AS $$ +WITH + alg AS ( + SELECT CASE + WHEN algorithm = 'HS256' THEN 'sha256' + WHEN algorithm = 'HS384' THEN 'sha384' + WHEN algorithm = 'HS512' THEN 'sha512' + ELSE '' END) -- hmac throws error +SELECT pgjwt.url_encode(public.hmac(signables, secret, (select * FROM alg))); +$$; + + +CREATE OR REPLACE FUNCTION sign(payload json, secret text, algorithm text DEFAULT 'HS256') +RETURNS text LANGUAGE sql AS $$ +WITH + header AS ( + SELECT pgjwt.url_encode(convert_to('{"alg":"' || algorithm || '","typ":"JWT"}', 'utf8')) + ), + payload AS ( + SELECT pgjwt.url_encode(convert_to(payload::text, 'utf8')) + ), + signables AS ( + SELECT (SELECT * FROM header) || '.' || (SELECT * FROM payload) + ) +SELECT + (SELECT * FROM signables) + || '.' || + pgjwt.algorithm_sign((SELECT * FROM signables), secret, algorithm); +$$; + + +CREATE OR REPLACE FUNCTION verify(token text, secret text, algorithm text DEFAULT 'HS256') +RETURNS table(header json, payload json, valid boolean) LANGUAGE sql AS $$ + SELECT + convert_from(pgjwt.url_decode(r[1]), 'utf8')::json AS header, + convert_from(pgjwt.url_decode(r[2]), 'utf8')::json AS payload, + r[3] = pgjwt.algorithm_sign(r[1] || '.' || r[2], secret, algorithm) AS valid + FROM regexp_split_to_array(token, '\.') r; +$$; + + +SET search_path TO public; diff --git a/app/migrations/0001-tables.sql b/app/migrations/0001-tables.sql deleted file mode 100644 index aa0bbc6..0000000 --- a/app/migrations/0001-tables.sql +++ /dev/null @@ -1,61 +0,0 @@ -CREATE EXTENSION IF NOT EXISTS pgcrypto; - -CREATE TABLE IF NOT EXISTS player ( - id SERIAL PRIMARY KEY, - email VARCHAR(255) UNIQUE NOT NULL, - ipaddr inet NOT NULL, - password TEXT NOT NULL, - display_name VARCHAR(32) NOT NULL, - banned BOOLEAN NOT NULL DEFAULT false -); - -CREATE TABLE IF NOT EXISTS quiz ( - id SERIAL PRIMARY KEY, - creator INTEGER REFERENCES player(id) ON DELETE CASCADE, - name VARCHAR(255) NOT NULL -); - -CREATE TABLE IF NOT EXISTS quiz_round ( - id SERIAL PRIMARY KEY, - quiz_id INTEGER REFERENCES quiz(id) ON DELETE CASCADE, - round_no SMALLINT NOT NULL DEFAULT 1, - UNIQUE(quiz_id, round_no) -); - -CREATE TABLE IF NOT EXISTS question ( - id SERIAL PRIMARY KEY, - round_id INTEGER REFERENCES quiz_round(id) ON DELETE CASCADE, - question TEXT, - question_no SMALLINT NOT NULL DEFAULT 1, - UNIQUE(round_id, question_no) -); - -CREATE TABLE IF NOT EXISTS answer ( - id SERIAL PRIMARY KEY, - question_id INTEGER REFERENCES question(id) ON DELETE CASCADE, - answer TEXT, - points SMALLINT -); - -CREATE TABLE IF NOT EXISTS game ( - id SERIAL PRIMARY KEY, - quiz_id INTEGER REFERENCES quiz(id) ON DELETE CASCADE, - code uuid NOT NULL DEFAULT gen_random_uuid(), - completed BOOLEAN NOT NULL DEFAULT false -); - -CREATE TABLE IF NOT EXISTS game_participant ( - id SERIAL PRIMARY KEY, - game_id INTEGER REFERENCES game(id) ON DELETE CASCADE, - player_id INTEGER REFERENCES player(id) ON DELETE CASCADE, - score INTEGER NOT NULL DEFAULT 0 -); - -CREATE TABLE IF NOT EXISTS participant_response ( - id SERIAL PRIMARY KEY, - answer_id INTEGER REFERENCES answer(id) ON DELETE CASCADE, - participant_id INTEGER REFERENCES game_participant(id) ON DELETE CASCADE, - response TEXT -); - -CREATE TYPE player_result AS (id integer, email VARCHAR(255), display_name VARCHAR(32)); diff --git a/app/migrations/0002-functions.sql b/app/migrations/0002-functions.sql index 278098d..21d5737 100644 --- a/app/migrations/0002-functions.sql +++ b/app/migrations/0002-functions.sql @@ -1,10 +1,10 @@ -CREATE OR REPLACE FUNCTION ip_banned(u_ipaddr inet) RETURNS boolean AS $$ +CREATE OR REPLACE FUNCTION api.ip_banned(u_ipaddr inet) RETURNS boolean AS $$ SELECT EXISTS(SELECT 1 FROM player p WHERE p.ipaddr = u_ipaddr AND p.banned IS true); $$ LANGUAGE SQL STABLE; -CREATE OR REPLACE FUNCTION new_player( +CREATE OR REPLACE FUNCTION api.new_player( u_email VARCHAR(255), u_password TEXT, u_ipaddr inet, u_display_name VARCHAR(32) -) RETURNS player_result AS $$ +) RETURNS api.player_result AS $$ DECLARE is_banned boolean; banned_user player_result = (-1, '', ''); @@ -29,7 +29,7 @@ BEGIN END; $$ LANGUAGE plpgsql VOLATILE; -CREATE OR REPLACE FUNCTION delete_user(email VARCHAR(255), u_ipaddr inet) RETURNS boolean AS $$ +CREATE OR REPLACE FUNCTION api.delete_user(email VARCHAR(255), u_ipaddr inet) RETURNS boolean AS $$ DECLARE u record; BEGIN IF ip_banned(u_ipaddr) THEN @@ -46,7 +46,7 @@ BEGIN END; $$ LANGUAGE plpgsql VOLATILE; -CREATE OR REPLACE FUNCTION draft_game(data json) RETURNS integer AS $$ +CREATE OR REPLACE FUNCTION api.draft_game(data json) RETURNS integer AS $$ DECLARE questions json; q_id integer; @@ -78,7 +78,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION user_answers(data json) RETURNS boolean AS $$ +CREATE OR REPLACE FUNCTION api.user_answers(data json) RETURNS boolean AS $$ DECLARE p_id integer; key text; @@ -92,7 +92,7 @@ BEGIN END; $$ LANGUAGE plpgsql VOLATILE; -CREATE OR REPLACE FUNCTION host_game(data json) RETURNS uuid AS $$ +CREATE OR REPLACE FUNCTION api.host_game(data json) RETURNS uuid AS $$ DECLARE user_id integer; game_id integer; @@ -109,7 +109,7 @@ BEGIN END; $$ LANGUAGE plpgsql VOLATILE; -CREATE OR REPLACE FUNCTION update_game(data json) RETURNS boolean AS $$ +CREATE OR REPLACE FUNCTION api.update_game(data json) RETURNS boolean AS $$ DECLARE questions json; creator_id integer; diff --git a/app/migrations/0002-tables.sql b/app/migrations/0002-tables.sql new file mode 100644 index 0000000..68bb441 --- /dev/null +++ b/app/migrations/0002-tables.sql @@ -0,0 +1,67 @@ +CREATE EXTENSION IF NOT EXISTS pgcrypto; + +DROP SCHEMA IF EXISTS api; + +CREATE TABLE IF NOT EXISTS api.player ( + id SERIAL PRIMARY KEY, + email VARCHAR(255) UNIQUE NOT NULL, + ipaddr inet NOT NULL, + password TEXT NOT NULL, + display_name VARCHAR(32) NOT NULL, + banned BOOLEAN NOT NULL DEFAULT false +); + +CREATE TABLE IF NOT EXISTS api.quiz ( + id SERIAL PRIMARY KEY, + creator INTEGER REFERENCES api.player(id) ON DELETE CASCADE, + name VARCHAR(255) NOT NULL +); + +CREATE TABLE IF NOT EXISTS api.quiz_round ( + id SERIAL PRIMARY KEY, + quiz_id INTEGER REFERENCES api.quiz(id) ON DELETE CASCADE, + round_no SMALLINT NOT NULL DEFAULT 1, + UNIQUE(quiz_id, round_no) +); + +CREATE TABLE IF NOT EXISTS api.question ( + id SERIAL PRIMARY KEY, + round_id INTEGER REFERENCES api.quiz_round(id) ON DELETE CASCADE, + question TEXT, + question_no SMALLINT NOT NULL DEFAULT 1, + UNIQUE(round_id, question_no) +); + +CREATE TABLE IF NOT EXISTS api.answer ( + id SERIAL PRIMARY KEY, + question_id INTEGER REFERENCES api.question(id) ON DELETE CASCADE, + answer TEXT, + points SMALLINT +); + +CREATE TABLE IF NOT EXISTS api.game ( + id SERIAL PRIMARY KEY, + quiz_id INTEGER REFERENCES api.quiz(id) ON DELETE CASCADE, + code uuid NOT NULL DEFAULT gen_random_uuid(), + completed BOOLEAN NOT NULL DEFAULT false +); + +CREATE TABLE IF NOT EXISTS api.game_participant ( + id SERIAL PRIMARY KEY, + game_id INTEGER REFERENCES api.game(id) ON DELETE CASCADE, + player_id INTEGER REFERENCES api.player(id) ON DELETE CASCADE, + score INTEGER NOT NULL DEFAULT 0 +); + +CREATE TABLE IF NOT EXISTS participant_response ( + id SERIAL PRIMARY KEY, + answer_id INTEGER REFERENCES api.answer(id) ON DELETE CASCADE, + participant_id INTEGER REFERENCES api.game_participant(id) ON DELETE CASCADE, + response TEXT +); + +CREATE TYPE api.player_result AS (id integer, email VARCHAR(255), display_name VARCHAR(32)); + +CREATE TABLE IF NOT EXISTS public.jwt_secret ( + secret TEXT +); diff --git a/app/migrations/0003-functions.sql b/app/migrations/0003-functions.sql new file mode 100644 index 0000000..21d5737 --- /dev/null +++ b/app/migrations/0003-functions.sql @@ -0,0 +1,176 @@ +CREATE OR REPLACE FUNCTION api.ip_banned(u_ipaddr inet) RETURNS boolean AS $$ + SELECT EXISTS(SELECT 1 FROM player p WHERE p.ipaddr = u_ipaddr AND p.banned IS true); +$$ LANGUAGE SQL STABLE; + +CREATE OR REPLACE FUNCTION api.new_player( + u_email VARCHAR(255), u_password TEXT, u_ipaddr inet, u_display_name VARCHAR(32) +) RETURNS api.player_result AS $$ +DECLARE + is_banned boolean; + banned_user player_result = (-1, '', ''); + u RECORD; + new_user player_result; +BEGIN + SELECT ip_banned(u_ipaddr) INTO is_banned; + IF is_banned THEN + RETURN banned_user; + ELSE + SELECT p.* INTO u FROM player p WHERE p.email = u_email; + IF NOT FOUND THEN + INSERT INTO player (email, ipaddr, password, display_name) + VALUES (u_email, u_ipaddr, crypt(u_password, gen_salt('md5')), u_display_name) + RETURNING player.id, player.email, player.display_name INTO new_user; + RETURN new_user; + ELSIF u.banned IS false AND u.password = (SELECT crypt(u_password, u.password)) THEN + RETURN (u.id, u.email, u.display_name); + ELSE RETURN banned_user; + END IF; + END IF; +END; +$$ LANGUAGE plpgsql VOLATILE; + +CREATE OR REPLACE FUNCTION api.delete_user(email VARCHAR(255), u_ipaddr inet) RETURNS boolean AS $$ +DECLARE u record; +BEGIN + IF ip_banned(u_ipaddr) THEN + RETURN false; + ELSE + SELECT p.* INTO u FROM player p WHERE p.email = email; + IF NOT FOUND THEN + RETURN false; + ELSIF u.banned IS false THEN + DELETE FROM player p WHERE p.id = u.id; + RETURN true; + END IF; + END IF; +END; +$$ LANGUAGE plpgsql VOLATILE; + +CREATE OR REPLACE FUNCTION api.draft_game(data json) RETURNS integer AS $$ +DECLARE + questions json; + q_id integer; + qe_id integer; + r_id integer; + round_count integer; + question_count integer; + answer_count integer; + rnd json; + q json; + a json; + q_no smallint; +BEGIN + questions := data->'questions'; + round_count := 0; + INSERT INTO quiz (creator, name) VALUES ((data->>'userId')::integer, data->>'name') RETURNING id INTO q_id; + FOREACH rnd IN ARRAY ARRAY(SELECT json_array_elements(questions)) LOOP + INSERT INTO quiz_round (quiz_id, round_no) VALUES (q_id, round_count) RETURNING id INTO r_id; + FOREACH q IN ARRAY ARRAY(SELECT json_array_elements(rnd->>'questions')) LOOP + INSERT INTO question (round_id, question, question_no) VALUES (r_id, q->>'question', q_no) RETURNING id INTO qe_id; + FOREACH a IN ARRAY ARRAY(SELECT json_array_elements(q->'answers')) LOOP + INSERT INTO answer (question_id, answer, points) VALUES (qe_id, a->>'answer', (a->>'points')::integer); + END LOOP; + q_no := q_no + 1; + END LOOP; + round_count := round_count + 1; + END LOOP; + RETURN q_id; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION api.user_answers(data json) RETURNS boolean AS $$ +DECLARE + p_id integer; + key text; + value text; +BEGIN + p_id := (data->>'userId')::integer; + FOR key, value IN SELECT * FROM json_each_text(data->'answers') LOOP + INSERT INTO participant_response (participant_id, response, answer_id) VALUES (p_id, value, key::integer); + END LOOP; + RETURN true; +END; +$$ LANGUAGE plpgsql VOLATILE; + +CREATE OR REPLACE FUNCTION api.host_game(data json) RETURNS uuid AS $$ +DECLARE + user_id integer; + game_id integer; + game_code uuid; +BEGIN + user_id := (data->>'userId')::integer; + game_id := (data->>'gameId')::integer; + IF EXISTS(SELECT 1 FROM quiz q WHERE q.id = game_id AND q.creator = user_id) THEN + INSERT INTO game (quiz_id) VALUES (game_id) RETURNING code INTO game_code; + RETURN game_code; + ELSE + RAISE EXCEPTION 'Permission to host game denied'; + END IF; +END; +$$ LANGUAGE plpgsql VOLATILE; + +CREATE OR REPLACE FUNCTION api.update_game(data json) RETURNS boolean AS $$ +DECLARE + questions json; + creator_id integer; + rnd json; + round_count integer; + rnd_id integer; + q_id integer; + qe_id integer; + qe_ix integer; + ans_id integer; + ans_ix integer; + q json; + a json; + q_name text; + q_no smallint; +BEGIN + questions := data->'questions'; + creator_id := (data->>'userId')::integer; + q_name := data->>'quizName'; + q_id := (data->>'quizId')::integer; + round_count := 0; + UPDATE quiz SET name = q_name WHERE id = q_id AND creator = creator_id; + IF NOT FOUND THEN + RETURN false; + ELSE + FOREACH rnd IN ARRAY ARRAY(SELECT json_array_elements(questions)) LOOP + rnd_id := (rnd->>'roundId')::integer; + q_no := 1; + IF rnd_id IS NULL THEN + INSERT INTO quiz_round (quiz_id, round_no) VALUES (q_id, round_count) RETURNING id INTO rnd_id; + END IF; + FOREACH q IN ARRAY ARRAY(SELECT json_array_elements(rnd->'questions')) LOOP + qe_id := (q->>'questionId')::integer; + IF qe_id IS NULL THEN + INSERT INTO question (round_id, question, question_no) VALUES (rnd_id, q->>'question', q_no) RETURNING id INTO qe_id; + ELSE + UPDATE question SET question = q->>'question' + FROM quiz_round qr + JOIN quiz ON qr.quiz_id = quiz.id + WHERE question.id = qe_id + AND quiz.creator = creator_id; + END IF; + FOREACH a IN ARRAY ARRAY(SELECT json_array_elements(q->'answers')) LOOP + ans_id := (a->>'answerId')::integer; + RAISE NOTICE 'answer id: %s', ans_id; + IF ans_id IS NULL THEN + INSERT INTO answer (question_id, answer, points) VALUES (qe_id, a->>'answer', (a->>'points')::integer); + ELSE + UPDATE answer SET answer = a->>'answer', points = (a->>'points')::integer + FROM question qe + JOIN quiz_round qr ON qe.round_id = qr.id + JOIN quiz ON qr.quiz_id = quiz.id + WHERE answer.id = ans_id + AND quiz.creator = creator_id; + END IF; + END LOOP; + q_no := q_no + 1; + END LOOP; + round_count := round_count + 1; + END LOOP; + RETURN true; + END IF; + END; +$$ LANGUAGE plpgsql VOLATILE; diff --git a/app/migrations/0004-auth.sql b/app/migrations/0004-auth.sql new file mode 100644 index 0000000..20311e2 --- /dev/null +++ b/app/migrations/0004-auth.sql @@ -0,0 +1,77 @@ +-- adapted from https://docs.subzero.cloud/tutorial/5min/#authentication + + +CREATE OR REPLACE FUNCTION public.new_session(u api.player_result) RETURNS api.player_result AS $$ + DECLARE + secret TEXT; + token TEXT; + BEGIN + SELECT js.secret FROM public.jwt_secret js INTO secret; + token := pgjwt.sign( + json_build_object( + 'role', 'user', + 'user_id', u.id, + 'exp', extract(epoch from now())::integer + 3600 + ), + secret + ); + PERFORM response.set_cookie('SESSIONID', token, 3600, '/'); + return u; + END +$$ STABLE LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION api.login( + u_email VARCHAR(255), + u_password TEXT, + u_ipaddr inet, + u_display_name VARCHAR(32) +) RETURNS api.player_result AS $$ + DECLARE + u api.player_result; + BEGIN + SELECT api.new_player(u_email, u_password, u_ipaddr, u_display_name) INTO u; + IF u.id = -1 THEN + RETURN u; + ELSE + RETURN public.new_session(u); + END IF; + END; +$$ SECURITY DEFINER LANGUAGE plpgsql; +REVOKE ALL PRIVILEGES ON FUNCTION api.login(VARCHAR(255), TEXT, inet, VARCHAR(32)) FROM public; + +CREATE ROLE user; +GRANT user TO authenticator; + +GRANT USAGE ON SCHEMA api TO user; +GRANT + SELECT(id, display_name) +ON api.player TO user; +GRANT + SELECT(id, name), +ON api.quiz TO user; +GRANT + SELECT(id, quiz_id, round_no) +ON api.quiz_round TO user; +GRANT + SELECT(id, round_id, question, question_no) +ON api.question TO user; +GRANT + SELECT(id, question_id, answer, points) +ON api.answer TO user; +GRANT + SELECT(id, quiz_id, code, completed), + UPDATE(completed) +ON api.game TO user; +GRANT + SELECT(id, game_id, player_id, score) +ON api.game_participant TO user; +GRANT + SELECT(id, answer_id, participant_id, response) +ON api.participant_response TO user; +GRANT EXECUTE ON FUNCTION api.login(VARCHAR(255), TEXT, inet, VARCHAR(32)) TO user; +GRANT EXECUTE ON FUNCTION api.login(VARCHAR(255), TEXT, inet, VARCHAR(32)) TO anonymous; +GRANT EXECUTE ON FUNCTION api.delete_user(VARCHAR(255), inet) TO user; +GRANT EXECUTE ON FUNCTION api.draft_game(json) TO user; +GRANT EXECUTE ON FUNCTION api.user_answers(json) TO user; +GRANT EXECUTE ON FUNCTION api.host_game(json) TO user; +GRANT EXECUTE ON FUNCTION api.update_game(json) TO user; diff --git a/app/setJWTSecret.js b/app/setJWTSecret.js new file mode 100644 index 0000000..e898c1e --- /dev/null +++ b/app/setJWTSecret.js @@ -0,0 +1,13 @@ +const { Client } = require('pg'); +const config = require('./dbConfig'); + +async function setJWTSecret() { + const client = new Client(config); + await client.connect(); + await client.query('TRUNCATE TABLE public.jwt_secret'); + await client.query('INSERT INTO public.jwt_secret (secret) VALUES($1)', [ + process.env.JWT_SECRET + ]); +} + +setJWTSecret();