From 4019823dd796ef0a40edc01c3e81301cec914875 Mon Sep 17 00:00:00 2001 From: Tait Hoyem Date: Thu, 6 Apr 2023 17:58:38 -0600 Subject: [PATCH] Update migrations, move translations from xml to JSON --- .env | 2 +- README.md | 10 ++ .../20230327021922_add_period_types.down.sql | 3 +- ...230327025718_create_game_players.down.sql} | 0 ...20230327025718_create_game_players.up.sql} | 0 .../20230327025719_add_game_players.down.sql | 3 +- .../20230327025719_add_game_players.up.sql | 118 +++++++++++++++++- .../20230327235842_add_periods.down.sql | 3 +- migrations/20230327235842_add_periods.up.sql | 14 ++- ...405014220_create_periods_function.down.sql | 1 + ...30405014220_create_periods_function.up.sql | 6 + ...014229_create_iihf_stats_per_game.down.sql | 2 + ...05014229_create_iihf_stats_per_game.up.sql | 99 +++++++++++++++ ...30406194600_create_goals_function.down.sql | 2 + ...0230406194600_create_goals_function.up.sql | 32 +++++ ...195200_create_iihf_stats_function.down.sql | 2 + ...06195200_create_iihf_stats_function.up.sql | 46 +++++++ ...95840_create_iihf_points_function.down.sql | 2 + ...6195840_create_iihf_points_function.up.sql | 14 +++ src/db.rs | 2 +- src/views.rs | 109 ++++++++++++++-- templates/division_list.html | 6 + templates/game_list.html | 26 ++-- templates/game_score_page.html | 6 + templates/league_list.html | 6 + templates/master.html | 16 +++ translations/en.json | 11 ++ translations/fr.json | 11 ++ 28 files changed, 524 insertions(+), 28 deletions(-) create mode 100644 README.md rename migrations/{20230327025718_add_game_players.down.sql => 20230327025718_create_game_players.down.sql} (100%) rename migrations/{20230327025718_add_game_players.up.sql => 20230327025718_create_game_players.up.sql} (100%) create mode 100644 migrations/20230405014220_create_periods_function.down.sql create mode 100644 migrations/20230405014220_create_periods_function.up.sql create mode 100644 migrations/20230405014229_create_iihf_stats_per_game.down.sql create mode 100644 migrations/20230405014229_create_iihf_stats_per_game.up.sql create mode 100644 migrations/20230406194600_create_goals_function.down.sql create mode 100644 migrations/20230406194600_create_goals_function.up.sql create mode 100644 migrations/20230406195200_create_iihf_stats_function.down.sql create mode 100644 migrations/20230406195200_create_iihf_stats_function.up.sql create mode 100644 migrations/20230406195840_create_iihf_points_function.down.sql create mode 100644 migrations/20230406195840_create_iihf_points_function.up.sql create mode 100644 templates/master.html create mode 100644 translations/en.json create mode 100644 translations/fr.json diff --git a/.env b/.env index e147f8d..b4716b5 100644 --- a/.env +++ b/.env @@ -1 +1 @@ -export DATABASE_URL="postgresql://ibihf2:ibihf@localhost/ibihf" +export DATABASE_URL="postgresql://ibihf:ibihf@localhost/ibihf" diff --git a/README.md b/README.md new file mode 100644 index 0000000..996ba20 --- /dev/null +++ b/README.md @@ -0,0 +1,10 @@ +# IBIHF Statistics System + +This is the official system of the International Blind Ice Hockey Federation, +and their stats website can be found live at [stats.ibihf.org](https://stats.ibihf.org/). + +## Database Inforamtion + +All migrations can be applied in order of the UNIX timestamp identifier before the name of the migrations. +These `*.sql` files are valid for the Postgres database. + diff --git a/migrations/20230327021922_add_period_types.down.sql b/migrations/20230327021922_add_period_types.down.sql index b5f0b53..628d811 100644 --- a/migrations/20230327021922_add_period_types.down.sql +++ b/migrations/20230327021922_add_period_types.down.sql @@ -1 +1,2 @@ -DELETE FROM period_types; +DELETE FROM period_types +WHERE id BETWEEN 1 AND 13; diff --git a/migrations/20230327025718_add_game_players.down.sql b/migrations/20230327025718_create_game_players.down.sql similarity index 100% rename from migrations/20230327025718_add_game_players.down.sql rename to migrations/20230327025718_create_game_players.down.sql diff --git a/migrations/20230327025718_add_game_players.up.sql b/migrations/20230327025718_create_game_players.up.sql similarity index 100% rename from migrations/20230327025718_add_game_players.up.sql rename to migrations/20230327025718_create_game_players.up.sql diff --git a/migrations/20230327025719_add_game_players.down.sql b/migrations/20230327025719_add_game_players.down.sql index fd09597..860b499 100644 --- a/migrations/20230327025719_add_game_players.down.sql +++ b/migrations/20230327025719_add_game_players.down.sql @@ -1,2 +1,3 @@ -- Add down migration script here -DELETE FROM game_players; +DELETE FROM game_players +WHERE id BETWEEN 1 AND 116; diff --git a/migrations/20230327025719_add_game_players.up.sql b/migrations/20230327025719_add_game_players.up.sql index 58dd921..4923172 100644 --- a/migrations/20230327025719_add_game_players.up.sql +++ b/migrations/20230327025719_add_game_players.up.sql @@ -1,8 +1,9 @@ -- Add up migration script here INSERT INTO game_players - (team, player, position, player_number, game) + (id, team, player, position, player_number, game) VALUES ( + 1, 1, 31, 1, @@ -10,6 +11,7 @@ VALUES 1 ), ( + 2, 1, 1, 3, @@ -17,6 +19,7 @@ VALUES 1 ), ( + 3, 1, 2, 4, @@ -24,6 +27,7 @@ VALUES 1 ), ( + 4, 1, 3, 5, @@ -31,6 +35,7 @@ VALUES 1 ), ( + 5, 1, 4, 2, @@ -38,6 +43,7 @@ VALUES 1 ), ( + 6, 1, 5, 4, @@ -45,6 +51,7 @@ VALUES 1 ), ( + 7, 1, 7, 1, @@ -52,6 +59,7 @@ VALUES 1 ), ( + 8, 1, 8, 4, @@ -59,6 +67,7 @@ VALUES 1 ), ( + 9, 1, 9, 3, @@ -66,6 +75,7 @@ VALUES 1 ), ( + 10, 1, 10, 1, @@ -73,6 +83,7 @@ VALUES 1 ), ( + 11, 1, 11, 2, @@ -80,6 +91,7 @@ VALUES 1 ), ( + 12, 2, 12, 5, @@ -87,6 +99,7 @@ VALUES 1 ), ( + 13, 2, 13, 5, @@ -94,6 +107,7 @@ VALUES 1 ), ( + 14, 2, 14, 1, @@ -101,6 +115,7 @@ VALUES 1 ), ( + 15, 2, 15, 2, @@ -108,6 +123,7 @@ VALUES 1 ), ( + 16, 2, 16, 1, @@ -115,6 +131,7 @@ VALUES 1 ), ( + 17, 2, 17, 2, @@ -122,6 +139,7 @@ VALUES 1 ), ( + 18, 2, 18, 4, @@ -129,6 +147,7 @@ VALUES 1 ), ( + 19, 2, 19, 4, @@ -136,6 +155,7 @@ VALUES 1 ), ( + 20, 2, 21, 4, @@ -143,6 +163,7 @@ VALUES 1 ), ( + 21, 2, 22, 4, @@ -150,6 +171,7 @@ VALUES 1 ), ( + 22, 2, 23, 2, @@ -157,6 +179,7 @@ VALUES 1 ), ( + 23, 2, 24, 7, @@ -164,6 +187,7 @@ VALUES 1 ), ( + 24, 2, 25, 7, @@ -171,6 +195,7 @@ VALUES 1 ), ( + 25, 2, 26, 7, @@ -178,6 +203,7 @@ VALUES 1 ), ( + 26, 1, 27, 7, @@ -185,6 +211,7 @@ VALUES 1 ), ( + 27, 1, 28, 7, @@ -192,6 +219,7 @@ VALUES 1 ), ( + 28, 1, 29, 7, @@ -199,6 +227,7 @@ VALUES 1 ), ( + 29, 1, 30, 7, @@ -206,6 +235,7 @@ VALUES 1 ), ( + 30, 1, 31, 1, @@ -213,6 +243,7 @@ VALUES 2 ), ( + 31, 1, 1, 3, @@ -220,6 +251,7 @@ VALUES 2 ), ( + 32, 1, 2, 4, @@ -227,6 +259,7 @@ VALUES 2 ), ( + 33, 1, 3, 5, @@ -234,6 +267,7 @@ VALUES 2 ), ( + 34, 1, 4, 2, @@ -241,6 +275,7 @@ VALUES 2 ), ( + 35, 1, 5, 4, @@ -248,6 +283,7 @@ VALUES 2 ), ( + 36, 1, 7, 1, @@ -255,6 +291,7 @@ VALUES 2 ), ( + 37, 1, 8, 4, @@ -262,6 +299,7 @@ VALUES 2 ), ( + 38, 1, 9, 3, @@ -269,6 +307,7 @@ VALUES 2 ), ( + 39, 1, 10, 1, @@ -276,6 +315,7 @@ VALUES 2 ), ( + 40, 1, 11, 2, @@ -283,6 +323,7 @@ VALUES 2 ), ( + 41, 2, 12, 5, @@ -290,6 +331,7 @@ VALUES 2 ), ( + 42, 2, 13, 5, @@ -297,6 +339,7 @@ VALUES 2 ), ( + 43, 2, 14, 1, @@ -304,6 +347,7 @@ VALUES 2 ), ( + 44, 2, 15, 2, @@ -311,6 +355,7 @@ VALUES 2 ), ( + 45, 2, 16, 1, @@ -318,6 +363,7 @@ VALUES 2 ), ( + 46, 2, 17, 2, @@ -325,6 +371,7 @@ VALUES 2 ), ( + 47, 2, 18, 4, @@ -332,6 +379,7 @@ VALUES 2 ), ( + 48, 2, 19, 4, @@ -339,6 +387,7 @@ VALUES 2 ), ( + 49, 2, 21, 4, @@ -346,6 +395,7 @@ VALUES 2 ), ( + 50, 2, 22, 4, @@ -353,6 +403,7 @@ VALUES 2 ), ( + 51, 2, 23, 2, @@ -360,6 +411,7 @@ VALUES 2 ), ( + 52, 2, 24, 7, @@ -367,6 +419,7 @@ VALUES 2 ), ( + 53, 2, 25, 7, @@ -374,6 +427,7 @@ VALUES 2 ), ( + 54, 2, 26, 7, @@ -381,6 +435,7 @@ VALUES 2 ), ( + 55, 1, 27, 7, @@ -388,6 +443,7 @@ VALUES 2 ), ( + 56, 1, 28, 7, @@ -395,6 +451,7 @@ VALUES 2 ), ( + 57, 1, 29, 7, @@ -402,6 +459,7 @@ VALUES 2 ), ( + 58, 1, 30, 7, @@ -409,6 +467,7 @@ VALUES 2 ), ( + 59, 1, 31, 1, @@ -416,6 +475,7 @@ VALUES 3 ), ( + 60, 1, 1, 3, @@ -423,6 +483,7 @@ VALUES 3 ), ( + 61, 1, 2, 4, @@ -430,6 +491,7 @@ VALUES 3 ), ( + 62, 1, 3, 5, @@ -437,6 +499,7 @@ VALUES 3 ), ( + 63, 1, 4, 2, @@ -444,6 +507,7 @@ VALUES 3 ), ( + 64, 1, 5, 4, @@ -451,6 +515,7 @@ VALUES 3 ), ( + 65, 1, 7, 1, @@ -458,6 +523,7 @@ VALUES 3 ), ( + 66, 1, 8, 4, @@ -465,6 +531,7 @@ VALUES 3 ), ( + 67, 1, 9, 3, @@ -472,6 +539,7 @@ VALUES 3 ), ( + 68, 1, 10, 1, @@ -479,6 +547,7 @@ VALUES 3 ), ( + 69, 1, 11, 2, @@ -486,6 +555,7 @@ VALUES 3 ), ( + 70, 2, 12, 5, @@ -493,6 +563,7 @@ VALUES 3 ), ( + 71, 2, 13, 5, @@ -500,6 +571,7 @@ VALUES 3 ), ( + 72, 2, 14, 1, @@ -507,6 +579,7 @@ VALUES 3 ), ( + 73, 2, 15, 2, @@ -514,6 +587,7 @@ VALUES 3 ), ( + 74, 2, 16, 1, @@ -521,6 +595,7 @@ VALUES 3 ), ( + 75, 2, 17, 2, @@ -528,6 +603,7 @@ VALUES 3 ), ( + 76, 2, 18, 4, @@ -535,6 +611,7 @@ VALUES 3 ), ( + 77, 2, 19, 4, @@ -542,6 +619,7 @@ VALUES 3 ), ( + 78, 2, 21, 4, @@ -549,6 +627,7 @@ VALUES 3 ), ( + 79, 2, 22, 4, @@ -556,6 +635,7 @@ VALUES 3 ), ( + 80, 2, 23, 2, @@ -563,6 +643,7 @@ VALUES 3 ), ( + 81, 2, 24, 7, @@ -570,6 +651,7 @@ VALUES 3 ), ( + 82, 2, 25, 7, @@ -577,6 +659,7 @@ VALUES 3 ), ( + 83, 2, 26, 7, @@ -584,6 +667,7 @@ VALUES 3 ), ( + 84, 1, 27, 7, @@ -591,6 +675,7 @@ VALUES 3 ), ( + 85, 1, 28, 7, @@ -598,6 +683,7 @@ VALUES 3 ), ( + 86, 1, 29, 7, @@ -605,6 +691,7 @@ VALUES 3 ), ( + 87, 1, 30, 7, @@ -612,6 +699,7 @@ VALUES 3 ), ( + 88, 1, 31, 1, @@ -619,6 +707,7 @@ VALUES 4 ), ( + 89, 1, 1, 3, @@ -626,6 +715,7 @@ VALUES 4 ), ( + 90, 1, 2, 4, @@ -633,6 +723,7 @@ VALUES 4 ), ( + 91, 1, 3, 5, @@ -640,6 +731,7 @@ VALUES 4 ), ( + 92, 1, 4, 2, @@ -647,6 +739,7 @@ VALUES 4 ), ( + 93, 1, 5, 4, @@ -654,6 +747,7 @@ VALUES 4 ), ( + 94, 1, 7, 1, @@ -661,6 +755,7 @@ VALUES 4 ), ( + 95, 1, 8, 4, @@ -668,6 +763,7 @@ VALUES 4 ), ( + 96, 1, 9, 3, @@ -675,6 +771,7 @@ VALUES 4 ), ( + 97, 1, 10, 1, @@ -682,6 +779,7 @@ VALUES 4 ), ( + 98, 1, 11, 2, @@ -689,6 +787,7 @@ VALUES 4 ), ( + 99, 2, 12, 5, @@ -696,6 +795,7 @@ VALUES 4 ), ( + 100, 2, 13, 5, @@ -703,6 +803,7 @@ VALUES 4 ), ( + 101, 2, 14, 1, @@ -710,6 +811,7 @@ VALUES 4 ), ( + 102, 2, 15, 2, @@ -717,6 +819,7 @@ VALUES 4 ), ( + 103, 2, 16, 1, @@ -724,6 +827,7 @@ VALUES 4 ), ( + 104, 2, 17, 2, @@ -731,6 +835,7 @@ VALUES 4 ), ( + 105, 2, 18, 4, @@ -738,6 +843,7 @@ VALUES 4 ), ( + 106, 2, 19, 4, @@ -745,6 +851,7 @@ VALUES 4 ), ( + 107, 2, 21, 4, @@ -752,6 +859,7 @@ VALUES 4 ), ( + 108, 2, 22, 4, @@ -759,6 +867,7 @@ VALUES 4 ), ( + 109, 2, 23, 2, @@ -766,6 +875,7 @@ VALUES 4 ), ( + 110, 2, 24, 7, @@ -773,6 +883,7 @@ VALUES 4 ), ( + 111, 2, 25, 7, @@ -780,6 +891,7 @@ VALUES 4 ), ( + 112, 2, 26, 7, @@ -787,6 +899,7 @@ VALUES 4 ), ( + 113, 1, 27, 7, @@ -794,6 +907,7 @@ VALUES 4 ), ( + 114, 1, 28, 7, @@ -801,6 +915,7 @@ VALUES 4 ), ( + 115, 1, 29, 7, @@ -808,6 +923,7 @@ VALUES 4 ), ( + 116, 1, 30, 7, diff --git a/migrations/20230327235842_add_periods.down.sql b/migrations/20230327235842_add_periods.down.sql index 3035fb5..8f9aedf 100644 --- a/migrations/20230327235842_add_periods.down.sql +++ b/migrations/20230327235842_add_periods.down.sql @@ -1 +1,2 @@ -DELETE FROM periods; +DELETE FROM periods +WHERE id BETWEEN 1 AND 12; diff --git a/migrations/20230327235842_add_periods.up.sql b/migrations/20230327235842_add_periods.up.sql index c69f100..0832d50 100644 --- a/migrations/20230327235842_add_periods.up.sql +++ b/migrations/20230327235842_add_periods.up.sql @@ -1,62 +1,74 @@ INSERT INTO periods - (game, period_type, period_length) + (id, game, period_type, period_length) VALUES ( + 1, 1, 1, 1200 ), ( + 2, 1, 2, 900 ), ( + 3, 1, 3, 900 ), ( + 4, 2, 1, 1200 ), ( + 5, 2, 2, 1200 ), ( + 6, 2, 3, 1200 ), ( + 7, 3, 1, 720 ), ( + 8, 3, 2, 720 ), ( + 9, 3, 3, 1200 ), ( + 10, 4, 1, 1200 ), ( + 11, 4, 2, 1200 ), ( + 12, 4, 3, 1200 diff --git a/migrations/20230405014220_create_periods_function.down.sql b/migrations/20230405014220_create_periods_function.down.sql new file mode 100644 index 0000000..92743a5 --- /dev/null +++ b/migrations/20230405014220_create_periods_function.down.sql @@ -0,0 +1 @@ +DROP FUNCTION periods(INTEGER); diff --git a/migrations/20230405014220_create_periods_function.up.sql b/migrations/20230405014220_create_periods_function.up.sql new file mode 100644 index 0000000..d3dce3c --- /dev/null +++ b/migrations/20230405014220_create_periods_function.up.sql @@ -0,0 +1,6 @@ +CREATE FUNCTION periods(game_id INTEGER) +RETURNS INTEGER AS $$ +BEGIN + RETURN (SELECT COUNT(id) FROM periods WHERE periods.game=game_id); +END; +$$ LANGUAGE plpgsql; diff --git a/migrations/20230405014229_create_iihf_stats_per_game.down.sql b/migrations/20230405014229_create_iihf_stats_per_game.down.sql new file mode 100644 index 0000000..093fb5b --- /dev/null +++ b/migrations/20230405014229_create_iihf_stats_per_game.down.sql @@ -0,0 +1,2 @@ +-- Add down migration script here +--DROP FUNCTION game_results(INTEGER, INTEGER); diff --git a/migrations/20230405014229_create_iihf_stats_per_game.up.sql b/migrations/20230405014229_create_iihf_stats_per_game.up.sql new file mode 100644 index 0000000..94795da --- /dev/null +++ b/migrations/20230405014229_create_iihf_stats_per_game.up.sql @@ -0,0 +1,99 @@ +-- Add up migration script here +--CREATE FUNCTION periods(game_id INTEGER) +--RETURNS INTEGER AS $$ +--BEGIN +-- RETURN (SELECT COUNT(id) FROM periods WHERE periods.game=game_id); +--END; +--$$ LANGUAGE plpgsql; +-- +--CREATE FUNCTION goals(game_id INTEGER, team_id INTEGER) +--RETURNS INTEGER AS $$ +--DECLARE +-- goals INTEGER; +--BEGIN +-- IF NOT EXISTS (SELECT * FROM games WHERE games.id=game_id) THEN +-- RAISE EXCEPTION 'The game does not exist.'; +-- END IF; +-- IF NOT EXISTS (SELECT * FROM teams WHERE teams.id=team_id) THEN +-- RAISE EXCEPTION 'The team does not exist.'; +-- END IF; +-- IF NOT EXISTS (SELECT * FROM games JOIN teams ON teams.id=games.team_home OR teams.id=team_away WHERE games.id=game_id) THEN +-- RAISE EXCEPTION 'The team specified did not play this game.'; +-- END IF; +-- +-- SELECT +-- COUNT(shots.id) +-- INTO +-- goals +-- FROM shots +-- JOIN game_players +-- ON game_players.id=shots.shooter +-- JOIN periods +-- ON periods.id=shots.period +-- WHERE shots.goal=true +-- AND game_players.team=team_id +-- AND periods.game=game_id; +-- -- return 0 if not goals are found given the team and the game +-- RETURN COALESCE(goals, 0); +--END; +--$$ LANGUAGE plpgsql; +-- +--CREATE OR REPLACE FUNCTION calculate_iihf_stats(game_id INT, team_id INT) +--RETURNS TABLE ( +-- reg_win INT, +-- reg_loss INT, +-- ot_win INT, +-- ot_loss INT, +-- tie INT, +-- game INT, +-- team INT +--) AS $$ +--DECLARE +-- opponent_team_id INTEGER; +--BEGIN +-- IF NOT EXISTS (SELECT * FROM games WHERE games.id=game_id) THEN +-- RAISE EXCEPTION 'The game does not exist.'; +-- END IF; +-- IF NOT EXISTS (SELECT * FROM teams WHERE teams.id=team_id) THEN +-- RAISE EXCEPTION 'The team does not exist.'; +-- END IF; +-- IF NOT EXISTS (SELECT * FROM games JOIN teams ON teams.id=games.team_home OR teams.id=team_away WHERE games.id=game_id) THEN +-- RAISE EXCEPTION 'The team specified did not play this game.'; +-- END IF; +-- +-- SELECT +-- teams.id +-- INTO +-- opponent_team_id +-- FROM games +-- JOIN teams +-- ON (teams.id=games.team_home +-- OR teams.id=games.team_away) +-- WHERE games.id=game_id +-- AND teams.id!=team_id; +-- +-- RETURN QUERY +-- SELECT +-- (CASE WHEN goals(game_id, team_id) > goals(game_id, opponent_team_id) AND periods(game_id) <= 3 THEN 1 ELSE 0 END) AS reg_win, +-- (CASE WHEN goals(game_id, team_id) < goals(game_id, opponent_team_id) AND periods(game_id) <= 3 THEN 1 ELSE 0 END) AS reg_loss, +-- (CASE WHEN goals(game_id, team_id) > goals(game_id, opponent_team_id) AND periods(game_id) > 3 THEN 1 ELSE 0 END) AS ot_win, +-- (CASE WHEN goals(game_id, team_id) < goals(game_id, opponent_team_id) AND periods(game_id) > 3 THEN 1 ELSE 0 END) AS ot_loss, +-- (CASE WHEN goals(game_id, team_id) = goals(game_id, opponent_team_id) THEN 1 ELSE 0 END) AS tie, +-- game_id AS game, +-- team_id AS team; +--END; +--$$ LANGUAGE plpgsql; +-- +--CREATE OR REPLACE FUNCTION calculate_iihf_points(game_id INT, team_id INT) +--RETURNS INTEGER AS $$ +--BEGIN +-- RETURN ( +-- SELECT +-- (iihs_stats.reg_win * 3) + +-- (iihs_stats.reg_loss * 0) + +-- (iihs_stats.ot_win * 2) + +-- (iihs_stats.ot_loss * 1) + +-- (iihs_stats.tie * 2) AS points +-- FROM calculate_iihs_stats_stats(game_id, team_id) iihs_stats); +--END; +--$$ LANGUAGE plpgsql; diff --git a/migrations/20230406194600_create_goals_function.down.sql b/migrations/20230406194600_create_goals_function.down.sql new file mode 100644 index 0000000..42bad98 --- /dev/null +++ b/migrations/20230406194600_create_goals_function.down.sql @@ -0,0 +1,2 @@ +-- Add down migration script here +DROP FUNCTION goals(INTEGER, INTEGER); diff --git a/migrations/20230406194600_create_goals_function.up.sql b/migrations/20230406194600_create_goals_function.up.sql new file mode 100644 index 0000000..b1a66cd --- /dev/null +++ b/migrations/20230406194600_create_goals_function.up.sql @@ -0,0 +1,32 @@ +-- Add up migration script here +CREATE FUNCTION goals(game_id INTEGER, team_id INTEGER) +RETURNS INTEGER AS $$ +DECLARE + goals INTEGER; +BEGIN + IF NOT EXISTS (SELECT * FROM games WHERE games.id=game_id) THEN + RAISE EXCEPTION 'The game does not exist.'; + END IF; + IF NOT EXISTS (SELECT * FROM teams WHERE teams.id=team_id) THEN + RAISE EXCEPTION 'The team does not exist.'; + END IF; + IF NOT EXISTS (SELECT * FROM games JOIN teams ON teams.id=games.team_home OR teams.id=team_away WHERE games.id=game_id) THEN + RAISE EXCEPTION 'The team specified did not play this game.'; + END IF; + + SELECT + COUNT(shots.id) + INTO + goals + FROM shots + JOIN game_players + ON game_players.id=shots.shooter + JOIN periods + ON periods.id=shots.period + WHERE shots.goal=true + AND game_players.team=team_id + AND periods.game=game_id; + -- return 0 if not goals are found given the team and the game + RETURN COALESCE(goals, 0); +END; +$$ LANGUAGE plpgsql; diff --git a/migrations/20230406195200_create_iihf_stats_function.down.sql b/migrations/20230406195200_create_iihf_stats_function.down.sql new file mode 100644 index 0000000..70a250a --- /dev/null +++ b/migrations/20230406195200_create_iihf_stats_function.down.sql @@ -0,0 +1,2 @@ +-- Add down migration script here +DROP FUNCTION iihf_stats(INTEGER, INTEGER); diff --git a/migrations/20230406195200_create_iihf_stats_function.up.sql b/migrations/20230406195200_create_iihf_stats_function.up.sql new file mode 100644 index 0000000..49cb98d --- /dev/null +++ b/migrations/20230406195200_create_iihf_stats_function.up.sql @@ -0,0 +1,46 @@ +-- Add up migration script here +CREATE OR REPLACE FUNCTION iihf_stats(game_id INT, team_id INT) +RETURNS TABLE ( + reg_win INT, + reg_loss INT, + ot_win INT, + ot_loss INT, + tie INT, + game INT, + team INT +) AS $$ +DECLARE + opponent_team_id INTEGER; +BEGIN + IF NOT EXISTS (SELECT * FROM games WHERE games.id=game_id) THEN + RAISE EXCEPTION 'The game does not exist.'; + END IF; + IF NOT EXISTS (SELECT * FROM teams WHERE teams.id=team_id) THEN + RAISE EXCEPTION 'The team does not exist.'; + END IF; + IF NOT EXISTS (SELECT * FROM games JOIN teams ON teams.id=games.team_home OR teams.id=team_away WHERE games.id=game_id) THEN + RAISE EXCEPTION 'The team specified did not play this game.'; + END IF; + + SELECT + teams.id + INTO + opponent_team_id + FROM games + JOIN teams + ON (teams.id=games.team_home + OR teams.id=games.team_away) + WHERE games.id=game_id + AND teams.id!=team_id; + + RETURN QUERY + SELECT + (CASE WHEN goals(game_id, team_id) > goals(game_id, opponent_team_id) AND periods(game_id) <= 3 THEN 1 ELSE 0 END) AS reg_win, + (CASE WHEN goals(game_id, team_id) < goals(game_id, opponent_team_id) AND periods(game_id) <= 3 THEN 1 ELSE 0 END) AS reg_loss, + (CASE WHEN goals(game_id, team_id) > goals(game_id, opponent_team_id) AND periods(game_id) > 3 THEN 1 ELSE 0 END) AS ot_win, + (CASE WHEN goals(game_id, team_id) < goals(game_id, opponent_team_id) AND periods(game_id) > 3 THEN 1 ELSE 0 END) AS ot_loss, + (CASE WHEN goals(game_id, team_id) = goals(game_id, opponent_team_id) THEN 1 ELSE 0 END) AS tie, + game_id AS game, + team_id AS team; +END; +$$ LANGUAGE plpgsql; diff --git a/migrations/20230406195840_create_iihf_points_function.down.sql b/migrations/20230406195840_create_iihf_points_function.down.sql new file mode 100644 index 0000000..7d6144a --- /dev/null +++ b/migrations/20230406195840_create_iihf_points_function.down.sql @@ -0,0 +1,2 @@ +-- Add down migration script here +DROP FUNCTION iihf_points(INTEGER, INTEGER); diff --git a/migrations/20230406195840_create_iihf_points_function.up.sql b/migrations/20230406195840_create_iihf_points_function.up.sql new file mode 100644 index 0000000..892880b --- /dev/null +++ b/migrations/20230406195840_create_iihf_points_function.up.sql @@ -0,0 +1,14 @@ +-- Add up migration script here +CREATE OR REPLACE FUNCTION iihf_points(game_id INT, team_id INT) +RETURNS INTEGER AS $$ +BEGIN + RETURN ( + SELECT + (iihs_stats.reg_win * 3) + + (iihs_stats.reg_loss * 0) + + (iihs_stats.ot_win * 2) + + (iihs_stats.ot_loss * 1) + + (iihs_stats.tie * 2) AS points + FROM calculate_iihs_stats_stats(game_id, team_id) iihs_stats); +END; +$$ LANGUAGE plpgsql; diff --git a/src/db.rs b/src/db.rs index 0ed89d8..e93fb94 100644 --- a/src/db.rs +++ b/src/db.rs @@ -4,6 +4,6 @@ use sqlx::postgres::PgPoolOptions; pub async fn connect() -> Pool { PgPoolOptions::new() .max_connections(8) - .connect("postgres://ibihf2:ibihf@localhost/ibihf").await + .connect("postgres://ibihf:ibihf@localhost/ibihf").await .unwrap() } diff --git a/src/views.rs b/src/views.rs index 710ced1..00d2874 100644 --- a/src/views.rs +++ b/src/views.rs @@ -20,7 +20,7 @@ pub struct TeamStats { pub struct IihfGameStats { pub team_name: String, pub team_id: i32, - pub points: i64, + pub points: i32, } #[derive(FromRow, Deserialize, Serialize, Debug)] @@ -109,20 +109,106 @@ impl Game { .fetch_all(pool) .await } + pub async fn iihf_stats(pool: &PgPool, game_id: i32) -> Result, sqlx::Error> { + let query = r#" + SELECT + (CASE WHEN + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id=teams.id + THEN shots.id + END) > + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id!=teams.id + THEN shots.id + END) + AND (SELECT COUNT(id) FROM periods WHERE periods.game=games.id) <= 3 + THEN 1 + ELSE 0 + END) AS reg_wins, + (CASE WHEN + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id=teams.id + THEN shots.id + END) < + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id!=teams.id + THEN shots.id + END) + AND (SELECT COUNT(id) FROM periods WHERE periods.game=games.id) <= 3 + THEN 1 + ELSE 0 + END) AS reg_losses, + (CASE WHEN + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id=teams.id + THEN shots.id + END) > + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id!=teams.id + THEN shots.id + END) + AND (SELECT COUNT(id) FROM periods WHERE periods.game=games.id) > 3 + THEN 1 + ELSE 0 + END) AS ot_wins, + (CASE WHEN + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id=teams.id + THEN shots.id + END) < + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id!=teams.id + THEN shots.id + END) + AND (SELECT COUNT(id) FROM periods WHERE periods.game=games.id) > 3 + THEN 1 + ELSE 0 + END) AS ot_losses, + (CASE WHEN + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id=teams.id + THEN shots.id + END) = + COUNT(CASE WHEN shots.goal=true + AND scoring_team.id!=teams.id + THEN shots.id + END) + THEN 1 + ELSE 0 + END) AS ties + FROM games + 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 + WHERE games.id=4 + GROUP BY teams.id,games.id; + "#; + sqlx::query_as::<_, IihfGameStats>(query) + .bind(game_id) + .fetch_all(pool) + .await + } /// Returns the number of points using IIHF scoring rules for each team. + /// NOTE: The algorithm used here requires that a 4th period is the "overtime"; + /// it does not check if there was only two periods, followed by an overtime. + /// This should be sufficient for most. pub async fn iihf_score(pool: &PgPool, game_id: i32) -> Result, sqlx::Error> { let query = r#" SELECT - COUNT(CASE WHEN shots.goal = true THEN shots.id END) AS points, - teams.id AS team_id, - teams.name AS team_name + calculate_iihf_points(games.id, teams.id) AS points, + teams.name AS team_name, + teams.id AS team_id FROM games - 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 ON teams.id=game_players.team + JOIN teams + ON teams.id=games.team_home + OR teams.id=games.team_away WHERE games.id=$1 - GROUP BY teams.id; + ORDER BY points; "#; sqlx::query_as::<_, IihfGameStats>(query) .bind(game_id) @@ -493,14 +579,15 @@ mod tests { fn check_iihf_score() { tokio_test::block_on(async move{ let pool = db_connect().await; - let game = Game::get(&pool, 1) + let game = Game::get(&pool, 4) .await .unwrap(); let score = Game::iihf_score(&pool, game.id) .await .unwrap(); - assert_eq!(score.get(0).unwrap().points, 3); + assert_eq!(score.get(0).unwrap().points, 2); assert_eq!(score.get(0).unwrap().team_name, "Bullseye"); + assert_eq!(score.get(1).unwrap().points, 2); }) } diff --git a/templates/division_list.html b/templates/division_list.html index 313acd1..227fe74 100644 --- a/templates/division_list.html +++ b/templates/division_list.html @@ -1,6 +1,12 @@ +{% extends "master.html" %} + +{% block title %}Divisions{% endblock %} + +{% block content %}

