maximum streak sorting: use age of streak as tiebreak

This commit is contained in:
Maximilian Keßler 2023-12-08 17:45:11 +01:00
parent 42aa041406
commit 5553124d59
Signed by: max
GPG key ID: BCC5A619923C0BA5
3 changed files with 22 additions and 10 deletions

View file

@ -336,6 +336,7 @@ CREATE TABLE user_statistics (
variant_type SMALLINT NOT NULL,
current_streak INTEGER,
maximum_streak INTEGER,
maximum_streak_last_game INTEGER REFERENCES games (league_id),
games_played INTEGER,
games_won INTEGER,
games_lost INTEGER GENERATED ALWAYS AS (games_played - games_won) STORED,

View file

@ -245,21 +245,28 @@ def get_streak_list():
}
for rating_type in rating_types:
cur.execute(
"SELECT * FROM ("
"SELECT"
" player_name,"
" user_accounts,"
" maximum_streak,"
" current_streak "
"FROM ("
" SELECT "
" player_name,"
" STRING_AGG(user_accounts.username, %s ORDER BY user_accounts.username) AS user_accounts,"
" COALESCE(maximum_streak, 0) AS maximum_streak,"
" COALESCE(current_streak, 0) AS current_streak"
" COALESCE(current_streak, 0) AS current_streak,"
" maximum_streak_last_game "
" FROM users "
" LEFT OUTER JOIN user_statistics"
" ON users.id = user_statistics.user_id AND variant_type = %s"
" LEFT OUTER JOIN user_accounts "
" ON users.id = user_accounts.user_id "
" GROUP BY (user_accounts.user_id, player_name, maximum_streak, current_streak) "
" GROUP BY (user_accounts.user_id, player_name, maximum_streak, current_streak, maximum_streak_last_game) "
" ) AS streaks "
# As a tiebreak, just sort by player name for now for determinancy
"ORDER BY maximum_streak DESC, player_name",
# As a tiebreak, the streak that was obtained first will be shown.
# If this is still the same, then we just use player name for determinancy
"ORDER BY maximum_streak DESC, maximum_streak_last_game ASC, player_name",
(", ", rating_type)
)
for (player_name, user_accounts, max_streak, current_streak) in cur.fetchall():

View file

@ -194,13 +194,17 @@ def update_user_statistics():
# row ranging over all games, where we grouped by user id and rating type (Clue Starved/Non-CS currently)
# Finally, we just wrap the computed data into an insert statement to directly store it in the statistics table
cur.execute(
"INSERT INTO user_statistics (user_id, variant_type, maximum_streak, current_streak)"
"INSERT INTO user_statistics (user_id, variant_type, maximum_streak, current_streak, maximum_streak_last_game)"
" ("
" SELECT"
" user_id,"
" CASE WHEN clue_starved THEN %s ELSE %s END,"
" MAX(streak_length) AS max_streak_length,"
" (array_agg(streak_length ORDER BY league_id DESC))[1]"
" COALESCE(MAX(streak_length), 0) AS maximum_streak,"
" COALESCE((ARRAY_AGG(streak_length ORDER BY league_id DESC))[1], 0) AS current_streak,"
" ("
" ARRAY_AGG(league_id ORDER BY streak_length DESC, league_id ASC)"
" FILTER ( WHERE streak_length IS NOT NULL)"
" )[1] AS maximum_streak_last_game"
" FROM"
" ("
" SELECT"
@ -211,7 +215,7 @@ def update_user_statistics():
" WHEN num_suits * 5 = score"
" THEN"
" COUNT(*)"
" OVER (PARTITION BY user_id, clue_starved, group_id ORDER BY league_id)"
" OVER (PARTITION BY user_id, clue_starved, group_id ORDER BY league_id ASC)"
" END"
" AS streak_length "
" FROM"
@ -240,7 +244,7 @@ def update_user_statistics():
" GROUP BY user_id, clue_starved"
" )"
"ON CONFLICT (user_id, variant_type) DO UPDATE "
"SET (maximum_streak, current_streak) = (EXCLUDED.maximum_streak, EXCLUDED.current_streak)",
"SET (maximum_streak, current_streak, maximum_streak_last_game) = (EXCLUDED.maximum_streak, EXCLUDED.current_streak, EXCLUDED.maximum_streak_last_game)",
(utils.get_rating_type(True), utils.get_rating_type(False))
)
conn_manager.get_connection().commit()