From d2b0fb7ec2dbd2e95cb95a563c0765df92d7d65e Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Maciej=20Krzy=C5=BCanowski?= Date: Sun, 26 Feb 2023 18:02:09 +0100 Subject: [PATCH] Added SQL scripts which create database --- skrytka_create_db.sql | 89 ++++++++++++++++++++++++++++++++++++++++ skrytka_create_utils.sql | 65 +++++++++++++++++++++++++++++ 2 files changed, 154 insertions(+) create mode 100644 skrytka_create_db.sql create mode 100644 skrytka_create_utils.sql diff --git a/skrytka_create_db.sql b/skrytka_create_db.sql new file mode 100644 index 0000000..20b9107 --- /dev/null +++ b/skrytka_create_db.sql @@ -0,0 +1,89 @@ +DROP TABLE IF EXISTS osp_unit CASCADE; +CREATE TABLE osp_unit ( + id SERIAL PRIMARY KEY, + name VARCHAR(128) NOT NULL, + locality VARCHAR(64) NOT NULL CHECK(locality SIMILAR TO '[A-ZĄĆĘŁŃÓŚŹŻ][A-zĄĆĘŁŃÓŚŹŻząćęłńóśźż. ]+') +); + +DROP TABLE IF EXISTS fire_truck CASCADE; +CREATE TABLE fire_truck ( + id SERIAL PRIMARY KEY, + name VARCHAR(64) NOT NULL, + image_path VARCHAR(128) CHECK(image_path ~ '^([0-9a-z_]+/?)*[0-9a-z_]+\.((png)|(jpg)|(jpeg)|(webp))$'), + osp_unit_id INTEGER NOT NULL REFERENCES osp_unit ON DELETE CASCADE ON UPDATE CASCADE +); + +DROP TABLE IF EXISTS truck_side CASCADE; +CREATE TABLE truck_side ( + id SERIAL PRIMARY KEY, + image_path VARCHAR(128) NOT NULL CHECK(image_path ~ '^([0-9a-z_]+/?)*[0-9a-z_]+\.((png)|(jpg)|(jpeg))$'), + ordinal_number INTEGER NOT NULL, + fire_truck_id INTEGER REFERENCES fire_truck ON DELETE CASCADE ON UPDATE CASCADE +); + +DROP TABLE IF EXISTS cache CASCADE; +CREATE TABLE cache ( + id SERIAL PRIMARY KEY, + name VARCHAR(64), + rectangle BOX NOT NULL CHECK( + (rectangle[0])[0] <= 1 AND (rectangle[0])[0] >= 0 AND + (rectangle[0])[1] <= 1 AND (rectangle[0])[1] >= 0 AND + (rectangle[1])[0] <= 1 AND (rectangle[1])[0] >= 0 AND + (rectangle[1])[1] <= 1 AND (rectangle[1])[1] >= 0 + ), + truck_side INTEGER NOT NULL REFERENCES truck_side ON DELETE CASCADE ON UPDATE CASCADE +); + +DROP TABLE IF EXISTS account CASCADE; +CREATE TABLE account ( + nickname VARCHAR(32) CHECK(nickname SIMILAR TO '[0-9A-z_żółćęśąźńŻÓŁĆĘŚĄŹŃ]{3,}') PRIMARY KEY, + name VARCHAR(32) CHECK(name SIMILAR TO '[A-ZŻÓŁĆĘŚĄŹŃ][a-zżółćęśąźń]+'), + surname VARCHAR(64) CHECK(surname SIMILAR TO '[A-ZŻÓŁĆĘŚĄŹŃ][a-zżółćęśąźń]+'), + pass_hash CHAR(72) NOT NULL, -- Tu należy dostosować odpowiednio dla wybranego sposobu hashowania + default_osp INTEGER REFERENCES osp_unit ON DELETE SET NULL ON UPDATE CASCADE +); + +DROP TABLE IF EXISTS equipment CASCADE; +CREATE TABLE equipment ( + id SERIAL PRIMARY KEY, + name VARCHAR(64) NOT NULL CHECK(LENGTH(name) > 0), + cache_id INTEGER NOT NULL REFERENCES cache ON DELETE CASCADE ON UPDATE CASCADE +); + +DROP TABLE IF EXISTS score; +CREATE TABLE score ( + id SERIAL PRIMARY KEY, + account_nickname VARCHAR(32) REFERENCES account ON DELETE CASCADE ON UPDATE CASCADE, + acquisition_timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), + fire_truck_id INTEGER NOT NULL REFERENCES fire_truck ON DELETE CASCADE ON UPDATE CASCADE, + points INTEGER NOT NULL CHECK(points BETWEEN 0 AND 10), + seconds INTEGER NOT NULL CHECK(seconds > 0) +); + +DROP TABLE IF EXISTS permission CASCADE; +CREATE TABLE permission ( + code VARCHAR(64) CHECK(code ~ '^[0-9A-Z_]{3,}$') PRIMARY KEY, + name VARCHAR(64) CHECK(LENGTH(name) >= 3), + description VARCHAR(128) +); + +-- PYTANIE: Czy aktualizować permission code przy zmianie czy na NULL? +DROP TABLE IF EXISTS accounts_permissions CASCADE; +CREATE TABLE accounts_permissions ( + account_nickname VARCHAR(32) REFERENCES account ON DELETE CASCADE ON UPDATE CASCADE, + permission_code VARCHAR(64) REFERENCES permission ON DELETE CASCADE ON UPDATE CASCADE, + osp_unit_id INTEGER REFERENCES osp_unit ON DELETE CASCADE ON UPDATE CASCADE, + CONSTRAINT pk_users_permissions PRIMARY KEY (account_nickname, permission_code, osp_unit_id) +); + +DROP TABLE IF EXISTS event CASCADE; +CREATE TABLE event ( + id SERIAL PRIMARY KEY, + name VARCHAR(64) NOT NULL CHECK(LENGTH(name) >= 3), + details VARCHAR(128), + report_time TIMESTAMP WITH TIME ZONE + CHECK(report_time <= NOW() AND DATE_PART('hour', CURRENT_TIMESTAMP - report_time) < 1), + -- Chcemy zachować spójność dziennika zdarzeń, nawet jak użytkownik usunie konto: + account_nickname VARCHAR(32) REFERENCES account ON DELETE SET NULL ON UPDATE CASCADE, + osp_unit_id INTEGER REFERENCES osp_unit ON DELETE CASCADE ON UPDATE CASCADE +); \ No newline at end of file diff --git a/skrytka_create_utils.sql b/skrytka_create_utils.sql new file mode 100644 index 0000000..32c5856 --- /dev/null +++ b/skrytka_create_utils.sql @@ -0,0 +1,65 @@ +DROP VIEW IF EXISTS units_list; +CREATE VIEW units_list AS + SELECT id, name, locality FROM osp_unit; + +DROP FUNCTION IF EXISTS get_units_list; +CREATE FUNCTION get_units_list(prefix VARCHAR) RETURNS TABLE (id INTEGER, name VARCHAR, locality VARCHAR) +AS +$func$ + SELECT * FROM units_list WHERE locality LIKE prefix || '%' OR name LIKE prefix || '%' ORDER BY locality, name LIMIT 3; +$func$ +LANGUAGE SQL; + +DROP FUNCTION IF EXISTS get_trucks_list_with_scores; +CREATE FUNCTION get_trucks_list_with_scores(osp_unit INTEGER, nickname VARCHAR, last_scores_num INTEGER = 3) + RETURNS TABLE (id INTEGER, name VARCHAR, image_path VARCHAR, avg_percent FLOAT) AS +$func$ + SELECT ft.id, name, image_path, ROUND(AVG(s.points) * 10, 2) AS avg_percent + FROM fire_truck ft + JOIN score s ON ft.id = s.fire_truck_id AND s.account_nickname = nickname + WHERE ft.osp_unit_id = osp_unit AND s.id IN ( + SELECT sc.id FROM score sc + WHERE sc.account_nickname = nickname AND sc.fire_truck_id = ft.id + ORDER BY sc.acquisition_timestamp DESC + LIMIT last_scores_num + ) GROUP BY ft.id, name, image_path + UNION + (SELECT ft.id, name, image_path, 0 + FROM fire_truck ft + WHERE ft.osp_unit_id = osp_unit AND + ft.id NOT IN (SELECT fire_truck_id FROM score WHERE account_nickname = nickname)) + ORDER BY 1; +$func$ +LANGUAGE SQL; + +DROP FUNCTION IF EXISTS get_quiz_data_for_truck; +CREATE FUNCTION get_quiz_data_for_truck(truck_id INTEGER) + RETURNS TABLE (side_id INTEGER, side_image_path VARCHAR, cache_id INTEGER, + cache_rectangle BOX, cache_name VARCHAR) AS +$func$ + SELECT ts.id, ts.image_path, c.id, c.rectangle, c.name + FROM fire_truck + JOIN truck_side ts on fire_truck.id = ts.fire_truck_id + JOIN cache c on ts.id = c.truck_side + WHERE fire_truck.id = truck_id + ORDER BY ts.ordinal_number; +$func$ +LANGUAGE SQL; + +DROP FUNCTION IF EXISTS get_random_question; +CREATE FUNCTION get_random_question(truck_id INTEGER) + RETURNS TABLE (cache_id INTEGER, equipment_name VARCHAR) AS +$func$ + SELECT c.id, e.name + FROM truck_side ts + JOIN cache c on ts.id = c.truck_side + JOIN equipment e on c.id = e.cache_id + WHERE ts.fire_truck_id = truck_id + ORDER BY RANDOM() + LIMIT 1; +$func$ +LANGUAGE SQL; + +DROP VIEW IF EXISTS trucks_list; +CREATE VIEW trucks_list AS + SELECT id, name, image_path FROM fire_truck; \ No newline at end of file