--- /dev/null
+/* Copyright (c) 2023 Jakub Czajka <jakub@ekhem.eu.org>
+ License: GPL-3.0 or later. */
+
+CREATE TABLE IF NOT EXISTS exercises (
+ id SERIAL PRIMARY KEY,
+ name VARCHAR(128) NOT NULL UNIQUE
+);
+
+CREATE TABLE IF NOT EXISTS gyms (
+ id SERIAL PRIMARY KEY,
+ name VARCHAR(128) NOT NULL UNIQUE
+);
+
+CREATE TABLE IF NOT EXISTS workouts (
+ id SERIAL PRIMARY KEY,
+ date DATE DEFAULT CURRENT_DATE UNIQUE,
+ duration_min INTEGER NOT NULL
+);
+
+CREATE TABLE IF NOT EXISTS gyms_records (
+ gym_id INTEGER REFERENCES gyms (id),
+ exercise_id INTEGER REFERENCES exercises (id),
+ value VARCHAR(64) NOT NULL,
+ PRIMARY KEY (gym_id, exercise_id)
+);
+
+CREATE TABLE IF NOT EXISTS records (
+ exercise_id INTEGER PRIMARY KEY REFERENCES exercises (id),
+ value VARCHAR(64) NOT NULL
+);
+
+CREATE TABLE IF NOT EXISTS workouts_gyms (
+ workout_id INTEGER PRIMARY KEY REFERENCES workouts (id),
+ gym_id INTEGER REFERENCES gyms (id)
+);
+
+CREATE TABLE IF NOT EXISTS workouts_exercises (
+ workout_id INTEGER REFERENCES workouts (id),
+ exercise_id INTEGER REFERENCES exercises (id),
+ value VARCHAR(64) NOT NULL,
+ PRIMARY KEY (workout_id, exercise_id)
+);
+
+DO $$
+BEGIN
+ IF NOT EXISTS (SELECT * FROM pg_user WHERE usename = 'gym_tracker')
+ THEN
+ CREATE ROLE gym_tracker LOGIN;
+
+ GRANT SELECT
+ ON TABLE exercises, gyms, gyms_records, records, workouts, workouts_exercises
+ TO gym_tracker;
+
+ GRANT INSERT
+ ON TABLE exercises, gyms, gyms_records, records, workouts, workouts_exercises, workouts_gyms
+ TO gym_tracker;
+
+ GRANT UPDATE
+ ON TABLE exercises, gyms, gyms_records, records
+ TO gym_tracker;
+
+ GRANT USAGE, SELECT
+ ON SEQUENCE exercises_id_seq, gyms_id_seq, workouts_id_seq
+ TO gym_tracker;
+
+ /* Execute for the current database. */
+ EXECUTE FORMAT('GRANT CONNECT
+ ON DATABASE %I
+ TO gym_tracker', current_database());
+ END IF;
+END$$;
--- /dev/null
+/* Copyright (c) 2023 Jakub Czajka <jakub@ekhem.eu.org>
+ License: GPL-3.0 or later. */
+
+DO $$
+BEGIN
+ IF EXISTS (SELECT * FROM pg_user WHERE usename = 'gym_tracker')
+ THEN
+ REVOKE SELECT
+ ON TABLE exercises, gyms, gyms_records, records, workouts, workouts_exercises
+ FROM gym_tracker;
+
+ REVOKE INSERT
+ ON TABLE exercises, gyms, gyms_records, records, workouts, workouts_exercises, workouts_gyms
+ FROM gym_tracker;
+
+ REVOKE UPDATE
+ ON TABLE exercises, gym, gyms_records, records
+ FROM gym_tracker;
+
+ REVOKE USAGE, SELECT
+ ON SEQUENCE exercises_id_seq, gyms_id_seq, workouts_id_seq
+ FROM gym_tracker;
+
+ EXECUTE
+ FORMAT('REVOKE CONNECT
+ ON DATABASE %I
+ FROM gym_tracker;', current_database());
+
+ DROP ROLE gym_tracker;
+ END IF;
+END$$;
+
+DROP TABLE IF EXISTS workouts_exercises;
+DROP TABLE IF EXISTS workouts_gyms;
+DROP TABLE IF EXISTS records;
+DROP TABLE IF EXISTS gyms_records;
+DROP TABLE IF EXISTS workouts;
+DROP TABLE IF EXISTS gyms;
+DROP TABLE IF EXISTS exercises;