From afecc6f63df22cf4feaf8980877c7ce96018b340 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Maximilian=20Ke=C3=9Fler?= Date: Mon, 18 Mar 2024 14:01:45 +0100 Subject: [PATCH] Rework database schema: Replicate server and store all info --- src/hanabi/database/games_db_interface.py | 119 +++++++++++++++++++++ src/hanabi/database/games_seeds_schema.sql | 115 +++++++++++++++++++- src/hanabi/live/download_data.py | 115 +++++++++++++++----- src/hanabi/live/generate_seeds.py | 0 4 files changed, 319 insertions(+), 30 deletions(-) create mode 100644 src/hanabi/database/games_db_interface.py create mode 100644 src/hanabi/live/generate_seeds.py diff --git a/src/hanabi/database/games_db_interface.py b/src/hanabi/database/games_db_interface.py new file mode 100644 index 0000000..c42a74a --- /dev/null +++ b/src/hanabi/database/games_db_interface.py @@ -0,0 +1,119 @@ +from typing import List, Tuple + +import psycopg2.extras + +import hanabi.hanab_game + + +def store_actions(game_id: int, actions: List[hanabi.hanab_game.Action]): + vals = [] + for turn, action in enumerate(actions): + vals.append((game_id, turn, action.type.value, action.target, action.value or 0)) + + conn = conn_manager.get_connection() + cur = conn.cursor() + psycopg2.extras.execute_values( + cur, + "INSERT INTO game_actions (game_id, turn, type, target, value) " + "VALUES %s " + "ON CONFLICT (game_id, turn) " + "DO NOTHING", + vals + ) + conn.commit() + + +def store_deck_for_seed(seed: str, deck: List[hanabi.hanab_game.DeckCard]): + vals = [] + for index, card in enumerate(deck): + vals.append((seed, index, card.suitIndex, card.rank)) + + conn = conn_manager.get_connection() + cur = conn.cursor() + psycopg2.extras.execute_values( + cur, + "INSERT INTO seeds (seed, card_index, suit_index, rank) " + "VALUES %s " + "ON CONFLICT (seed, card_index) " + "DO NOTHING", + vals + ) + conn.commit() + + +def load_actions(game_id: int) -> List[hanabi.hanab_game.Action]: + cur = conn_manager.get_new_cursor() + cur.execute("SELECT type, target, value FROM game_actions " + "WHERE game_id = %s " + "ORDER BY turn ASC", + (game_id,)) + actions = [] + for action_type, target, value in cur.fetchall(): + actions.append( + hanabi.hanab_game.Action(hanabi.hanab_game.ActionType(action_type), target, value) + ) + if len(actions) == 0: + err_msg = "Failed to load actions for game id {} from DB: No actions stored.".format(game_id) + logger.error(err_msg) + raise ValueError(err_msg) + return actions + + +def load_deck(seed: str) -> List[hanabi.hanab_game.DeckCard]: + cur = conn_manager.get_new_cursor() + cur.execute("SELECT card_index, suit_index, rank FROM seeds " + "WHERE seed = %s " + "ORDER BY card_index ASC", + (seed,) + ) + deck = [] + for index, (card_index, suit_index, rank) in enumerate(cur.fetchall()): + assert index == card_index + deck.append( + hanabi.hanab_game.DeckCard(suit_index, rank, card_index) + ) + if len(deck) == 0: + err_msg = "Failed to load deck for seed {} from DB: No cards stored.".format(seed) + logger.error(err_msg) + raise ValueError(err_msg) + return deck + + +def load_game_parts(game_id: int) -> Tuple[hanabi.hanab_game.HanabiInstance, List[hanabi.hanab_game.Action], str]: + """ + Loads information on game from database + @param game_id: ID of game + @return: Instance (i.e. deck + settings) of game, list of actions, variant name + """ + cur = conn_manager.get_new_cursor() + cur.execute( + "SELECT games.num_players, games.seed, variants.clue_starved, variants.name " + "FROM games " + "INNER JOIN variants" + " ON games.variant_id = variants.id " + "WHERE games.id = %s", + (game_id,) + ) + res = cur.fetchone() + if res is None: + err_msg = "Failed to retrieve game details of game {}.".format(game_id) + logger.error(err_msg) + raise ValueError(err_msg) + + # Unpack results now + (num_players, seed, clue_starved, variant_name) = res + + actions = load_actions(game_id) + deck = load_deck(seed) + + instance = hanabi.hanab_game.HanabiInstance(deck, num_players, clue_starved=clue_starved) + return instance, actions, variant_name + + +def load_game(game_id: int) -> Tuple[hanabi.hanab_game.GameState, str]: + instance, actions, variant_name = load_game_parts(game_id) + game = hanabi.hanab_game.GameState(instance) + for action in actions: + game.make_action(action) + return game, variant_name + diff --git a/src/hanabi/database/games_seeds_schema.sql b/src/hanabi/database/games_seeds_schema.sql index d076b8c..35592ee 100644 --- a/src/hanabi/database/games_seeds_schema.sql +++ b/src/hanabi/database/games_seeds_schema.sql @@ -1,9 +1,16 @@ +DROP TABLE IF EXISTS users CASCADE; +CREATE TABLE users ( + id SERIAL PRIMARY KEY, + username TEXT NOT NULL UNIQUE, + normalized_username TEXT NOT NULL UNIQUE +); + + DROP TABLE IF EXISTS seeds CASCADE; CREATE TABLE seeds ( seed TEXT NOT NULL PRIMARY KEY, num_players SMALLINT NOT NULL, variant_id SMALLINT NOT NULL, - deck VARCHAR(62) NOT NULL, starting_player SMALLINT NOT NULL DEFAULT 0, feasible BOOLEAN DEFAULT NULL, max_score_theoretical SMALLINT @@ -11,26 +18,124 @@ CREATE TABLE seeds ( CREATE INDEX seeds_variant_idx ON seeds (variant_id); +DROP TABLE IF EXISTS decks CASCADE; +CREATE TABLE decks ( + seed TEXT REFERENCES seeds (seed), + /* Order of card in deck*/ + deck_index SMALLINT NOT NULL, + /* Suit */ + suit_index SMALLINT NOT NULL, + /* Rank */ + rank SMALLINT NOT NULL, + PRIMARY KEY (seed, deck_index) +); + DROP TABLE IF EXISTS games CASCADE; CREATE TABLE games ( id INT PRIMARY KEY, - seed TEXT NOT NULL REFERENCES seeds, num_players SMALLINT NOT NULL, - score SMALLINT NOT NULL, + + starting_player SMALLINT NOT NULL DEFAULT 0, + variant_id SMALLINT NOT NULL, + + timed BOOLEAN, + time_base INTEGER, + time_per_turn INTEGER, + speedrun BOOLEAN, + card_cycle BOOLEAN, deck_plays BOOLEAN, + empty_clues BOOLEAN, one_extra_card BOOLEAN, one_less_card BOOLEAN, all_or_nothing BOOLEAN, detrimental_characters BOOLEAN, - num_turns SMALLINT, - actions TEXT + + seed TEXT NOT NULL REFERENCES seeds, + score SMALLINT NOT NULL, + num_turns SMALLINT ); + CREATE INDEX games_seed_score_idx ON games (seed, score); CREATE INDEX games_var_seed_idx ON games (variant_id, seed); CREATE INDEX games_player_idx ON games (num_players); + +DROP TABLE IF EXISTS game_participants CASCADE; +CREATE TABLE game_participants ( + id SERIAL PRIMARY KEY, + game_id INTEGER NOT NULL, + user_id INTEGER NOT NULL, + seat SMALLINT NOT NULL, /* Needed for the "GetNotes()" function */ + FOREIGN KEY (game_id) REFERENCES games (id) ON DELETE CASCADE, + FOREIGN KEY (user_id) REFERENCES users (id) ON DELETE CASCADE, + CONSTRAINT game_participants_unique UNIQUE (game_id, user_id) +); + + +DROP FUNCTION IF EXISTS delete_game_of_deleted_participant; +CREATE FUNCTION delete_game_of_deleted_participant() RETURNS TRIGGER AS $_$ +BEGIN + DELETE FROM games WHERE games.id = OLD.game_id; + RETURN OLD; +END $_$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER delete_game_upon_participant_deletion + AFTER DELETE ON game_participants + FOR EACH ROW +EXECUTE PROCEDURE delete_game_of_deleted_participant(); + + +DROP TABLE IF EXISTS game_participant_notes CASCADE; +CREATE TABLE game_participant_notes ( + game_participant_id INTEGER NOT NULL, + card_order SMALLINT NOT NULL, /* "order" is a reserved word in PostgreSQL. */ + note TEXT NOT NULL, + FOREIGN KEY (game_participant_id) REFERENCES game_participants (id) ON DELETE CASCADE, + PRIMARY KEY (game_participant_id, card_order) +); + + +DROP TABLE IF EXISTS game_actions CASCADE; +CREATE TABLE game_actions ( + game_id INTEGER NOT NULL, + turn SMALLINT NOT NULL, + + /** + * Corresponds to the "DatabaseGameActionType" enum. + * + * - 0 - play + * - 1 - discard + * - 2 - color clue + * - 3 - rank clue + * - 4 - game over + */ + type SMALLINT NOT NULL, + + /** + * - If a play or a discard, corresponds to the order of the the card that was played/discarded. + * - If a clue, corresponds to the index of the player that received the clue. + * - If a game over, corresponds to the index of the player that caused the game to end or -1 if + * the game was terminated by the server. + */ + target SMALLINT NOT NULL, + + /** + * - If a play or discard, then 0 (as NULL). It uses less database space and reduces code + * complexity to use a value of 0 for NULL than to use a SQL NULL: + * https://dev.mysql.com/doc/refman/8.0/en/data-size.html + * - If a color clue, then 0 if red, 1 if yellow, etc. + * - If a rank clue, then 1 if 1, 2 if 2, etc. + * - If a game over, then the value corresponds to the "endCondition" values in "constants.go". + */ + value SMALLINT NOT NULL, + + FOREIGN KEY (game_id) REFERENCES games (id) ON DELETE CASCADE, + PRIMARY KEY (game_id, turn) +); + + DROP TABLE IF EXISTS score_upper_bounds; CREATE TABLE score_upper_bounds ( seed TEXT NOT NULL REFERENCES seeds ON DELETE CASCADE, diff --git a/src/hanabi/live/download_data.py b/src/hanabi/live/download_data.py index ab8f977..73298c4 100644 --- a/src/hanabi/live/download_data.py +++ b/src/hanabi/live/download_data.py @@ -1,8 +1,10 @@ import alive_progress -from typing import Dict, Optional +from typing import Dict, Optional, List import psycopg2.errors +import psycopg2.extras import platformdirs +import unidecode from hanabi import hanab_game from hanabi import constants @@ -49,6 +51,29 @@ class GameExportInvalidNumberOfPlayersError(GameExportInvalidFormatError): ) +def ensure_users_in_db_and_get_ids(usernames: List[str]): + normalized_usernames = [unidecode.unidecode(username) for username in usernames] + psycopg2.extras.execute_values( + database.cur, + "INSERT INTO users (username, normalized_username)" + "VALUES %s " + "ON CONFLICT (username) DO NOTHING ", + zip(usernames, normalized_usernames) + ) + + # To only do one DB query, we sort by the normalized username. + ids = [] + for username in usernames: + database.cur.execute( + "SELECT id FROM users " + "WHERE username = %s", + (username,) + ) + (id, ) = database.cur.fetchone() + ids.append(id) + + return ids + # def detailed_export_game( game_id: int @@ -94,13 +119,20 @@ def detailed_export_game( options = game_json.get('options', {}) var_id = var_id or variants.variant_id(options.get('variant', 'No Variant')) + timed = options.get('timed', False) + time_base = options.get('timeBase', 0) + time_per_turn = options.get('timePerTurn', 0) + speedrun = options.get('speedrun', False) + card_cycle = options.get('cardCycle', False) deck_plays = options.get('deckPlays', False) + empty_clues = options.get('emptyClues', False) one_extra_card = options.get('oneExtraCard', False) one_less_card = options.get('oneLessCard', False) all_or_nothing = options.get('allOrNothing', False) - starting_player = options.get('startingPlayer', 0) detrimental_characters = options.get('detrimentalCharacters', False) + starting_player = options.get('startingPlayer', 0) + try: actions = [hanab_game.Action.from_json(action) for action in game_json.get('actions', [])] except hanab_game.ParseError as e: @@ -131,44 +163,75 @@ def detailed_export_game( game.make_action(action) score = game.score - try: - compressed_deck = compress.compress_deck(deck) - except compress.InvalidFormatError as e: - logger.error("Failed to compress deck while exporting game {}: {}".format(game_id, deck)) - raise GameExportInvalidFormatError(game_id, "Failed to compress deck") from e - - try: - compressed_actions = compress.compress_actions(actions) - except compress.InvalidFormatError as e: - logger.error("Failed to compress actions while exporting game {}".format(game_id)) - raise GameExportInvalidFormatError(game_id, "Failed to compress actions") from e - if not seed_exists: database.cur.execute( - "INSERT INTO seeds (seed, num_players, starting_player, variant_id, deck)" - "VALUES (%s, %s, %s, %s, %s)" + "INSERT INTO seeds (seed, num_players, starting_player, variant_id)" + "VALUES (%s, %s, %s, %s)" "ON CONFLICT (seed) DO NOTHING", - (seed, num_players, starting_player, var_id, compressed_deck) + (seed, num_players, starting_player, var_id) ) logger.debug("New seed {} imported.".format(seed)) + values = [] + for index, card in enumerate(deck): + values.append((seed, index, card.suitIndex, card.rank)) + + psycopg2.extras.execute_values( + database.cur, + "INSERT INTO decks (seed, deck_index, suit_index, rank)" + "VALUES %s " + "ON CONFLICT (seed, deck_index) DO UPDATE SET " + "(suit_index, rank) = (excluded.suit_index, excluded.rank)", + values + ) + database.cur.execute( "INSERT INTO games (" - "id, num_players, score, seed, variant_id, deck_plays, one_extra_card, one_less_card," - "all_or_nothing, detrimental_characters, actions" + "id, num_players, starting_player, variant_id, timed, time_base, time_per_turn, speedrun, card_cycle, " + "deck_plays, empty_clues, one_extra_card, one_less_card," + "all_or_nothing, detrimental_characters, seed, score" ")" - "VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s)" + "VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s)" "ON CONFLICT (id) DO UPDATE SET (" - "deck_plays, one_extra_card, one_less_card, all_or_nothing, actions, detrimental_characters" + "timed, time_base, time_per_turn, speedrun, card_cycle, deck_plays, empty_clues, one_extra_card," + "all_or_nothing, detrimental_characters" ") = (" - "EXCLUDED.deck_plays, EXCLUDED.one_extra_card, EXCLUDED.one_less_card, EXCLUDED.all_or_nothing," - "EXCLUDED.actions, EXCLUDED.detrimental_characters" + "EXCLUDED.timed, EXCLUDED.time_base, EXCLUDED.time_per_turn, EXCLUDED.speedrun, EXCLUDED.card_cycle, " + "EXCLUDED.deck_plays, EXCLUDED.empty_clues, EXCLUDED.one_extra_card," + "EXCLUDED.all_or_nothing, EXCLUDED.detrimental_characters" ")", ( - game_id, num_players, score, seed, var_id, deck_plays, one_extra_card, one_less_card, - all_or_nothing, detrimental_characters, compressed_actions + game_id, num_players, starting_player, var_id, timed, time_base, time_per_turn, speedrun, card_cycle, + deck_plays, empty_clues, one_extra_card, one_less_card, + all_or_nothing, detrimental_characters, seed, score ) ) + + # Insert participants into database + ids = ensure_users_in_db_and_get_ids(players) + game_participant_values = [] + for index, user_id in enumerate(ids): + game_participant_values.append((game_id, user_id, index)) + psycopg2.extras.execute_values( + database.cur, + "INSERT INTO game_participants (game_id, user_id, seat) VALUES %s " + "ON CONFLICT (game_id, user_id) DO UPDATE SET seat = excluded.seat", + game_participant_values + ) + + # Insert actions into database + action_values = [] + for turn, action in enumerate(actions): + action: hanab_game.Action + action_values.append((game_id, turn, action.type.value, action.target, action.value or 0)) + + psycopg2.extras.execute_values( + database.cur, + "INSERT INTO game_actions (game_id, turn, type, target, value) " + "VALUES %s", + action_values + ) + logger.debug("Imported game {}".format(game_id)) @@ -192,6 +255,8 @@ def _process_game_row(game: Dict, var_id, export_all_games: bool = False): return # raise GameExportInvalidNumberOfPlayersError(game_id, num_players, users) + # Ensure users in database and find out their ids + if export_all_games: detailed_export_game(game_id, score=score, var_id=var_id) logger.debug("Imported game {}".format(game_id)) diff --git a/src/hanabi/live/generate_seeds.py b/src/hanabi/live/generate_seeds.py new file mode 100644 index 0000000..e69de29