PickleBALLER/migrations/001_initial_schema.sql

81 lines
2.7 KiB
SQL

-- Pickleball ELO Tracker Database Schema
-- Glicko-2 Rating System with Singles/Doubles tracking
-- Enable foreign keys
PRAGMA foreign_keys = ON;
-- Players table
CREATE TABLE IF NOT EXISTS players (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL UNIQUE,
email TEXT,
-- Singles Glicko-2 values
singles_rating REAL NOT NULL DEFAULT 1500.0,
singles_rd REAL NOT NULL DEFAULT 350.0,
singles_volatility REAL NOT NULL DEFAULT 0.06,
-- Doubles Glicko-2 values
doubles_rating REAL NOT NULL DEFAULT 1500.0,
doubles_rd REAL NOT NULL DEFAULT 350.0,
doubles_volatility REAL NOT NULL DEFAULT 0.06,
-- Metadata
created_at TEXT NOT NULL DEFAULT (datetime('now')),
last_played TEXT NOT NULL DEFAULT (datetime('now'))
);
-- Sessions (rating periods)
CREATE TABLE IF NOT EXISTS sessions (
id INTEGER PRIMARY KEY AUTOINCREMENT,
start_time TEXT NOT NULL DEFAULT (datetime('now')),
end_time TEXT,
summary_sent BOOLEAN NOT NULL DEFAULT 0,
notes TEXT
);
-- Matches
CREATE TABLE IF NOT EXISTS matches (
id INTEGER PRIMARY KEY AUTOINCREMENT,
session_id INTEGER NOT NULL,
match_type TEXT NOT NULL CHECK(match_type IN ('singles', 'doubles')),
timestamp TEXT NOT NULL DEFAULT (datetime('now')),
team1_score INTEGER NOT NULL,
team2_score INTEGER NOT NULL,
FOREIGN KEY (session_id) REFERENCES sessions(id) ON DELETE CASCADE
);
-- Match participants (links players to matches with rating changes)
CREATE TABLE IF NOT EXISTS match_participants (
id INTEGER PRIMARY KEY AUTOINCREMENT,
match_id INTEGER NOT NULL,
player_id INTEGER NOT NULL,
team INTEGER NOT NULL CHECK(team IN (1, 2)),
-- Pre-match Glicko-2 values
rating_before REAL NOT NULL,
rd_before REAL NOT NULL,
volatility_before REAL NOT NULL,
-- Post-match Glicko-2 values
rating_after REAL NOT NULL,
rd_after REAL NOT NULL,
volatility_after REAL NOT NULL,
-- Calculated change
rating_change REAL NOT NULL,
FOREIGN KEY (match_id) REFERENCES matches(id) ON DELETE CASCADE,
FOREIGN KEY (player_id) REFERENCES players(id) ON DELETE CASCADE
);
-- Indexes for performance
CREATE INDEX IF NOT EXISTS idx_matches_session ON matches(session_id);
CREATE INDEX IF NOT EXISTS idx_matches_timestamp ON matches(timestamp DESC);
CREATE INDEX IF NOT EXISTS idx_participants_match ON match_participants(match_id);
CREATE INDEX IF NOT EXISTS idx_participants_player ON match_participants(player_id);
CREATE INDEX IF NOT EXISTS idx_players_name ON players(name);
CREATE INDEX IF NOT EXISTS idx_players_singles_rating ON players(singles_rating DESC);
CREATE INDEX IF NOT EXISTS idx_players_doubles_rating ON players(doubles_rating DESC);