Skip to content

Commit

Permalink
site: Add medic leaderboard
Browse files Browse the repository at this point in the history
In the same style as the generic leaderboard, add a leaderboard for medic
stats. The stats need a bit of massaging, especially since so many are
optional or derived. The info is not the best since it's so easy to mess up
the stats by e.g. running vaccinator. But it's better than drops.tf :)

Signed-off-by: Sean Anderson <[email protected]>
  • Loading branch information
Forty-Bot committed Apr 17, 2024
1 parent 6810213 commit 2245249
Show file tree
Hide file tree
Showing 8 changed files with 384 additions and 1 deletion.
31 changes: 31 additions & 0 deletions salt/backend.sls
Original file line number Diff line number Diff line change
Expand Up @@ -69,6 +69,29 @@
[Install]
WantedBy=timers.target

/etc/systemd/system/medic_refresh.service:
file.managed:
- contents: |
[Unit]
Description=Refresh medic leaderboard
[Service]
Type=oneshot
ExecStart=/usr/bin/psql -c 'REFRESH MATERIALIZED VIEW medic_cube' postgres:///trends
User=daemon

/etc/systemd/system/medic_refresh.timer:
file.managed:
- contents: |
[Unit]
Description=Daily medic leaderboard refresh
[Timer]
OnCalendar=7:30

[Install]
WantedBy=timers.target

/etc/systemd/system/map_refresh.service:
file.managed:
- contents: |
Expand Down Expand Up @@ -246,6 +269,8 @@ backend_services:
- /etc/systemd/system/player_import.service
- /etc/systemd/system/leaderboard_refresh.service
- /etc/systemd/system/leaderboard_refresh.timer
- /etc/systemd/system/medic_refresh.service
- /etc/systemd/system/medic_refresh.timer
- /etc/systemd/system/map_refresh.service
- /etc/systemd/system/map_refresh.timer
- /etc/systemd/system/weapon_import.service
Expand Down Expand Up @@ -279,6 +304,12 @@ leaderboard_refresh.timer:
- require:
- backend_services

medic_refresh.timer:
service.running:
- enable: True
- require:
- backend_services

map_refresh.timer:
service.running:
- enable: True
Expand Down
1 change: 1 addition & 0 deletions test/create.py
Original file line number Diff line number Diff line change
Expand Up @@ -114,6 +114,7 @@ class args:
# A second time to test partitioning log_json
db_init(c)
cur.execute("REFRESH MATERIALIZED VIEW leaderboard_cube;")
cur.execute("REFRESH MATERIALIZED VIEW medic_cube;")
cur.execute("REFRESH MATERIALIZED VIEW map_popularity;")

if __name__ == '__main__':
Expand Down
1 change: 1 addition & 0 deletions test/site_test.py
Original file line number Diff line number Diff line change
Expand Up @@ -101,6 +101,7 @@ def test_filter(client, logs, players, titles, maps, names, compids, teamids, co
"/search",
"/logs",
"/leaderboard",
"/medics",
"/api/v1/players",
"/api/v1/logs",
)),
Expand Down
90 changes: 90 additions & 0 deletions trends/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -755,6 +755,96 @@ CREATE INDEX IF NOT EXISTS leaderboard_bloom ON leaderboard_cube
USING bloom (grouping, mapid, classid, formatid, league)
WITH (col1=1, col2=1, col3=1, col4=1, col5=1);

