From 852f2ea3293c28116cc3d6429178d220d2155962 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Maximilian=20Ke=C3=9Fler?= Date: Fri, 24 Nov 2023 11:42:37 +0100 Subject: [PATCH] add more user statistics --- install/database_schema.sql | 6 ++++++ src/stats.py | 15 +++++++++------ 2 files changed, 15 insertions(+), 6 deletions(-) diff --git a/install/database_schema.sql b/install/database_schema.sql index 4ace3ea..0498889 100644 --- a/install/database_schema.sql +++ b/install/database_schema.sql @@ -344,10 +344,16 @@ CREATE TABLE user_statistics ( current_streak INTEGER, games_played 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, /** Number of critical cards that were either discarded or misplayed */ total_crits_lots 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) ); diff --git a/src/stats.py b/src/stats.py index 84f06e3..8ad0e64 100644 --- a/src/stats.py +++ b/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. cur.execute( "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 " "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,) ) 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" " users.id," " CASE WHEN clue_starved THEN %s ELSE %s END," " SUM(games.num_turns)," " 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" " INNER JOIN game_participants " " ON game_participants.user_id = users.id " @@ -113,6 +114,8 @@ def update_user_statistics(): " ON game_participants.game_id = games.id " " INNER JOIN variants" " ON variants.id = games.variant_id " + " LEFT OUTER JOIN game_statistics" + " ON games.id = game_statistics.game_id" " GROUP BY users.id, clue_starved " " ) " "ON CONFLICT (user_id, variant_type) DO UPDATE "