From 2dc24846acc54df19d4fdbda2241e3699f664a96 Mon Sep 17 00:00:00 2001 From: Sean Anderson Date: Sat, 25 Nov 2023 11:32:35 -0500 Subject: [PATCH] site: player: Show first as well as last competition under teams It's a bit confusing to show only the most-recent competition for a player, especially if they have been rostered for multiple competitions. Show the last-recent competition as well, to give a better overview of how long they have been on the team. Finding the maximal/minimal row is such a pain to do in SQL. Switch from the previous method of using window functions to using a CTE and multiple selects. While window functions work fine for grabbing either the minimum or maximum, they are really terrible for grabbing both (especially when there are NULL rows to ignore. To ensure we don't do a sequential scan on matches, denormalize the first/last scheduled date into competition. Signed-off-by: Sean Anderson --- trends/importer/league.py | 7 ++ trends/migrations/competition_scheduled.sql | 19 ++++ trends/schema.sql | 3 + trends/site/player.py | 104 ++++++++++++++------ trends/site/templates/macros/teams.html | 24 +++-- 5 files changed, 122 insertions(+), 35 deletions(-) create mode 100644 trends/migrations/competition_scheduled.sql diff --git a/trends/importer/league.py b/trends/importer/league.py index fc7d33d..230a8c2 100644 --- a/trends/importer/league.py +++ b/trends/importer/league.py @@ -292,6 +292,13 @@ def import_match(c, m): (SELECT round_nameid FROM round_name WHERE round = %(round)s) ) ON CONFLICT DO NOTHING;""", m) + c.execute(""" + UPDATE competition + SET + scheduled_from = least(scheduled_from, %(scheduled)s::BIGINT), + scheduled_to = greatest(scheduled_to, %(scheduled)s::BIGINT) + WHERE league = %(league)s + AND compid = %(compid)s;""", m) c.execute("INSERT INTO map (map) SELECT unnest(%(maps)s::TEXT[]) ON CONFLICT DO NOTHING;", m) c.execute( """INSERT INTO match ( diff --git a/trends/migrations/competition_scheduled.sql b/trends/migrations/competition_scheduled.sql new file mode 100644 index 0000000..b92be34 --- /dev/null +++ b/trends/migrations/competition_scheduled.sql @@ -0,0 +1,19 @@ +BEGIN; +ALTER TABLE competition +ADD scheduled_from BIGINT, +ADD scheduled_to BIGINT, +ADD CHECK (equal(scheduled_from ISNULL, scheduled_to ISNULL)); +CREATE TEMP TABLE new AS SELECT + league, + compid, + min(scheduled) AS scheduled_from, + max(scheduled) AS scheduled_to +FROM match +GROUP BY league, compid; +UPDATE competition AS comp +SET + scheduled_from = new.scheduled_from, + scheduled_to = new.scheduled_to +FROM new +WHERE comp.league = new.league AND comp.compid = new.compid; +COMMIT; diff --git a/trends/schema.sql b/trends/schema.sql index fdddd4a..9fe323f 100644 --- a/trends/schema.sql +++ b/trends/schema.sql @@ -135,6 +135,9 @@ CREATE TABLE IF NOT EXISTS competition ( compid INT NOT NULL, formatid INT NOT NULL REFERENCES format (formatid), name TEXT NOT NULL, + scheduled_from BIGINT, + scheduled_to BIGINT, + CHECK (equal(scheduled_from ISNULL, scheduled_to ISNULL)), PRIMARY KEY (league, compid) ); diff --git a/trends/site/player.py b/trends/site/player.py index a872c35..d391acf 100644 --- a/trends/site/player.py +++ b/trends/site/player.py @@ -139,56 +139,102 @@ def get_logs(c, playerid, filters, duplicates=True, order_clause="logid DESC", l }) return logs -def get_teams(c, filters, order_clause="upper(rostered) DESC", limit=10, offset=0): +def get_teams(c, filters, order_clause="rto DESC", limit=10, offset=0): inner_clauses = get_filter_clauses(filters, 'league', date_range='rostered') outer_clauses = get_filter_clauses(filters, 'formatid') teams = c.cursor() teams.execute( - """SELECT - league, - format, - competition.name AS comp, - competition.compid, - division AS div, - team, - teamid, - lower(rostered) AS from, - upper(rostered) AS to - FROM (SELECT + """WITH t AS (SELECT tc.league, - tc.compid, + tc.compid AS compid, + comp.compid AS ccompid, tc.teamid, + tc.team_nameid, divid, - team_name AS team, rostered, - rank() OVER ( - PARTITION BY tc.league, tc.teamid - ORDER BY tc.league, tc.compid DESC - ) AS r + comp.scheduled FROM (SELECT league, teamid, compid, - range_max(rostered) AS rostered + range_agg(rostered) AS rostered FROM team_player WHERE playerid = %(playerid)s {} GROUP BY league, teamid, compid ) AS tp - JOIN team_comp AS tc ON ( + JOIN team_comp_backing AS tc ON ( tp.league = tc.league AND tp.teamid = tc.teamid AND (NOT league_team_per_comp(tc.league) OR tp.compid = tc.compid) - )) AS teams - JOIN competition USING (league, compid) - JOIN format USING (formatid) - LEFT JOIN division USING (league, divid) - LEFT JOIN div_name USING (div_nameid) - WHERE r = 1 + ) LEFT JOIN (SELECT + league, + compid, + int8range(scheduled_from, scheduled_to, '[]') AS scheduled + FROM competition + WHERE scheduled_from NOTNULL + ) AS comp ON ( + tp.league = comp.league + AND NOT league_team_per_comp(tc.league) + AND tc.compid = comp.compid AND tp.rostered && comp.scheduled + ) + ) SELECT + league, + format, + l.comp AS comp2, + l.compid AS compid2, + u.comp AS comp1, + u.compid AS compid1, + div, + team, + teamid, + rfrom AS from, + rto AS to + FROM (SELECT + league, + teamid, + coalesce(t.team_nameid, league_team.team_nameid) AS team_nameid, + competition.compid, + competition.name AS comp, + format, + division AS div, + upper(rostered) AS rto + FROM (SELECT + league, + teamid, + coalesce(max(ccompid), max(compid)) as compid + FROM t + GROUP BY league, teamid + ) AS u + JOIN t USING (league, teamid, compid) + JOIN competition USING (league, compid) + JOIN format USING (formatid) + LEFT JOIN division USING (league, divid) + LEFT JOIN div_name USING (div_nameid) + JOIN league_team USING (league, teamid) + WHERE TRUE {} - ORDER BY {} + ) AS u + JOIN (SELECT + league, + teamid, + compid, + competition.name AS comp, + lower(rostered) AS rfrom + FROM (SELECT + league, + teamid, + coalesce(min(ccompid), min(compid)) as compid + FROM t + GROUP BY league, teamid + ) AS l + JOIN t USING (league, teamid, compid) + JOIN competition USING (league, compid) + ) AS l USING (league, teamid) + JOIN team_name USING (team_nameid) + ORDER BY {}, rfrom DESC, u.compid DESC, l.compid DESC LIMIT %(limit)s OFFSET %(offset)s;""".format(inner_clauses, outer_clauses, order_clause), { 'playerid': flask.g.playerid, 'limit': limit, 'offset': offset, **filters }) return teams.fetchall() @@ -314,8 +360,8 @@ def teams(steamid): limit, offset = get_pagination() filters = get_filter_params() order, order_clause = get_order({ - 'to': "upper(rostered)", - 'from': "lower(rostered)", + 'to': "rto", + 'from': "rfrom", }, 'to') teams = get_teams(get_db(), get_filter_params(), order_clause, limit=limit, offset=offset) return flask.render_template("player/teams.html", teams=teams) diff --git a/trends/site/templates/macros/teams.html b/trends/site/templates/macros/teams.html index f853e10..2bed177 100644 --- a/trends/site/templates/macros/teams.html +++ b/trends/site/templates/macros/teams.html @@ -8,15 +8,19 @@ League Team - Most-recent Competition + Competitions Division Format - Rostered From - Rostered To + + Rostered From + + + Rostered To + @@ -33,9 +37,17 @@ - {{ team['comp'] }} - + compid=team['compid2']) }}"> + {{ team['comp2'] }} + + {% if team['compid1'] != team['compid2'] %} + to + + {{ team['comp1'] }} + + {% endif %} + {{ team['div'] if team['div'] != None }} {{ format_map[team['format']] }} {{ date_col(team['from']) }}