CREATE MATERIALIZED VIEW IF NOT EXISTS medic_cube AS SELECT
playerid,
league,
formatid,
mapid,
grouping(league, formatid, mapid) AS grouping,
count(*) AS logs,
sum(duration) AS duration,
sum(ubers) AS ubers,
sum(medigun_ubers) AS medigun_ubers,
sum(kritz_ubers) AS kritz_ubers,
sum(other_ubers) AS other_ubers,
sum(drops) AS drops,
sum(advantages_lost) AS advantages_lost,
sum(avg_time_before_using * ubers) AS time_before_using,
sum(nullelse(avg_time_before_using, ubers)) AS ubers_before_using,
sum(avg_time_to_build * (ubers + drops)) AS time_to_build,
sum(nullelse(avg_time_to_build, ubers + drops)) AS builds,
sum(avg_uber_duration * ubers) AS uber_duration,
sum(nullelse(avg_uber_duration, ubers)) AS ubers_duration,
sum(nullelse(healing, duration)) AS healing_duration,
sum(healing) AS healing,
sum(healing_scout) AS healing_scout,
sum(healing_soldier) AS healing_soldier,
sum(healing_pyro) AS healing_pyro,
sum(healing_demoman) AS healing_demoman,
sum(healing_engineer) AS healing_engineer,
sum(healing_heavyweapons) AS healing_heavyweapons,
sum(healing_medic) AS healing_medic,
sum(healing_sniper) AS healing_sniper,
sum(healing_spy) AS healing_spy,
sum(healing_other) AS healing_other
FROM log_nodups AS log
JOIN medic_stats USING (logid)
LEFT JOIN LATERAL (SELECT
logid,
healer AS playerid,
sum(healing) AS healing,
sum(CASE WHEN class = 'scout' THEN healing END) AS healing_scout,
sum(CASE WHEN class = 'soldier' THEN healing END) AS healing_soldier,
sum(CASE WHEN class = 'pyro' THEN healing END) AS healing_pyro,
sum(CASE WHEN class = 'demoman' THEN healing END) AS healing_demoman,
sum(CASE WHEN class = 'engineer' THEN healing END) AS healing_engineer,
sum(CASE WHEN class = 'heavyweapons' THEN healing END) AS healing_heavyweapons,
sum(CASE WHEN class = 'medic' THEN healing END) AS healing_medic,
sum(CASE WHEN class = 'sniper' THEN healing END) AS healing_sniper,
sum(CASE WHEN class = 'spy' THEN healing END) AS healing_spy,
sum(CASE WHEN class ISNULL THEN healing END) AS healing_other
FROM heal_stats
JOIN player_stats USING (logid)
LEFT JOIN class ON (classid=primary_classid)
WHERE logid = medic_stats.logid
AND healer = medic_stats.playerid
AND player_stats.playerid = healee
GROUP BY logid, healer
) AS heal_stats USING (logid, playerid)
GROUP BY playerid, CUBE (league, formatid, mapid)
ORDER BY mapid, formatid, playerid, league
WITH NO DATA;

-- To help out the query planner
CREATE STATISTICS IF NOT EXISTS medic_cube_stats (dependencies, ndistinct, mcv)
ON league, formatid, mapid, grouping
FROM medic_cube;

-- When we have no filters (or nothing better)
CREATE INDEX IF NOT EXISTS medic_grouping ON medic_cube (grouping);

-- When we have a single filter
CREATE INDEX IF NOT EXISTS medic_league ON medic_cube (league)
WHERE grouping = b'011'::INT
AND league NOTNULL
AND formatid ISNULL
AND mapid ISNULL;
CREATE INDEX IF NOT EXISTS medic_format ON medic_cube (formatid)
WHERE grouping = b'101'::INT
AND league ISNULL
AND formatid NOTNULL
AND mapid ISNULL;
CREATE INDEX IF NOT EXISTS medic_map ON medic_cube (mapid)
WHERE grouping = b'110'::INT
AND league ISNULL
AND formatid ISNULL
AND mapid NOTNULL;

-- When we have multiple filters
CREATE INDEX IF NOT EXISTS medic_bloom ON medic_cube
USING bloom (grouping, mapid, formatid, league)
WITH (col1=1, col2=1, col3=1, col5=1);

CREATE TABLE IF NOT EXISTS weapon (
weaponid SERIAL PRIMARY KEY,
weapon TEXT NOT NULL UNIQUE,
Expand Down
140 changes: 140 additions & 0 deletions trends/site/leaderboards.py
Original file line number Diff line number Diff line change
Expand Up @@ -98,3 +98,143 @@ def overview():
leaderboard=leaderboard.fetchall()))
resp.cache_control.max_age = 3600
return resp

@leaderboards.route('/medics')
def medics():
limit, offset = get_pagination()
filters = get_filter_params()
filter_clauses = get_filter_clauses(filters, 'league', 'formatid', 'mapid')

# Since we are using a cube, we need to explicitly select the NULL rows
cube_clauses = []
grouping = 0b0000
for (name, column, group) in (
('map', 'mapid', 0b001),
('format', 'formatid', 0b010),
('league', 'league', 0b100),
):
if not filters[name]:
cube_clauses.append(f"AND {column} ISNULL")
grouping |= group
cube_clauses = '\n'.join(cube_clauses)

