Calculate streak lengths for users

This commit is contained in:
Maximilian Keßler 2023-11-24 11:12:58 +01:00
parent 729dbb9085
commit cc08f032e3
Signed by: max
GPG key ID: BCC5A619923C0BA5
2 changed files with 53 additions and 7 deletions

View file

@ -332,7 +332,8 @@ DROP TABLE IF EXISTS game_outcomes CASCADE;
CREATE TABLE game_outcomes (
game_id INTEGER REFERENCES games (id),
/** This stores the game outcome, corresponding to the values of the statistics.GameOutcome enum */
outcome SMALLINT
outcome SMALLINT,
CONSTRAINT outcomes_no_duplicates UNIQUE (game_id, outcome)
);
DROP TABLE IF EXISTS user_statistics;

View file

@ -85,15 +85,15 @@ def update_user_statistics():
# Note that this will immediately be changed by the next query in case it is nonzero,
# so the zero value never shows up in the database if it was nonzero before.
cur.execute(
"INSERT INTO user_statistics (user_id, variant_type, total_game_moves, games_played, games_won)"
"INSERT INTO user_statistics (user_id, variant_type, total_game_moves, games_played, games_won, current_streak)"
" ("
" SELECT id, %s, 0, 0, 0 FROM users"
" SELECT id, %s, 0, 0, 0, 0 FROM users"
" )"
"ON CONFLICT (user_id, variant_type) DO UPDATE "
"SET"
" (total_game_moves, games_played, games_won)"
" (total_game_moves, games_played, games_won, current_streak)"
" ="
" (EXCLUDED.total_game_moves, EXCLUDED.games_played, EXCLUDED.games_won)",
" (EXCLUDED.total_game_moves, EXCLUDED.games_played, EXCLUDED.games_won, EXCLUDED.current_streak)",
(rating_type,)
)
cur.execute(
@ -106,7 +106,7 @@ def update_user_statistics():
" ON game_participants.game_id = games.id "
" INNER JOIN variants"
" ON variants.id = games.variant_id "
" WHERE variants.clue_starved = %s OR variants.clue_starved IS NULL"
" WHERE variants.clue_starved = %s"
" GROUP BY users.id "
" ) "
"ON CONFLICT (user_id, variant_type) DO UPDATE "
@ -128,11 +128,56 @@ def update_user_statistics():
" ON game_participants.game_id = games.id "
" INNER JOIN variants "
" ON variants.id = games.variant_id "
" WHERE variants.clue_starved = %s OR variants.clue_starved IS NULL "
" WHERE variants.clue_starved = %s"
" GROUP BY users.id"
" )"
"ON CONFLICT (user_id, variant_type) DO UPDATE "
"SET (games_played, games_won) = (EXCLUDED.games_played, EXCLUDED.games_won)",
(rating_type, clue_starved)
)
cur.execute(
"INSERT INTO user_statistics (user_id, variant_type, current_streak)"
" ("
" SELECT"
" user_id,"
" CASE WHEN clue_starved THEN %s ELSE %s END,"
" MAX(streak_length) AS max_streak_length FROM"
" ("
" SELECT"
" *,"
" CASE"
" WHEN num_suits * 5 = score"
" THEN"
" COUNT(*)"
" OVER (PARTITION BY user_id, clue_starved, group_id ORDER BY league_id)"
" END"
" AS streak_length "
" FROM"
" ("
" SELECT"
" users.id AS user_id,"
" variants.clue_starved,"
" variants.num_suits,"
" games.score,"
" games.league_id,"
" COUNT(*) "
" FILTER (WHERE variants.num_suits * 5 != games.score)"
" OVER (PARTITION BY users.id, variants.clue_starved ORDER BY games.league_id)"
" - CASE WHEN variants.num_suits * 5 != games.score THEN 1 ELSE 0 END"
" AS group_id"
" FROM users "
" INNER JOIN game_participants "
" ON game_participants.user_id = users.id "
" INNER JOIN games "
" ON game_participants.game_id = games.id "
" INNER JOIN variants "
" ON variants.id = games.variant_id "
" ) AS games_grouped_by_streak "
" ) AS games_with_streaks "
" GROUP BY user_id, clue_starved"
" )"
"ON CONFLICT (user_id, variant_type) DO UPDATE "
"SET current_streak = EXCLUDED.current_streak",
(utils.get_rating_type(True), utils.get_rating_type(False))
)
conn_manager.get_connection().commit()