Skip to content

Commit

Permalink
site: player: Show first as well as last competition under teams
Browse files Browse the repository at this point in the history
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 <[email protected]>
  • Loading branch information
Forty-Bot committed Nov 25, 2023
1 parent c24ab48 commit 2dc2484
Show file tree
Hide file tree
Showing 5 changed files with 122 additions and 35 deletions.
7 changes: 7 additions & 0 deletions trends/importer/league.py
Original file line number Diff line number Diff line change
Expand Up @@ -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 (
Expand Down
19 changes: 19 additions & 0 deletions trends/migrations/competition_scheduled.sql
Original file line number Diff line number Diff line change
@@ -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;
3 changes: 3 additions & 0 deletions trends/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
);

Expand Down
104 changes: 75 additions & 29 deletions trends/site/player.py
Original file line number Diff line number Diff line change
Expand Up @@ -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()
Expand Down Expand Up @@ -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)
Expand Down
24 changes: 18 additions & 6 deletions trends/site/templates/macros/teams.html
Original file line number Diff line number Diff line change
Expand Up @@ -8,15 +8,19 @@
<tr>
<th>League</th>
<th>Team</th>
<th>Most-recent Competition</th>
<th>Competitions</th>
<th><abbr title="Division of most-recent competition">
Division
</abbr></th>
<th><abbr title="Format of most-recent competition">
Format
</abbr></th>
<th><abbr title="Most-recent join date">Rostered From</abbr></th>
<th><abbr title="Most-recent leave date">Rostered To</abbr></th>
<th><abbr title="Join date for least-recent competition">
Rostered From
</abbr></th>
<th><abbr title="Leave date for most-recent competition">
Rostered To
</abbr></th>
</tr>
</thead>
<tbody>
Expand All @@ -33,9 +37,17 @@
</a></td>
<td class="left">
<a href="{{ url_for('league.comp.overview', league=team['league'],
compid=team['compid']) }}">
{{ team['comp'] }}
</a></td>
compid=team['compid2']) }}">
{{ team['comp2'] }}
</a>
{% if team['compid1'] != team['compid2'] %}
to
<a href="{{ url_for('league.comp.overview', league=team['league'],
compid=team['compid1']) }}">
{{ team['comp1'] }}
</a>
{% endif %}
</td>
<td class="left">{{ team['div'] if team['div'] != None }}</td>
<td class="left">{{ format_map[team['format']] }}</td>
{{ date_col(team['from']) }}
Expand Down

0 comments on commit 2dc2484

Please sign in to comment.