ezgg-lan-manager/sql/tournament_patch.sql
David Rodenkirchen 54df84a7da Add Tournaments UI (#32)
Co-authored-by: David Rodenkirchen <drodenkirchen@linetco.com>
Reviewed-on: #32
2026-02-03 23:00:58 +00:00

145 lines
5.3 KiB
SQL

-- Apply this patch after using create_database.sql to extend the schema to support tournaments from version 0.2.0
-- WARNING: Executing this on a post 0.2.0 database will delete all data related to tournaments !!!
DROP TABLE IF EXISTS `game_titles`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `game_titles` (
id INT AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(255) NOT NULL,
description TEXT NOT NULL,
web_link VARCHAR(512) NOT NULL,
image_name VARCHAR(255) NOT NULL,
UNIQUE KEY uq_game_title_name (name)
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
DROP TABLE IF EXISTS `tournaments`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tournaments` (
id INT AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(255) NOT NULL,
description TEXT NOT NULL,
game_title_id INT NOT NULL,
format VARCHAR(20) NOT NULL, -- SE_BO1, DE_BO3, ...
start_time DATETIME NOT NULL,
status VARCHAR(20) NOT NULL, -- OPEN, CLOSED, ONGOING, ...
max_participants INT NOT NULL,
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT fk_tournament_game
FOREIGN KEY (game_title_id)
REFERENCES game_titles(id)
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
CREATE INDEX idx_tournaments_game_title
ON tournaments(game_title_id);
DROP TABLE IF EXISTS `tournament_participants`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tournament_participants` (
id INT AUTO_INCREMENT PRIMARY KEY,
tournament_id INT NOT NULL,
user_id INT NOT NULL,
participant_type VARCHAR(10) NOT NULL DEFAULT 'PLAYER',
seed INT NULL,
joined_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE KEY uq_tournament_user (tournament_id, user_id),
CONSTRAINT fk_tp_tournament
FOREIGN KEY (tournament_id)
REFERENCES tournaments(id)
ON DELETE CASCADE,
CONSTRAINT fk_tp_user
FOREIGN KEY (user_id)
REFERENCES users(user_id)
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
CREATE INDEX idx_tp_tournament
ON tournament_participants(tournament_id);
CREATE INDEX idx_tp_user
ON tournament_participants(user_id);
DROP TABLE IF EXISTS `tournament_rounds`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tournament_rounds` (
id INT AUTO_INCREMENT PRIMARY KEY,
tournament_id INT NOT NULL,
bracket VARCHAR(10) NOT NULL, -- UPPER, LOWER, FINAL
round_index INT NOT NULL,
UNIQUE KEY uq_round (tournament_id, bracket, round_index),
CONSTRAINT fk_round_tournament
FOREIGN KEY (tournament_id)
REFERENCES tournaments(id)
ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
CREATE INDEX idx_rounds_tournament
ON tournament_rounds(tournament_id);
DROP TABLE IF EXISTS `matches`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `matches` (
id INT AUTO_INCREMENT PRIMARY KEY,
tournament_id INT NOT NULL,
round_id INT NOT NULL,
match_index INT NOT NULL,
status VARCHAR(15) NOT NULL, -- WAITING, PENDING, COMPLETED, ...
best_of INT NOT NULL, -- 1, 3, 5
scheduled_time DATETIME NULL,
completed_at DATETIME NULL,
UNIQUE KEY uq_match (round_id, match_index),
CONSTRAINT fk_match_tournament
FOREIGN KEY (tournament_id)
REFERENCES tournaments(id)
ON DELETE CASCADE,
CONSTRAINT fk_match_round
FOREIGN KEY (round_id)
REFERENCES tournament_rounds(id)
ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
CREATE INDEX idx_matches_tournament
ON matches(tournament_id);
CREATE INDEX idx_matches_round
ON matches(round_id);
DROP TABLE IF EXISTS `match_participants`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `match_participants` (
match_id INT NOT NULL,
participant_id INT NOT NULL,
score INT NULL,
is_winner TINYINT(1) NULL,
PRIMARY KEY (match_id, participant_id),
CONSTRAINT fk_mp_match
FOREIGN KEY (match_id)
REFERENCES matches(id)
ON DELETE CASCADE,
CONSTRAINT fk_mp_participant
FOREIGN KEY (participant_id)
REFERENCES tournament_participants(id)
) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;