Divisions for the {{ league.name }}

+{% endblock %} diff --git a/templates/game_list.html b/templates/game_list.html index e447a85..eb61d3c 100644 --- a/templates/game_list.html +++ b/templates/game_list.html @@ -1,10 +1,16 @@ -

Games for {{ division.name }}

-{% if games.len() > 0 %} -
    - {% for game in games %} -
  1. {{ game.name }}
  2. - {% endfor %} -
-{% else %} -

No games have been recorded.

-{% endif %} +{% extends "master.html" %} + +{% block title %}Games{% endblock %} + +{% block content %} +

Games for {{ division.name }}

+ {% if games.len() > 0 %} +
    + {% for game in games %} +
  1. {{ game.name }}
  2. + {% endfor %} +
+ {% else %} +

No games have been recorded.

+ {% endif %} +{% endblock %} diff --git a/templates/game_score_page.html b/templates/game_score_page.html index d8dee08..77e1cca 100644 --- a/templates/game_score_page.html +++ b/templates/game_score_page.html @@ -1,3 +1,8 @@ +{% extends "master.html" %} + +{% block title %}{{ game.name }}{% endblock %} + +{% block content %}

{{ game.name }} of the {{ division.name }}

Team

{{ team_stats|safe }} @@ -7,3 +12,4 @@ {{ box_score|safe }}

