108 lines
		
	
	
		
			3.8 KiB
		
	
	
	
		
			SQL
		
	
	
	
	
	
			
		
		
	
	
			108 lines
		
	
	
		
			3.8 KiB
		
	
	
	
		
			SQL
		
	
	
	
	
	
| -- migrations/001_initial_schema.up.sql
 | |
| 
 | |
| CREATE TABLE rooms (
 | |
|     id TEXT PRIMARY KEY,
 | |
|     created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
 | |
|     creator_name TEXT NOT NULL,
 | |
|     team_turn TEXT NOT NULL DEFAULT '',
 | |
|     this_turn_limit INTEGER NOT NULL DEFAULT 0,
 | |
|     opened_this_turn INTEGER NOT NULL DEFAULT 0,
 | |
|     blue_counter INTEGER NOT NULL DEFAULT 0,
 | |
|     red_counter INTEGER NOT NULL DEFAULT 0,
 | |
|     red_turn BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     mime_done BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     is_running BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     is_over BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     bot_failed BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     team_won TEXT NOT NULL DEFAULT '',
 | |
|     room_link TEXT NOT NULL DEFAULT ''
 | |
| );
 | |
| 
 | |
| CREATE TABLE players (
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     room_id TEXT, -- nullable
 | |
|     username TEXT NOT NULL UNIQUE,
 | |
|     password TEXT NOT NULL DEFAULT '',
 | |
|     team TEXT NOT NULL DEFAULT '', -- 'red' or 'blue'
 | |
|     role TEXT NOT NULL DEFAULT '', -- 'guesser' or 'mime'
 | |
|     is_bot BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     FOREIGN KEY (room_id) REFERENCES rooms(id) ON DELETE CASCADE
 | |
| );
 | |
| 
 | |
| CREATE TABLE word_cards (
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     room_id TEXT NOT NULL,
 | |
|     word TEXT NOT NULL,
 | |
|     color TEXT NOT NULL DEFAULT '',
 | |
|     revealed BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     mime_view BOOLEAN NOT NULL DEFAULT FALSE,
 | |
|     FOREIGN KEY (room_id) REFERENCES rooms(id) ON DELETE CASCADE
 | |
| );
 | |
| 
 | |
| CREATE TABLE card_marks (
 | |
|     card_id INTEGER NOT NULL,
 | |
|     username TEXT NOT NULL,
 | |
|     FOREIGN KEY (card_id) REFERENCES word_cards(id) ON DELETE CASCADE,
 | |
|     FOREIGN KEY (username) REFERENCES players(username) ON DELETE CASCADE,
 | |
|     PRIMARY KEY (card_id, username)
 | |
| );
 | |
| 
 | |
| CREATE TABLE actions (
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     room_id TEXT NOT NULL,
 | |
|     actor TEXT NOT NULL,
 | |
|     actor_color TEXT NOT NULL DEFAULT '',
 | |
|     action_type TEXT NOT NULL,
 | |
|     word TEXT NOT NULL DEFAULT '',
 | |
|     word_color TEXT NOT NULL DEFAULT '',
 | |
|     number_associated TEXT NOT NULL DEFAULT '', -- for clues
 | |
|     created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
 | |
|     FOREIGN KEY (room_id) REFERENCES rooms(id) ON DELETE CASCADE
 | |
| );
 | |
| 
 | |
| CREATE TABLE settings (
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     room_id TEXT NOT NULL,
 | |
|     language TEXT NOT NULL DEFAULT 'en',
 | |
|     room_pass TEXT NOT NULL DEFAULT '',
 | |
|     turn_time INTEGER NOT NULL DEFAULT 60, -- seconds
 | |
|     created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
 | |
|     FOREIGN KEY (room_id) REFERENCES rooms(id) ON DELETE CASCADE
 | |
| );
 | |
| 
 | |
| CREATE TABLE sessions(
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
 | |
|     lifetime INTEGER NOT NULL DEFAULT 3600,
 | |
|     token_key TEXT NOT NULL DEFAULT '' UNIQUE, -- encoded value
 | |
|     username TEXT NOT NULL,
 | |
|     FOREIGN KEY (username) REFERENCES players(username) ON DELETE CASCADE
 | |
| );
 | |
| 
 | |
| CREATE TABLE journal(
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
 | |
|     entry TEXT NOT NULL DEFAULT '',
 | |
|     username TEXT NOT NULL,
 | |
|     room_id TEXT NOT NULL,
 | |
|     FOREIGN KEY (username) REFERENCES players(username) ON DELETE CASCADE,
 | |
|     FOREIGN KEY (room_id) REFERENCES rooms(id) ON DELETE CASCADE
 | |
| );
 | |
| 
 | |
| CREATE TABLE player_stats (
 | |
|     id INTEGER PRIMARY KEY AUTOINCREMENT,
 | |
|     username TEXT NOT NULL UNIQUE,
 | |
|     games_played INTEGER NOT NULL DEFAULT 0,
 | |
|     games_won INTEGER NOT NULL DEFAULT 0,
 | |
|     games_lost INTEGER NOT NULL DEFAULT 0,
 | |
|     opened_opposite_words INTEGER NOT NULL DEFAULT 0,
 | |
|     opened_white_words INTEGER NOT NULL DEFAULT 0,
 | |
|     opened_black_words INTEGER NOT NULL DEFAULT 0,
 | |
|     mime_winrate REAL NOT NULL DEFAULT 0.0,
 | |
|     guesser_winrate REAL NOT NULL DEFAULT 0.0,
 | |
|     played_as_mime INTEGER NOT NULL DEFAULT 0,
 | |
|     played_as_guesser INTEGER NOT NULL DEFAULT 0,
 | |
|     FOREIGN KEY (username) REFERENCES players(username) ON DELETE CASCADE
 | |
| );
 | |
| 
 | 
