adjust database scheme: rename some fields and introduce rating type to
variants
This commit is contained in:
parent
b376d1b95b
commit
707c1814ef
5 changed files with 35 additions and 37 deletions
|
@ -113,7 +113,8 @@ CREATE TABLE variants (
|
||||||
id INTEGER PRIMARY KEY,
|
id INTEGER PRIMARY KEY,
|
||||||
name TEXT NOT NULL,
|
name TEXT NOT NULL,
|
||||||
num_suits INTEGER NOT NULL,
|
num_suits INTEGER NOT NULL,
|
||||||
clue_starved BOOLEAN NOT NULL
|
clue_starved BOOLEAN NOT NULL,
|
||||||
|
rating_type INTEGER NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
/**
|
/**
|
||||||
|
@ -262,30 +263,29 @@ CREATE TABLE variant_base_ratings (
|
||||||
DROP TABLE IF EXISTS variant_ratings CASCADE;
|
DROP TABLE IF EXISTS variant_ratings CASCADE;
|
||||||
CREATE TABLE variant_ratings (
|
CREATE TABLE variant_ratings (
|
||||||
/** This should reference the game that triggered the elo update */
|
/** This should reference the game that triggered the elo update */
|
||||||
league_id INTEGER PRIMARY KEY REFERENCES games (league_id),
|
league_id INTEGER NOT NULL REFERENCES games (league_id),
|
||||||
|
variant_id SMALLINT NOT NULL REFERENCES variants (id),
|
||||||
|
|
||||||
variant_id SMALLINT NOT NULL,
|
|
||||||
num_players SMALLINT NOT NULL,
|
num_players SMALLINT NOT NULL,
|
||||||
change REAL NOT NULL,
|
change REAL NOT NULL,
|
||||||
value_after REAL NOT NULL,
|
value_after REAL NOT NULL,
|
||||||
|
|
||||||
FOREIGN KEY (variant_id) REFERENCES variants (id)
|
PRIMARY KEY (league_id, variant_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
DROP TABLE IF EXISTS user_base_ratings CASCADE;
|
DROP TABLE IF EXISTS user_base_ratings CASCADE;
|
||||||
CREATE TABLE user_base_ratings (
|
CREATE TABLE user_base_ratings (
|
||||||
user_id INTEGER,
|
user_id INTEGER REFERENCES users (id),
|
||||||
/**
|
/**
|
||||||
* Since a user has different ratings now, this should represent which of the ratings we mean.
|
* Since a user has different ratings now, this should represent which of the ratings we mean.
|
||||||
* For now, I suggest 0 = NoVar, 1 = ClueStarved.
|
* For now, I suggest 0 = NoVar, 1 = ClueStarved.
|
||||||
* I'd use an integer here to be open for more elos per player in future seasons
|
* I'd use an integer here to be open for more elos per player in future seasons
|
||||||
*/
|
*/
|
||||||
type SMALLINT NOT NULL,
|
rating_type SMALLINT NOT NULL,
|
||||||
|
|
||||||
rating REAL NOT NULL,
|
rating REAL NOT NULL,
|
||||||
|
|
||||||
PRIMARY KEY (user_id, type),
|
PRIMARY KEY (user_id, rating_type)
|
||||||
FOREIGN KEY (user_id) REFERENCES users (id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
DROP TABLE IF EXISTS user_ratings CASCADE;
|
DROP TABLE IF EXISTS user_ratings CASCADE;
|
||||||
|
@ -297,14 +297,13 @@ CREATE TABLE user_ratings (
|
||||||
*/
|
*/
|
||||||
league_id INTEGER NOT NULL REFERENCES games (league_id),
|
league_id INTEGER NOT NULL REFERENCES games (league_id),
|
||||||
|
|
||||||
user_id INTEGER NOT NULL,
|
user_id INTEGER NOT NULL REFERENCES users (id),
|
||||||
type SMALLINT NOT NULL,
|
rating_type SMALLINT NOT NULL,
|
||||||
|
|
||||||
change REAL NOT NULL,
|
change REAL NOT NULL,
|
||||||
value_after REAL NOT NULL,
|
value_after REAL NOT NULL,
|
||||||
|
|
||||||
FOREIGN KEY (user_id) REFERENCES users (id),
|
PRIMARY KEY (league_id, user_id)
|
||||||
CONSTRAINT user_change_per_game_unique UNIQUE (league_id, user_id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -78,9 +78,9 @@ def init_database():
|
||||||
def fetch_and_initialize_variants():
|
def fetch_and_initialize_variants():
|
||||||
response = requests.get(constants.VARIANTS_JSON_URL)
|
response = requests.get(constants.VARIANTS_JSON_URL)
|
||||||
if not response.status_code == 200:
|
if not response.status_code == 200:
|
||||||
logger.error(
|
err_msg = "Could not download variants.json file from github (tried url {})".format(constants.VARIANTS_JSON_URL)
|
||||||
"Could not download variants.json file from github (tried url {})".format(constants.VARIANTS_JSON_URL))
|
logger.error(err_msg)
|
||||||
return
|
raise ConnectionError(err_msg)
|
||||||
variants = json.loads(response.text)
|
variants = json.loads(response.text)
|
||||||
|
|
||||||
config = config_manager.get_config()
|
config = config_manager.get_config()
|
||||||
|
@ -96,8 +96,8 @@ def fetch_and_initialize_variants():
|
||||||
continue
|
continue
|
||||||
cur = conn_manager.get_new_cursor()
|
cur = conn_manager.get_new_cursor()
|
||||||
cur.execute(
|
cur.execute(
|
||||||
"INSERT INTO variants (id, name, num_suits, clue_starved) VALUES (%s, %s, %s, %s)",
|
"INSERT INTO variants (id, name, num_suits, clue_starved, rating_type) VALUES (%s, %s, %s, %s, %s)",
|
||||||
(variant_id, name, num_suits, clue_starved)
|
(variant_id, name, num_suits, clue_starved, utils.get_rating_type(clue_starved))
|
||||||
)
|
)
|
||||||
conn_manager.get_connection().commit()
|
conn_manager.get_connection().commit()
|
||||||
|
|
||||||
|
@ -226,7 +226,7 @@ def init_player_base_rating(player_name: str, base_rating: Optional[int] = None)
|
||||||
try:
|
try:
|
||||||
psycopg2.extras.execute_values(
|
psycopg2.extras.execute_values(
|
||||||
cur,
|
cur,
|
||||||
"INSERT INTO user_base_ratings (user_id, type, rating) VALUES %s",
|
"INSERT INTO user_base_ratings (user_id, rating_type, rating) VALUES %s",
|
||||||
vals
|
vals
|
||||||
)
|
)
|
||||||
conn_manager.get_connection().commit()
|
conn_manager.get_connection().commit()
|
||||||
|
|
|
@ -68,7 +68,7 @@ def get_current_user_ratings(user_ids: List[int], rating_type: int) -> Dict[int,
|
||||||
"""
|
"""
|
||||||
cur = conn_manager.get_new_cursor()
|
cur = conn_manager.get_new_cursor()
|
||||||
cur.execute("SELECT user_id, rating FROM user_base_ratings "
|
cur.execute("SELECT user_id, rating FROM user_base_ratings "
|
||||||
"WHERE user_id IN ({}) AND type = %s".format(", ".join("%s" for _ in user_ids)),
|
"WHERE user_id IN ({}) AND rating_type = %s".format(", ".join("%s" for _ in user_ids)),
|
||||||
user_ids + [rating_type]
|
user_ids + [rating_type]
|
||||||
)
|
)
|
||||||
base_ratings = cur.fetchall()
|
base_ratings = cur.fetchall()
|
||||||
|
@ -82,17 +82,17 @@ def get_current_user_ratings(user_ids: List[int], rating_type: int) -> Dict[int,
|
||||||
# even though we do not retrieve any values from the subclause-table
|
# even though we do not retrieve any values from the subclause-table
|
||||||
cur.execute("SELECT user_ratings.user_id, value_after FROM user_ratings "
|
cur.execute("SELECT user_ratings.user_id, value_after FROM user_ratings "
|
||||||
"INNER JOIN ("
|
"INNER JOIN ("
|
||||||
" SELECT user_id, type, MAX(league_id) AS max_league_id"
|
" SELECT user_id, rating_type, MAX(league_id) AS max_league_id"
|
||||||
" FROM user_ratings "
|
" FROM user_ratings "
|
||||||
" GROUP BY (user_id, type)"
|
" GROUP BY (user_id, rating_type)"
|
||||||
" ) AS latest_user_ratings "
|
" ) AS latest_user_ratings "
|
||||||
" ON"
|
" ON"
|
||||||
" user_ratings.league_id = latest_user_ratings.max_league_id"
|
" user_ratings.league_id = latest_user_ratings.max_league_id"
|
||||||
" AND user_ratings.user_id = latest_user_ratings.user_id"
|
" AND user_ratings.user_id = latest_user_ratings.user_id"
|
||||||
" AND user_ratings.type = latest_user_ratings.type "
|
" AND user_ratings.rating_type = latest_user_ratings.rating_type "
|
||||||
"WHERE "
|
"WHERE "
|
||||||
" user_ratings.user_id IN ({})"
|
" user_ratings.user_id IN ({})"
|
||||||
" AND user_ratings.type = %s"
|
" AND user_ratings.rating_type = %s"
|
||||||
.format(", ".join("%s" for _ in user_ids))
|
.format(", ".join("%s" for _ in user_ids))
|
||||||
, user_ids + [rating_type]
|
, user_ids + [rating_type]
|
||||||
)
|
)
|
||||||
|
@ -153,14 +153,14 @@ def process_rating_of_next_game() -> bool:
|
||||||
|
|
||||||
# Fetch data on the game played
|
# Fetch data on the game played
|
||||||
cur.execute(
|
cur.execute(
|
||||||
"SELECT games.league_id, games.num_players, games.score, variants.num_suits, variants.clue_starved, variants.id "
|
"SELECT games.league_id, games.num_players, games.score, variants.num_suits, variants.clue_starved, variants.rating_type, variants.id "
|
||||||
"FROM games "
|
"FROM games "
|
||||||
"INNER JOIN variants "
|
"INNER JOIN variants "
|
||||||
" ON games.variant_id = variants.id "
|
" ON games.variant_id = variants.id "
|
||||||
"WHERE games.id = %s",
|
"WHERE games.id = %s",
|
||||||
(game_id,)
|
(game_id,)
|
||||||
)
|
)
|
||||||
league_id, num_players, score, num_suits, clue_starved, variant_id = cur.fetchone()
|
league_id, num_players, score, num_suits, clue_starved, rating_type, variant_id = cur.fetchone()
|
||||||
|
|
||||||
# Fetch game participants and how many games they played each so far
|
# Fetch game participants and how many games they played each so far
|
||||||
cur.execute("SELECT game_participants.user_id, COUNT(games.id) "
|
cur.execute("SELECT game_participants.user_id, COUNT(games.id) "
|
||||||
|
@ -190,7 +190,6 @@ def process_rating_of_next_game() -> bool:
|
||||||
raise ValueError(err_msg)
|
raise ValueError(err_msg)
|
||||||
|
|
||||||
# Fetch current ratings of variant and players involved
|
# Fetch current ratings of variant and players involved
|
||||||
rating_type = utils.get_rating_type(clue_starved)
|
|
||||||
user_ratings = get_current_user_ratings(list(games_played.keys()), rating_type)
|
user_ratings = get_current_user_ratings(list(games_played.keys()), rating_type)
|
||||||
variant_rating = get_current_variant_rating(variant_id, num_players)
|
variant_rating = get_current_variant_rating(variant_id, num_players)
|
||||||
|
|
||||||
|
@ -211,7 +210,7 @@ def process_rating_of_next_game() -> bool:
|
||||||
# This updates the player rating.
|
# This updates the player rating.
|
||||||
psycopg2.extras.execute_values(
|
psycopg2.extras.execute_values(
|
||||||
cur,
|
cur,
|
||||||
"INSERT INTO user_ratings (league_id, user_id, type, change, value_after) "
|
"INSERT INTO user_ratings (league_id, user_id, rating_type, change, value_after) "
|
||||||
"VALUES %s",
|
"VALUES %s",
|
||||||
user_ratings_vals
|
user_ratings_vals
|
||||||
)
|
)
|
||||||
|
|
|
@ -225,11 +225,11 @@ def get_rating_lists() -> Dict[int, List[PlayerEntry]]:
|
||||||
" COALESCE(value_after, rating) AS current_rating"
|
" COALESCE(value_after, rating) AS current_rating"
|
||||||
" FROM users "
|
" FROM users "
|
||||||
" LEFT OUTER JOIN user_ratings "
|
" LEFT OUTER JOIN user_ratings "
|
||||||
" ON user_ratings.user_id = users.id AND user_ratings.type = %s "
|
" ON user_ratings.user_id = users.id AND user_ratings.rating_type = %s "
|
||||||
" LEFT OUTER JOIN user_accounts "
|
" LEFT OUTER JOIN user_accounts "
|
||||||
" ON users.id = user_accounts.user_id "
|
" ON users.id = user_accounts.user_id "
|
||||||
" INNER JOIN user_base_ratings "
|
" INNER JOIN user_base_ratings "
|
||||||
" ON users.id = user_base_ratings.user_id AND user_base_ratings.type = %s"
|
" ON users.id = user_base_ratings.user_id AND user_base_ratings.rating_type = %s"
|
||||||
" GROUP BY (user_accounts.user_id, player_name, value_after, league_id, rating) "
|
" GROUP BY (user_accounts.user_id, player_name, value_after, league_id, rating) "
|
||||||
" ORDER BY user_accounts.user_id, league_id DESC"
|
" ORDER BY user_accounts.user_id, league_id DESC"
|
||||||
" ) AS ratings "
|
" ) AS ratings "
|
||||||
|
@ -381,11 +381,11 @@ def get_player_stats() -> Dict[str, Dict[int, PlayerStats]]:
|
||||||
" COALESCE(value_after, rating) AS current_rating"
|
" COALESCE(value_after, rating) AS current_rating"
|
||||||
" FROM users "
|
" FROM users "
|
||||||
" LEFT OUTER JOIN user_ratings "
|
" LEFT OUTER JOIN user_ratings "
|
||||||
" ON user_ratings.user_id = users.id AND user_ratings.type = %s "
|
" ON user_ratings.user_id = users.id AND user_ratings.rating_type = %s "
|
||||||
" LEFT OUTER JOIN user_accounts "
|
" LEFT OUTER JOIN user_accounts "
|
||||||
" ON users.id = user_accounts.user_id "
|
" ON users.id = user_accounts.user_id "
|
||||||
" INNER JOIN user_base_ratings "
|
" INNER JOIN user_base_ratings "
|
||||||
" ON users.id = user_base_ratings.user_id AND user_base_ratings.type = %s"
|
" ON users.id = user_base_ratings.user_id AND user_base_ratings.rating_type = %s"
|
||||||
" GROUP BY (user_accounts.user_id, player_name, value_after, league_id, rating) "
|
" GROUP BY (user_accounts.user_id, player_name, value_after, league_id, rating) "
|
||||||
" ORDER BY user_accounts.user_id, league_id DESC"
|
" ORDER BY user_accounts.user_id, league_id DESC"
|
||||||
" ) AS ratings "
|
" ) AS ratings "
|
||||||
|
|
12
src/stats.py
12
src/stats.py
|
@ -155,7 +155,7 @@ def update_user_statistics():
|
||||||
" ("
|
" ("
|
||||||
" SELECT"
|
" SELECT"
|
||||||
" users.id,"
|
" users.id,"
|
||||||
" CASE WHEN clue_starved THEN %s ELSE %s END,"
|
" rating_type,"
|
||||||
" SUM(games.num_turns),"
|
" SUM(games.num_turns),"
|
||||||
" COUNT(*)," # This counts the number of rows (per user id), so the number of played game
|
" COUNT(*)," # This counts the number of rows (per user id), so the number of played game
|
||||||
" COUNT(*) FILTER ( WHERE variants.num_suits * 5 = games.score )," # Same, but only count wins now
|
" COUNT(*) FILTER ( WHERE variants.num_suits * 5 = games.score )," # Same, but only count wins now
|
||||||
|
@ -170,7 +170,7 @@ def update_user_statistics():
|
||||||
" ON variants.id = games.variant_id "
|
" ON variants.id = games.variant_id "
|
||||||
" LEFT OUTER JOIN game_statistics"
|
" LEFT OUTER JOIN game_statistics"
|
||||||
" ON games.id = game_statistics.game_id"
|
" ON games.id = game_statistics.game_id"
|
||||||
" GROUP BY users.id, clue_starved "
|
" GROUP BY users.id, rating_type "
|
||||||
" ) "
|
" ) "
|
||||||
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
||||||
"SET"
|
"SET"
|
||||||
|
@ -198,7 +198,7 @@ def update_user_statistics():
|
||||||
" ("
|
" ("
|
||||||
" SELECT"
|
" SELECT"
|
||||||
" user_id,"
|
" user_id,"
|
||||||
" CASE WHEN clue_starved THEN %s ELSE %s END,"
|
" rating_type,"
|
||||||
" COALESCE(MAX(streak_length), 0) AS maximum_streak,"
|
" COALESCE(MAX(streak_length), 0) AS maximum_streak,"
|
||||||
" COALESCE((ARRAY_AGG(streak_length ORDER BY league_id DESC))[1], 0) AS current_streak,"
|
" COALESCE((ARRAY_AGG(streak_length ORDER BY league_id DESC))[1], 0) AS current_streak,"
|
||||||
" ("
|
" ("
|
||||||
|
@ -215,15 +215,15 @@ def update_user_statistics():
|
||||||
" WHEN num_suits * 5 = score"
|
" WHEN num_suits * 5 = score"
|
||||||
" THEN"
|
" THEN"
|
||||||
" COUNT(*)"
|
" COUNT(*)"
|
||||||
" OVER (PARTITION BY user_id, clue_starved, group_id ORDER BY league_id ASC)"
|
" OVER (PARTITION BY user_id, rating_type, group_id ORDER BY league_id ASC)"
|
||||||
" END"
|
" END"
|
||||||
" AS streak_length "
|
" AS streak_length "
|
||||||
" FROM"
|
" FROM"
|
||||||
" ("
|
" ("
|
||||||
" SELECT"
|
" SELECT"
|
||||||
" users.id AS user_id,"
|
" users.id AS user_id,"
|
||||||
" variants.clue_starved,"
|
|
||||||
" variants.num_suits,"
|
" variants.num_suits,"
|
||||||
|
" variants.rating_type,"
|
||||||
" games.score,"
|
" games.score,"
|
||||||
" games.league_id,"
|
" games.league_id,"
|
||||||
# This count function is the tricky part that labels each game with the group_id of the streak it belongs to
|
# This count function is the tricky part that labels each game with the group_id of the streak it belongs to
|
||||||
|
@ -241,7 +241,7 @@ def update_user_statistics():
|
||||||
" ON variants.id = games.variant_id "
|
" ON variants.id = games.variant_id "
|
||||||
" ) AS games_grouped_by_streak "
|
" ) AS games_grouped_by_streak "
|
||||||
" ) AS games_with_streaks "
|
" ) AS games_with_streaks "
|
||||||
" GROUP BY user_id, clue_starved"
|
" GROUP BY user_id, rating_type"
|
||||||
" )"
|
" )"
|
||||||
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
"ON CONFLICT (user_id, variant_type) DO UPDATE "
|
||||||
"SET (maximum_streak, current_streak, maximum_streak_last_game) = (EXCLUDED.maximum_streak, EXCLUDED.current_streak, EXCLUDED.maximum_streak_last_game)",
|
"SET (maximum_streak, current_streak, maximum_streak_last_game) = (EXCLUDED.maximum_streak, EXCLUDED.current_streak, EXCLUDED.maximum_streak_last_game)",
|
||||||
|
|
Loading…
Reference in a new issue