feat: update structure
This commit is contained in:
17
cs2102/labs/cases/Assessment DB/01-tdfdb-clean.sql
Normal file
17
cs2102/labs/cases/Assessment DB/01-tdfdb-clean.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
/*******************
|
||||
Cleaning script
|
||||
*******************/
|
||||
|
||||
DROP TABLE IF EXISTS results_individual;
|
||||
DROP TABLE IF EXISTS results_sprints;
|
||||
DROP TABLE IF EXISTS results_mountains;
|
||||
DROP TABLE IF EXISTS results_combative;
|
||||
DROP TABLE IF EXISTS sprints;
|
||||
DROP TABLE IF EXISTS mountains;
|
||||
DROP TABLE IF EXISTS stages;
|
||||
DROP TABLE IF EXISTS locations;
|
||||
DROP TABLE IF EXISTS riders;
|
||||
DROP TABLE IF EXISTS teams;
|
||||
DROP TABLE IF EXISTS countries;
|
||||
DROP TABLE IF EXISTS subregions;
|
||||
DROP TABLE IF EXISTS regions;
|
||||
130
cs2102/labs/cases/Assessment DB/02-tdfdb-schema.sql
Normal file
130
cs2102/labs/cases/Assessment DB/02-tdfdb-schema.sql
Normal file
@@ -0,0 +1,130 @@
|
||||
/*******************
|
||||
Create the schema
|
||||
********************/
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS regions (
|
||||
name VARCHAR(32) PRIMARY KEY
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS subregions (
|
||||
name VARCHAR(32) PRIMARY KEY,
|
||||
region VARCHAR(32) NOT NULL,
|
||||
CONSTRAINT fk_region FOREIGN KEY (region) REFERENCES regions (name)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS countries (
|
||||
code CHAR(3) PRIMARY KEY,
|
||||
name VARCHAR(64) UNIQUE NOT NULL,
|
||||
subregion VARCHAR(32) NOT NULL,
|
||||
CONSTRAINT fk_subregion FOREIGN KEY (subregion) REFERENCES subregions (name)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS teams (
|
||||
name VARCHAR(64) PRIMARY KEY,
|
||||
country CHAR(3) NOT NULL,
|
||||
CONSTRAINT fk_country FOREIGN KEY (country) REFERENCES countries (code) ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS riders (
|
||||
bib INTEGER PRIMARY KEY,
|
||||
name VARCHAR(64) NOT NULL,
|
||||
dob DATE NOT NULL,
|
||||
country CHAR(3) NOT NULL,
|
||||
team VARCHAR(64) NOT NULL,
|
||||
CONSTRAINT fk_team FOREIGN KEY (team) REFERENCES teams (name) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_country FOREIGN KEY (country) REFERENCES countries (code) ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS locations (
|
||||
name VARCHAR(64) PRIMARY KEY,
|
||||
country CHAR(3) NOT NULL,
|
||||
CONSTRAINT fk_country FOREIGN KEY (country) REFERENCES countries (code) ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS stages (
|
||||
nr INTEGER PRIMARY KEY,
|
||||
day DATE UNIQUE NOT NULL,
|
||||
start VARCHAR(64) NOT NULL,
|
||||
finish VARCHAR(64) NOT NULL,
|
||||
length NUMERIC(5,1) NOT NULL,
|
||||
type VARCHAR(32),
|
||||
CONSTRAINT fk_start FOREIGN KEY (start) REFERENCES locations (name) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_finish FOREIGN KEY (finish) REFERENCES locations (name) ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS sprints (
|
||||
stage INTEGER NOT NULL,
|
||||
location VARCHAR(64) NOT NULL,
|
||||
distance NUMERIC(5,1) NOT NULL,
|
||||
PRIMARY KEY (stage, location),
|
||||
CONSTRAINT fk_stage FOREIGN KEY (stage) REFERENCES stages (nr) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_location FOREIGN KEY (location) REFERENCES locations (name) ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS mountains (
|
||||
stage INTEGER NOT NULL,
|
||||
location VARCHAR(64) NOT NULL,
|
||||
distance NUMERIC(5,1) NOT NULL,
|
||||
height NUMERIC(5,1) NOT NULL,
|
||||
length NUMERIC(3,1) NOT NULL,
|
||||
percent NUMERIC(3,1) NOT NULL,
|
||||
category CHAR(1) NOT NULL,
|
||||
PRIMARY KEY (stage, location),
|
||||
CONSTRAINT fk_stage FOREIGN KEY (stage) REFERENCES stages (nr) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_location FOREIGN KEY (location) REFERENCES locations (name) ON UPDATE CASCADE
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS results_individual (
|
||||
stage INTEGER NOT NULL,
|
||||
rank INTEGER NOT NULL CHECK (rank > 0),
|
||||
rider INTEGER NOT NULL,
|
||||
time INTEGER NOT NULL CHECK (time >= 0),
|
||||
bonus INTEGER NOT NULL DEFAULT 0 CHECK (bonus >= 0),
|
||||
penalty INTEGER NOT NULL DEFAULT 0 CHECK (penalty >= 0),
|
||||
CONSTRAINT fk_stage FOREIGN KEY (stage) REFERENCES stages (nr) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_rider FOREIGN KEY (rider) REFERENCES riders (bib) ON UPDATE CASCADE,
|
||||
CONSTRAINT pk_result_individual PRIMARY KEY (stage, rank, rider)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS results_sprints (
|
||||
stage INTEGER NOT NULL,
|
||||
location VARCHAR(64) NOT NULL,
|
||||
rank INTEGER NOT NULL CHECK (rank > 0),
|
||||
rider INTEGER NOT NULL,
|
||||
points INTEGER NOT NULL CHECK (points > 0),
|
||||
CONSTRAINT fk_sprint FOREIGN KEY (stage, location) REFERENCES sprints (stage, location) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_rider FOREIGN KEY (rider) REFERENCES riders (bib) ON UPDATE CASCADE,
|
||||
CONSTRAINT pk_result_sprint PRIMARY KEY (stage, location, rank, rider)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS results_mountains (
|
||||
stage INTEGER NOT NULL,
|
||||
location VARCHAR(64) NOT NULL,
|
||||
rank INTEGER NOT NULL CHECK (rank > 0),
|
||||
rider INTEGER NOT NULL,
|
||||
points INTEGER NOT NULL CHECK (points > 0),
|
||||
CONSTRAINT fk_mountain FOREIGN KEY (stage, location) REFERENCES mountains (stage, location) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_rider FOREIGN KEY (rider) REFERENCES riders (bib) ON UPDATE CASCADE,
|
||||
CONSTRAINT pk_result_mountain PRIMARY KEY (stage, location, rank, rider)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS results_combative (
|
||||
stage INTEGER NOT NULL,
|
||||
rider INTEGER NOT NULL,
|
||||
CONSTRAINT fk_stage FOREIGN KEY (stage) REFERENCES stages (nr) ON UPDATE CASCADE,
|
||||
CONSTRAINT fk_rider FOREIGN KEY (rider) REFERENCES riders (bib) ON UPDATE CASCADE,
|
||||
CONSTRAINT pk_winner PRIMARY KEY (stage, rider)
|
||||
);
|
||||
5092
cs2102/labs/cases/Assessment DB/03-tdfdb-data.sql
Normal file
5092
cs2102/labs/cases/Assessment DB/03-tdfdb-data.sql
Normal file
File diff suppressed because it is too large
Load Diff
106
cs2102/labs/cases/Assessment DB/04-tdfdb-check.sql
Normal file
106
cs2102/labs/cases/Assessment DB/04-tdfdb-check.sql
Normal file
@@ -0,0 +1,106 @@
|
||||
/*******************
|
||||
Check database
|
||||
********************/
|
||||
|
||||
DO
|
||||
$$
|
||||
DECLARE
|
||||
table_count INTEGER = 0;
|
||||
BEGIN
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM regions; -- 5
|
||||
IF table_count = 5 THEN
|
||||
RAISE NOTICE 'Table "regions": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "regions": FAIL (% instead of 5 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM subregions; -- 17
|
||||
IF table_count = 17 THEN
|
||||
RAISE NOTICE 'Table "subregions": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "subregions": FAIL (% instead of 17 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM countries; -- 226
|
||||
IF table_count = 226 THEN
|
||||
RAISE NOTICE 'Table "countries": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "countries": FAIL (% instead of 226 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM teams; -- 22
|
||||
IF table_count = 22 THEN
|
||||
RAISE NOTICE 'Table "teams": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "teams": FAIL (% instead of 22 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM riders; -- 176
|
||||
IF table_count = 176 THEN
|
||||
RAISE NOTICE 'Table "riders": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "riders": FAIL (% instead of 176 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM locations; -- 132
|
||||
IF table_count = 132 THEN
|
||||
RAISE NOTICE 'Table "locations": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "locations": FAIL (% instead of 132 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM sprints; -- 40
|
||||
IF table_count = 40 THEN
|
||||
RAISE NOTICE 'Table "sprints": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "sprints": FAIL (% instead of 40 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM mountains; -- 70
|
||||
IF table_count = 70 THEN
|
||||
RAISE NOTICE 'Table "mountains": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "mountains": FAIL (% instead of 70 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM stages; -- 21
|
||||
IF table_count = 21 THEN
|
||||
RAISE NOTICE 'Table "stages": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "stages": FAIL (% instead of 21 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM results_individual; -- 3449
|
||||
IF table_count = 3449 THEN
|
||||
RAISE NOTICE 'Table "results_individual": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "results_individual": FAIL (% instead of 3449 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM results_sprints; -- 600
|
||||
IF table_count = 600 THEN
|
||||
RAISE NOTICE 'Table "results_sprints": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "results_sprints": FAIL (% instead of 600 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM results_mountains; -- 233
|
||||
IF table_count = 233 THEN
|
||||
RAISE NOTICE 'Table "results_mountains": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "results_mountains": FAIL (% instead of 233 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
SELECT COUNT(*) INTO table_count FROM results_combative; -- 19
|
||||
IF table_count = 19 THEN
|
||||
RAISE NOTICE 'Table "results_combative": OK (% rows)', table_count;
|
||||
ELSE
|
||||
RAISE NOTICE 'Table "results_combative": FAIL (% instead of 19 rows)', table_count;
|
||||
END IF;
|
||||
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
Binary file not shown.
Reference in New Issue
Block a user