order, order_clause = get_order({
'logs': "logs",
'ubers': "ubers",
'drops': "drops",
'ubers30': "ubers30",
'drops30': "drops30",
'lost30': "lost30",
'medirate': "medirate",
'kritzrate': "kritzrate",
'otherrate': "otherrate",
'droprate': "droprate",
'avg_time_before_using': "avg_time_before_using",
'avg_time_to_build': "avg_time_to_build",
'avg_uber_duration': "avg_uber_duration",
'hpm': "hpm",
'hpm_scout': "hpm_scout",
'hpm_soldier': "hpm_soldier",
'hpm_pyro': "hpm_pyro",
'hpm_demoman': "hpm_demoman",
'hpm_engineer': "hpm_engineer",
'hpm_heavyweapons': "hpm_heavyweapons",
'hpm_medic': "hpm_medic",
'hpm_sniper': "hpm_sniper",
'hpm_spy': "hpm_spy",
'hpm_other': "hpm_other",
'duration': "duration",
}, 'drops')

db = get_db()
medics = db.cursor()
medics.execute(f"""SELECT
name,
avatarhash,
steamid64,
logs,
ubers,
drops,
ubers30,
drops30,
lost30,
medirate,
kritzrate,
otherrate,
droprate,
avg_time_before_using,
avg_time_to_build,
avg_uber_duration,
hpm,
hpm_scout,
hpm_soldier,
hpm_pyro,
hpm_demoman,
hpm_engineer,
hpm_heavyweapons,
hpm_medic,
hpm_sniper,
hpm_spy,
hpm_other,
duration
FROM (SELECT
playerid,
sum(logs) AS logs,
sum(ubers) AS ubers,
sum(drops) AS drops,
sum(ubers) * 30.0 * 60 / nullif(sum(duration), 0) AS ubers30,
sum(drops) * 30.0 * 60 / nullif(sum(duration), 0) AS drops30,
sum(advantages_lost) * 30.0 * 60 / nullif(sum(duration), 0) AS lost30,
sum(medigun_ubers) /
nullif(sum(medigun_ubers + kritz_ubers + other_ubers), 0)
AS medirate,
sum(kritz_ubers) /
nullif(sum(medigun_ubers + kritz_ubers + other_ubers), 0)
AS kritzrate,
sum(other_ubers) /
nullif(sum(medigun_ubers + kritz_ubers + other_ubers), 0)
AS otherrate,
sum(drops) / nullif(sum(ubers + drops), 0) AS droprate,
sum(time_before_using) /
nullif(sum(ubers_before_using), 0) AS avg_time_before_using,
sum(time_to_build) / nullif(sum(builds), 0) AS avg_time_to_build,
sum(uber_duration) /
nullif(sum(ubers_duration), 0) AS avg_uber_duration,
sum(healing) * 60.0 / nullif(sum(healing_duration), 0) AS hpm,
sum(healing_scout) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_scout,
sum(healing_soldier) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_soldier,
sum(healing_pyro) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_pyro,
sum(healing_demoman) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_demoman,
sum(healing_engineer) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_engineer,
sum(healing_heavyweapons) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_heavyweapons,
sum(healing_medic) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_medic,
sum(healing_sniper) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_sniper,
sum(healing_spy) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_spy,
sum(healing_other) * 60.0 /
nullif(sum(healing_duration), 0) AS hpm_other,
sum(duration) AS duration
FROM medic_cube
WHERE grouping = %(grouping)s
{filter_clauses}
{cube_clauses}
GROUP BY playerid
ORDER BY {order_clause} NULLS LAST
LIMIT %(limit)s OFFSET %(offset)s
) AS medics
LEFT JOIN player USING (playerid)
LEFT JOIN name USING (nameid)
ORDER BY {order_clause} NULLS LAST;""",
{ **filters, 'grouping': grouping, 'limit': limit, 'offset': offset })
resp = flask.make_response(flask.render_template("leaderboards/medics.html",
medics=medics.fetchall()))
resp.cache_control.max_age = 3600
return resp
4 changes: 4 additions & 0 deletions trends/site/static/css/style.css
Original file line number Diff line number Diff line change
Expand Up @@ -310,3 +310,7 @@ h4 {
.pre {
font-family: monospace;
}

.mean {
text-decoration: overline;
}
2 changes: 1 addition & 1 deletion trends/site/templates/leaderboards/base.html
Original file line number Diff line number Diff line change
Expand Up @@ -6,5 +6,5 @@
{% block content %}
{{ super() }}
<h1>Leaderboards</h1>
{{ navbar(('.overview', "Overview"),) }}
{{ navbar(('.overview', "Overview"), ('.medics', "Medics")) }}
{% endblock %}
Loading

0 comments on commit 2245249

Please sign in to comment.