From e2b2321f7309552e027876161224ff0dcc427205 Mon Sep 17 00:00:00 2001 From: jamaik <jamaik@utu.fi> Date: Fri, 17 Apr 2020 15:44:36 +0300 Subject: [PATCH] added comments --- database/index.md | 10 ++++++- migrate/src/migrations/100_init.up.sql | 37 ++++++++++++++++++++++++++ 2 files changed, 46 insertions(+), 1 deletion(-) diff --git a/database/index.md b/database/index.md index 9c53d0b..fd140a2 100644 --- a/database/index.md +++ b/database/index.md @@ -11,4 +11,12 @@ - The database tests and migrations are handled by the `migrate` service. ### Running the database -`docker-compose up postgres --build` \ No newline at end of file +`docker-compose up postgres --build` + +### Browsing the database via psql +```bash +# Accessing the postgres-database inside docker +docker-compose exec postgres psql testdb testuser + +# Exit with the command \q +``` \ No newline at end of file diff --git a/migrate/src/migrations/100_init.up.sql b/migrate/src/migrations/100_init.up.sql index 7a948e5..1e17d81 100644 --- a/migrate/src/migrations/100_init.up.sql +++ b/migrate/src/migrations/100_init.up.sql @@ -34,16 +34,21 @@ CREATE TABLE ${GRAPH_EDITOR_SCHEMA}.person ( created_at timestamp DEFAULT NOW() NOT NULL, updated_at timestamp DEFAULT NOW() NOT NULL ); +COMMENT ON TABLE ${GRAPH_EDITOR_SCHEMA}.person IS 'A user of the application'; +-- Enable row-level-security and start index from 111, so that we can use test data for ids in range 1-110. ALTER TABLE ${GRAPH_EDITOR_SCHEMA}.person ENABLE ROW LEVEL SECURITY; ALTER SEQUENCE ${GRAPH_EDITOR_SCHEMA}.person_id_seq RESTART WITH 111; CREATE TRIGGER set_timestamp BEFORE UPDATE ON ${GRAPH_EDITOR_SCHEMA}.person FOR EACH ROW EXECUTE PROCEDURE trigger_set_timestamp(); +-- Grant select and update(email) for person. +-- Note that insert and delete are handled by functions. GRANT USAGE, SELECT ON SEQUENCE ${GRAPH_EDITOR_SCHEMA}.person_id_seq TO ${GRAPH_EDITOR_SCHEMA}_person; GRANT SELECT, UPDATE(email) ON TABLE ${GRAPH_EDITOR_SCHEMA}.person TO ${GRAPH_EDITOR_SCHEMA}_person; +-- Allow ${GRAPH_EDITOR_SCHEMA}_person to only access own data. CREATE POLICY ${GRAPH_EDITOR_SCHEMA}_person_all_access_to_person ON ${GRAPH_EDITOR_SCHEMA}.person FOR ALL @@ -63,12 +68,19 @@ CREATE TABLE ${GRAPH_EDITOR_SCHEMA}.graph ( created_at timestamp DEFAULT NOW() NOT NULL, UNIQUE(person_id, name) ); +COMMENT ON TABLE ${GRAPH_EDITOR_SCHEMA}.graph IS 'A graph created by a person.'; +COMMENT ON COLUMN ${GRAPH_EDITOR_SCHEMA}.graph.name IS 'A readable name for the graph.'; +COMMENT ON COLUMN ${GRAPH_EDITOR_SCHEMA}.graph.nodes IS 'A json-array of nodes.'; +COMMENT ON COLUMN ${GRAPH_EDITOR_SCHEMA}.graph.edges IS 'A json-array of edges.'; + +-- Enable row-level-security and start index from 111, so that we can use test data for ids in range 1-110. ALTER TABLE ${GRAPH_EDITOR_SCHEMA}.graph ENABLE ROW LEVEL SECURITY; ALTER SEQUENCE ${GRAPH_EDITOR_SCHEMA}.graph_id_seq RESTART WITH 111; CREATE TRIGGER set_timestamp BEFORE UPDATE ON ${GRAPH_EDITOR_SCHEMA}.graph FOR EACH ROW EXECUTE PROCEDURE trigger_set_timestamp(); +-- Grant privileges. GRANT USAGE, SELECT ON SEQUENCE ${GRAPH_EDITOR_SCHEMA}.graph_id_seq TO ${GRAPH_EDITOR_SCHEMA}_person; GRANT SELECT, @@ -76,6 +88,7 @@ GRANT UPDATE(name, nodes, edges), DELETE ON TABLE ${GRAPH_EDITOR_SCHEMA}.graph TO ${GRAPH_EDITOR_SCHEMA}_person; +-- Allow ${GRAPH_EDITOR_SCHEMA}_person to only access graphs that have the same person_id as in the jwt. CREATE POLICY ${GRAPH_EDITOR_SCHEMA}_person_all_access_to_graph ON ${GRAPH_EDITOR_SCHEMA}.graph FOR ALL @@ -92,19 +105,32 @@ CREATE TABLE ${GRAPH_EDITOR_SCHEMA}_private.person_account ( updated_at timestamp DEFAULT NOW() NOT NULL, UNIQUE(person_id) ); +COMMENT ON TABLE ${GRAPH_EDITOR_SCHEMA}_private.person_account IS 'Private information about the person.'; +COMMENT ON COLUMN ${GRAPH_EDITOR_SCHEMA}_private.person_account.password_hash IS 'A hash of the person''s password.'; + +-- Enable row-level-security. ALTER TABLE ${GRAPH_EDITOR_SCHEMA}.person ENABLE ROW LEVEL SECURITY; CREATE TRIGGER set_timestamp BEFORE UPDATE ON ${GRAPH_EDITOR_SCHEMA}_private.person_account FOR EACH ROW EXECUTE PROCEDURE trigger_set_timestamp(); +------------------------------------------------ +-------------- FUNCTIONS ----------------------- +------------------------------------------------ +-- The below functions are marked with the keyword 'security definer', +-- which means that the functions are called with the owner's privileges. +-- This means that the statements inside the function bybass the row-level-security. + +-- The type that postgraphile uses for creating json-web-tokens. CREATE TYPE ${GRAPH_EDITOR_SCHEMA}.auth_token as ( role text, person_id integer, exp bigint ); +-- Authentication function. This is called when logging in. CREATE FUNCTION ${GRAPH_EDITOR_SCHEMA}.authenticate( email text, password text @@ -131,10 +157,14 @@ BEGIN END IF; END; $$ language plpgsql strict security definer; +COMMENT ON FUNCTION ${GRAPH_EDITOR_SCHEMA}.authenticate(text, text) is 'Authenticates a person by email and password. Returns a JWT.'; +-- Allow an anonymous user to authenticate. GRANT EXECUTE ON FUNCTION ${GRAPH_EDITOR_SCHEMA}.authenticate(text, text) TO ${GRAPH_EDITOR_SCHEMA}_anonymous; + +-- Person-registration function. CREATE FUNCTION ${GRAPH_EDITOR_SCHEMA}.register_person( email text, password text @@ -156,10 +186,14 @@ BEGIN )::${GRAPH_EDITOR_SCHEMA}.auth_token; END; $$ language plpgsql strict security definer; +COMMENT ON FUNCTION ${GRAPH_EDITOR_SCHEMA}.register_person(text, text) is 'Registers a person by email and password. Returns a JWT.'; +-- Allow an anonymous user to register. GRANT EXECUTE ON FUNCTION ${GRAPH_EDITOR_SCHEMA}.register_person(text, text) TO ${GRAPH_EDITOR_SCHEMA}_anonymous; +-- Function that removes a person from the database. +-- Note that this is the only way a person can delete the account. CREATE FUNCTION ${GRAPH_EDITOR_SCHEMA}.remove_person( email text, password text @@ -172,6 +206,7 @@ BEGIN FROM ${GRAPH_EDITOR_SCHEMA}_private.person_account a, ${GRAPH_EDITOR_SCHEMA}.person p WHERE p.email = $1 AND p.id = a.person_id; + -- Throw error if the person is trying to remove another person's account. IF (account.person_id != person_id_from_jwt) THEN RAISE EXCEPTION 'unauthorized'; END IF; @@ -185,7 +220,9 @@ BEGIN RETURN true; END; $$ language plpgsql strict security definer; +COMMENT ON FUNCTION ${GRAPH_EDITOR_SCHEMA}.remove_person(text, text) is 'Removes an authenticated person by email and password.'; +-- Only allow an authenticated user to run this function. GRANT EXECUTE ON FUNCTION ${GRAPH_EDITOR_SCHEMA}.remove_person(text, text) TO ${GRAPH_EDITOR_SCHEMA}_person; -- GitLab