Add views and functions to keep things easy

master
Tait Hoyem 1 year ago
parent d84931f2b5
commit 21ad6975b8

@ -1,5 +1,4 @@
-- Add up migration script here
CREATE TABLE IF NOT EXISTS leagues (
id SERIAL PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL
id SERIAL PRIMARY KEY NOT NULL
);

@ -0,0 +1 @@
DROP TABLE IF EXISTS league_names;

@ -0,0 +1,14 @@
CREATE TABLE IF NOT EXISTS league_names (
id SERIAL PRIMARY KEY NOT NULL,
language INTEGER NOT NULL,
name VARCHAR(255) NOT NULL,
league INTEGER NOT NULL,
CONSTRAINT language_fk
FOREIGN KEY(language)
REFERENCES supported_languages(id)
ON DELETE RESTRICT,
CONSTRAINT league_fk
FOREIGN KEY(league)
REFERENCES leagues(id)
ON DELETE RESTRICT
);

@ -1,7 +1,6 @@
CREATE TABLE IF NOT EXISTS divisions (
id SERIAL PRIMARY KEY NOT NULL,
league INTEGER NOT NULL,
name VARCHAR(255) NOT NULL,
CONSTRAINT league_fk
FOREIGN KEY(league)
REFERENCES leagues(id)

@ -0,0 +1 @@
DROP TABLE IF EXISTS division_names;

@ -0,0 +1,14 @@
CREATE TABLE IF NOT EXISTS division_names (
id SERIAL PRIMARY KEY NOT NULL,
language INTEGER NOT NULL,
name VARCHAR(255) NOT NULL,
division INTEGER NOT NULL,
CONSTRAINT language_fk
FOREIGN KEY(language)
REFERENCES supported_languages(id)
ON DELETE RESTRICT,
CONSTRAINT division_fk
FOREIGN KEY(division)
REFERENCES divisions(id)
ON DELETE RESTRICT
);

@ -1,7 +1,6 @@
-- Add up migration script here
CREATE TABLE IF NOT EXISTS teams (
id SERIAL PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL,
division INTEGER NOT NULL,
-- possibly add an image
image VARCHAR(255),

@ -0,0 +1 @@
DROP TABLE IF EXISTS team_names;

@ -0,0 +1,15 @@
CREATE TABLE IF NOT EXISTS team_names (
id SERIAL PRIMARY KEY NOT NULL,
language INTEGER NOT NULL,
name VARCHAR(255) NOT NULL,
team INTEGER NOT NULL,
CONSTRAINT language_fk
FOREIGN KEY(language)
REFERENCES supported_languages(id)
ON DELETE RESTRICT,
CONSTRAINT team_fk
FOREIGN KEY(team)
REFERENCES teams(id)
ON DELETE RESTRICT
);

@ -1,7 +1,8 @@
-- Add up migration script here
CREATE TABLE IF NOT EXISTS players (
id SERIAL PRIMARY KEY NOT NULL,
name VARCHAR(255) NOT NULL,
first_names VARCHAR(255) NOT NULL,
last_name VARCHAR(32) NOT NULL,
height_cm INTEGER,
weight_kg INTEGER
);

@ -1,2 +1,3 @@
-- Add down migration script here
DELETE FROM league_names WHERE id=1;
DELETE FROM leagues WHERE id=1;

@ -1,5 +1,9 @@
-- Add up migration script here
INSERT INTO leagues
(id, name)
(id)
VALUES
(1, '2022 Canadian National Blind Hockey Tournament');
(1);
INSERT INTO league_names
(id, league, name, language)
VALUES
(1, 1, '2022 Canadian National Blind Hockey Tournament', 1);

@ -1,2 +1,4 @@
DELETE FROM division_names
WHERE id BETWEEN 1 AND 3;
DELETE FROM divisions
WHERE id BETWEEN 1 AND 3;

@ -1,6 +1,13 @@
INSERT INTO divisions
(id, name, league)
(id, league)
VALUES
(1, 'Low Vision & Development Division', 1),
(2, 'Open Division', 1),
(3, 'Children Division', 1);
(1, 1),
(2, 1),
(3, 1);
INSERT INTO division_names
(id, name, division, language)
vALUES
(1, 'Low Vision & Development Division', 1, 1),
(2, 'Open Division', 2, 1),
(3, 'Children Division', 3, 1);

@ -1,2 +1,3 @@
-- Add down migration script here
DELETE FROM team_names WHERE id BETWEEN 1 AND 4;
DELETE FROM teams WHERE id=1 OR id=2;

@ -1,6 +1,14 @@
-- Add up migration script here
INSERT INTO teams
(id, name, division)
(id, division)
VALUES
(1, 'Bullseye', 1),
(2, 'See Cats', 1);
(1, 1),
(2, 1);
INSERT INTO team_names
(id, team, name, language)
VALUES
(1, 1, 'Bullseye', 1),
(2, 2, 'See Cats', 1),
(3, 1, 'bulle', 2),
(4, 2, 'Chats Voient', 2);

@ -1,35 +1,35 @@
-- Add up migration script here
INSERT INTO players
(id, name)
(id, first_names, last_name)
VALUES
(1, 'Tait Hoyem'),
(2, 'Hillary Scanlon'),
(3, 'Nelson Rego'),
(4, 'Carrie Anton'),
(5, 'Salamaan Chaudhri'),
(6, 'Ben Ho Lung'),
(7, 'Brian MacLean'),
(8, 'Shannon Murphy'),
(9, 'Joseph Robinson'),
(10, 'Drexcyl Sison'),
(11, 'Ginny Sweet'),
(12, 'Catharine Lemay'),
(13, 'Thomas Stewart'),
(14, 'Maurice Clement-Lafrance'),
(15, 'Jennifer Fancy'),
(16, 'Allyssa Foulds'),
(17, 'Ryan Kucy'),
(18, 'Denis LeBlanc'),
(19, 'Bob Lowe'),
(20, 'Ted Moritsugu'),
(21, 'Dave Poidevin'),
(22, 'Jillian Stewart'),
(23, 'Laura Mark'),
(24, 'Matt Arnold'),
(25, 'Rory Kucy'),
(26, 'Jeff Stewart'),
(27, 'Dylan Brown'),
(28, 'Codi Isaac'),
(29, 'Richard Isaac'),
(30, 'Tyler McGuffin'),
(31, 'Scarlette Dorn');
(1, 'Tait', 'Hoyem'),
(2, 'Hillary', 'Scanlon'),
(3, 'Nelson', 'Rego'),
(4, 'Carrie', 'Anton'),
(5, 'Salamaan', 'Chaudhri'),
(6, 'Ben Ho', 'Lung'),
(7, 'Brian', 'MacLean'),
(8, 'Shannon', 'Murphy'),
(9, 'Joseph', 'Robinson'),
(10, 'Drexcyl', 'Sison'),
(11, 'Ginny', 'Sweet'),
(12, 'Catharine', 'Lemay'),
(13, 'Thomas', 'Stewart'),
(14, 'Maurice Clement', 'Lafrance'),
(15, 'Jennifer', 'Fancy'),
(16, 'Allyssa', 'Foulds'),
(17, 'Ryan', 'Kucy'),
(18, 'Denis', 'LeBlanc'),
(19, 'Bob', 'Lowe'),
(20, 'Ted', 'Moritsugu'),
(21, 'Dave', 'Poidevin'),
(22, 'Jillian', 'Stewart'),
(23, 'Laura', 'Mark'),
(24, 'Matt', 'Arnold'),
(25, 'Rory', 'Kucy'),
(26, 'Jeff', 'Stewart'),
(27, 'Dylan', 'Brown'),
(28, 'Codi', 'Isaac'),
(29, 'Richard', 'Isaac'),
(30, 'Tyler', 'McGuffin'),
(31, 'Scarlette', 'Dorn');

@ -1,9 +1,6 @@
-- Add up migration script here
CREATE TABLE IF NOT EXISTS games (
id SERIAL PRIMARY KEY NOT NULL,
-- this allows there to be special names like "Gold Medal Game", but the default will be the number of games already in the division + 1
-- NOTE: this is only done in the front end, the backend will not give a default value
name VARCHAR(255) NOT NULL,
-- what divison is the game a part of (usefl for stats)
division INTEGER NOT NULL,
team_home INTEGER NOT NULL,

@ -0,0 +1 @@
DROP TABLE IF EXISTS game_names;

@ -0,0 +1,14 @@
CREATE TABLE IF NOT EXISTS game_names (
id SERIAL PRIMARY KEY NOT NULL,
language INTEGER NOT NULL,
name VARCHAR(255) NOT NULL,
game INTEGER NOT NULL,
CONSTRAINT language_fk
FOREIGN KEY(language)
REFERENCES supported_languages(id)
ON DELETE RESTRICT,
CONSTRAINT game_fk
FOREIGN KEY(game)
REFERENCES games(id)
ON DELETE RESTRICT
);

@ -1,2 +1,4 @@
DELETE FROM game_names
WHERE id BETWEEN 1 AND 4;
DELETE FROM games
WHERE id BETWEEN 1 AND 4;

@ -1,9 +1,8 @@
INSERT INTO games
(id, name, division, team_home, team_away, start_at, end_at)
(id, division, team_home, team_away, start_at, end_at)
VALUES
(
1,
'Game 1',
1, -- LV/D
1, -- Bullseye
2, -- Seecats
@ -12,7 +11,6 @@ VALUES
),
(
2,
'Game 2',
1, -- LV/D
1, -- Bullseye
2, -- Seecats
@ -21,7 +19,6 @@ VALUES
),
(
3,
'Game 3',
1, -- LV/D
1, -- Bullseye
2, -- Seecats
@ -30,10 +27,17 @@ VALUES
),
(
4,
'Game 4',
1, -- LV/D
1, -- Bullseye
2, -- Seecats
'2022-03-27 10:00:00 America/Toronto',
'2022-03-27 11:30:00 America/Toronto'
);
INSERT INTO game_names
(id, game, name, language)
VALUES
(1, 1, 'Game 1', 1),
(2, 2, 'Game 2', 1),
(3, 3, 'Game 3', 1),
(4, 4, 'Game 4', 1);

@ -0,0 +1,2 @@
-- Add down migration script here
DROP VIEW player_points_view;

@ -0,0 +1,25 @@
-- Add up migration script here
CREATE OR REPLACE VIEW player_points_view
AS SELECT
COUNT(shots.id) AS points,
COUNT(CASE WHEN shots.shooter = game_players.id THEN shots.id END) AS goals,
COUNT(CASE WHEN shots.assistant = game_players.id OR shots.assistant_second = game_players.id THEN shots.id END) AS assists,
periods.id AS period_id,
games.id AS game_id,
games.division AS division_id,
players.first_names,
players.last_name,
players.id
FROM players JOIN game_players
ON game_players.player = players.id
LEFT JOIN shots
ON shots.goal=true
AND (shots.shooter=game_players.id
OR shots.assistant=game_players.id
OR shots.assistant_second=game_players.id)
LEFT JOIN periods
ON periods.id=shots.period
LEFT JOIN games
ON games.id=periods.game
GROUP BY
players.id,division_id,game_id,period_id;

@ -0,0 +1,2 @@
-- Add down migration script here
DROP VIEW team_points_view;

@ -0,0 +1,28 @@
-- Add up migration script here
CREATE OR REPLACE VIEW team_points_view
AS SELECT
teams.id AS team_id,
games.id AS game_id,
games.division AS division_id,
divisions.league AS league_id,
reg_win(games.id, teams.id) AS reg_wins,
reg_loss(games.id, teams.id) AS reg_losses,
ot_win(games.id, teams.id) AS ot_wins,
ot_loss(games.id, teams.id) AS ot_losses,
tie(games.id, teams.id) AS ties,
iihf_points(games.id, teams.id) AS points
FROM games
JOIN divisions
ON divisions.id=games.division
JOIN periods
ON periods.game=games.id
JOIN shots
ON shots.period=periods.id
JOIN game_players
ON game_players.id=shots.shooter
JOIN teams scoring_team
ON scoring_team.id=game_players.team
JOIN teams
ON teams.id=games.team_home
OR teams.id=games.team_away
GROUP BY team_id,game_id,division_id,league_id;

@ -0,0 +1,2 @@
-- Add down migration script here
DROP FUNCTION team_name(INTEGER, INTEGER);

@ -0,0 +1,17 @@
-- Add up migration script here
CREATE FUNCTION team_name(team_id INT, lang_id INT)
RETURNS TEXT
AS $$
SELECT
COALESCE(
MAX(a.name),
MAX(b.name),
MAX(c.name
)) AS name
FROM teams
LEFT JOIN team_names a ON a.team = teams.id AND a.language = lang_id
LEFT JOIN team_names b ON b.team = teams.id AND b.language = 1
LEFT JOIN team_names c ON c.team = teams.id
WHERE teams.id = team_id
GROUP BY teams.id;
$$ LANGUAGE SQL;

@ -0,0 +1,2 @@
-- Add down migration script here
DROP FUNCTION league_name(INTEGER, INTEGER);

@ -0,0 +1,17 @@
-- Add up migration script here
CREATE FUNCTION league_name(league_id INT, lang_id INT)
RETURNS TEXT
AS $$
SELECT
COALESCE(
MAX(a.name),
MAX(b.name),
MAX(c.name
)) AS name
FROM leagues
LEFT JOIN league_names a ON a.league = leagues.id AND a.language = lang_id
LEFT JOIN league_names b ON b.league = leagues.id AND b.language = 1
LEFT JOIN league_names c ON c.league = leagues.id
WHERE leagues.id = league_id
GROUP BY leagues.id;
$$ LANGUAGE SQL;

@ -0,0 +1,2 @@
-- Add down migration script here
DROP FUNCTION division_name(INTEGER, INTEGER);

@ -0,0 +1,17 @@
-- Add up migration script here
CREATE FUNCTION division_name(division_id INT, lang_id INT)
RETURNS TEXT
AS $$
SELECT
COALESCE(
MAX(a.name),
MAX(b.name),
MAX(c.name
)) AS name
FROM divisions
LEFT JOIN division_names a ON a.division = divisions.id AND a.language = lang_id
LEFT JOIN division_names b ON b.division = divisions.id AND b.language = 1
LEFT JOIN division_names c ON c.division = divisions.id
WHERE divisions.id = division_id
GROUP BY divisions.id;
$$ LANGUAGE SQL;

@ -0,0 +1,2 @@
-- Add down migration script here
DROP FUNCTION game_name(INTEGER, INTEGER);

@ -0,0 +1,17 @@
-- Add up migration script here
CREATE FUNCTION game_name(game_id INT, lang_id INT)
RETURNS TEXT
AS $$
SELECT
COALESCE(
MAX(a.name),
MAX(b.name),
MAX(c.name
)) AS name
FROM games
LEFT JOIN game_names a ON a.game = games.id AND a.language = lang_id
LEFT JOIN game_names b ON b.game = games.id AND b.language = 1
LEFT JOIN game_names c ON c.game = games.id
WHERE games.id = game_id
GROUP BY games.id;
$$ LANGUAGE SQL;
Loading…
Cancel
Save