Play-by-Play

{{ play_by_play|safe }} +{% endblock %} diff --git a/templates/league_list.html b/templates/league_list.html index 22bd5dc..ac64727 100644 --- a/templates/league_list.html +++ b/templates/league_list.html @@ -1,6 +1,12 @@ +{% extends "master.html" %} + +{% block title %}Leagues{% endblock %} + +{% block content %}

{{ heading }}

    {% for league in leagues %}
  1. {{ league.name }}
  2. {% endfor %}
+{% endblock %} diff --git a/templates/master.html b/templates/master.html new file mode 100644 index 0000000..e75a0e7 --- /dev/null +++ b/templates/master.html @@ -0,0 +1,16 @@ + + + + + + {% block title %}{% endblock %} | IBIHF Stats + {% block head %}{% endblock %} + + +
+
+ {% block content %}{% endblock %} +
+ + + diff --git a/translations/en.json b/translations/en.json new file mode 100644 index 0000000..54c9f7c --- /dev/null +++ b/translations/en.json @@ -0,0 +1,11 @@ +{ + "phrases": { + "urlGame": "game", + "urlDivision": "division", + "urlLeague": "league", + "ibihfLeagues": "IBIHF Leagues", + "goals": "Goals", + "assists": "Assists", + "period": "Period" + } +} diff --git a/translations/fr.json b/translations/fr.json new file mode 100644 index 0000000..9d6d839 --- /dev/null +++ b/translations/fr.json @@ -0,0 +1,11 @@ +{ + "phrases": { + "urlGame": "match", + "urlDivision": "division", + "urlLeague": "league", + "ibihfLeagues": "Leagues de FIDHS", + "goals": "But", + "assists": "Assisté", + "period": "Période" + } +}