forked from Hanabi/hanabi-league
add more user statistics
This commit is contained in:
parent
bb3be235d9
commit
852f2ea329
2 changed files with 15 additions and 6 deletions
|
@ -344,10 +344,16 @@ CREATE TABLE user_statistics (
|
||||||
current_streak INTEGER,
|
current_streak INTEGER,
|
||||||
games_played INTEGER,
|
games_played INTEGER,
|
||||||
games_won INTEGER,
|
games_won INTEGER,
|
||||||
|
games_lost INTEGER GENERATED ALWAYS AS (games_played - games_won) STORED,
|
||||||
|
winrate REAL GENERATED ALWAYS AS (CASE WHEN games_played != 0 THEN CAST(games_won AS REAL)/ games_played ELSE NULL END) STORED,
|
||||||
total_bdr INTEGER,
|
total_bdr INTEGER,
|
||||||
/** Number of critical cards that were either discarded or misplayed */
|
/** Number of critical cards that were either discarded or misplayed */
|
||||||
total_crits_lots INTEGER,
|
total_crits_lots INTEGER,
|
||||||
total_game_moves INTEGER,
|
total_game_moves INTEGER,
|
||||||
|
average_bdr REAL GENERATED ALWAYS AS (CASE WHEN games_played != 0 THEN CAST(total_bdr AS REAL) / games_played ELSE NULL END) STORED,
|
||||||
|
average_crits_lost REAL GENERATED ALWAYS AS (CASE WHEN games_played != 0 THEN CAST(total_crits_lots AS REAL) / games_played ELSE NULL END) STORED,
|
||||||
|
/** TODO: We should probably also evaluate this over normally-finished (or won?) games */
|
||||||
|
average_game_moves REAL GENERATED ALWAYS AS (CASE WHEN games_played != 0 THEN CAST(total_game_moves AS REAL) / games_played ELSE NULL END) STORED,
|
||||||
PRIMARY KEY (user_id, variant_type)
|
PRIMARY KEY (user_id, variant_type)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
15
src/stats.py
15
src/stats.py
|
@ -86,26 +86,27 @@ def update_user_statistics():
|
||||||
# so the zero value never shows up in the database if it was nonzero before.
|
# so the zero value never shows up in the database if it was nonzero before.
|
||||||
cur.execute(
|
cur.execute(
|
||||||
"INSERT INTO user_statistics"
|
"INSERT INTO user_statistics"
|
||||||
" (user_id, variant_type, total_game_moves, games_played, games_won, current_streak)"
|
" (user_id, variant_type, total_game_moves, games_played, games_won, current_streak, total_bdr)"
|
||||||
" ("
|
" ("
|
||||||
" SELECT id, %s, 0, 0, 0, 0 FROM users"
|
" SELECT id, %s, 0, 0, 0, 0, 0 FROM users"
|
||||||
" )"
|
" )"
|
||||||
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
||||||
"SET"
|
"SET"
|
||||||
" (total_game_moves, games_played, games_won, current_streak)"
|
" (total_game_moves, games_played, games_won, current_streak, total_bdr)"
|
||||||
" ="
|
" ="
|
||||||
" (EXCLUDED.total_game_moves, EXCLUDED.games_played, EXCLUDED.games_won, EXCLUDED.current_streak)",
|
" (EXCLUDED.total_game_moves, EXCLUDED.games_played, EXCLUDED.games_won, EXCLUDED.current_streak, EXCLUDED.total_bdr)",
|
||||||
(rating_type,)
|
(rating_type,)
|
||||||
)
|
)
|
||||||
cur.execute(
|
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, total_bdr)"
|
||||||
" ("
|
" ("
|
||||||
" SELECT"
|
" SELECT"
|
||||||
" users.id,"
|
" users.id,"
|
||||||
" CASE WHEN clue_starved THEN %s ELSE %s END,"
|
" CASE WHEN clue_starved THEN %s ELSE %s END,"
|
||||||
" SUM(games.num_turns),"
|
" SUM(games.num_turns),"
|
||||||
" COUNT(*),"
|
" COUNT(*),"
|
||||||
" COUNT(*) FILTER ( WHERE variants.num_suits * 5 = games.score )"
|
" COUNT(*) FILTER ( WHERE variants.num_suits * 5 = games.score ),"
|
||||||
|
" SUM (game_statistics.bottom_deck_risk)"
|
||||||
"FROM users"
|
"FROM users"
|
||||||
" INNER JOIN game_participants "
|
" INNER JOIN game_participants "
|
||||||
" ON game_participants.user_id = users.id "
|
" ON game_participants.user_id = users.id "
|
||||||
|
@ -113,6 +114,8 @@ def update_user_statistics():
|
||||||
" ON game_participants.game_id = games.id "
|
" ON game_participants.game_id = games.id "
|
||||||
" INNER JOIN variants"
|
" INNER JOIN variants"
|
||||||
" ON variants.id = games.variant_id "
|
" ON variants.id = games.variant_id "
|
||||||
|
" LEFT OUTER JOIN game_statistics"
|
||||||
|
" ON games.id = game_statistics.game_id"
|
||||||
" GROUP BY users.id, clue_starved "
|
" GROUP BY users.id, clue_starved "
|
||||||
" ) "
|
" ) "
|
||||||
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
||||||
|
|
Loading…
Reference in a new issue