use sqlx::{SqlitePool, sqlite::SqlitePoolOptions}; use std::path::Path; /// Creates and initializes a connection pool to the SQLite database. /// /// This function: /// - Creates the database file if it doesn't exist /// - Ensures parent directories are created /// - Configures a connection pool with max 5 connections /// - Enables foreign key constraints for referential integrity /// - Runs database migrations to set up the schema /// /// # Arguments /// * `db_path` - Path to the SQLite database file (e.g., "pickleball.db") /// /// # Returns /// * `Ok(SqlitePool)` - Initialized connection pool ready to use /// * `Err(sqlx::Error)` - If connection or migration fails pub async fn create_pool(db_path: &str) -> Result { // Create database file if it doesn't exist let path = Path::new(db_path); let db_exists = path.exists(); // Ensure parent directory exists if let Some(parent) = path.parent() { std::fs::create_dir_all(parent).ok(); } // Create connection pool with correct SQLite connection string let pool = SqlitePoolOptions::new() .max_connections(5) .connect(&format!("sqlite://{}?mode=rwc", db_path)) .await?; // Enable foreign keys sqlx::query("PRAGMA foreign_keys = ON") .execute(&pool) .await?; // Run migrations run_migrations(&pool).await?; Ok(pool) } /// Runs database migrations to create tables and indexes if they don't exist. /// /// Creates the following schema: /// - **players**: Stores player profiles with separate singles/doubles Glicko2 ratings /// - **sessions**: Tracks play sessions with optional summaries /// - **matches**: Individual matches within sessions (singles or doubles) /// - **match_participants**: Records each player's performance in a match with before/after ratings /// /// All tables include foreign keys and appropriate indexes for query performance. /// Idempotent - safe to call multiple times. pub async fn run_migrations(pool: &SqlitePool) -> Result<(), sqlx::Error> { let schema = include_str!("../../migrations/001_initial_schema.sql"); // Execute each statement let statements = vec![ "PRAGMA foreign_keys = ON", // Players table: Stores player profiles with separate Glicko2 ratings for singles and doubles // Each player maintains independent rating systems since skill in singles vs doubles may differ "CREATE TABLE IF NOT EXISTS players ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL UNIQUE, email TEXT, -- Glicko2 Rating: Skill estimate (1500 = average) singles_rating REAL NOT NULL DEFAULT 1500.0, -- Glicko2 RD (Rating Deviation): Confidence in rating (lower = more confident; ~30 = highly confident) singles_rd REAL NOT NULL DEFAULT 350.0, -- Glicko2 Volatility: Unpredictability of performance (0.06 = starting volatility) singles_volatility REAL NOT NULL DEFAULT 0.06, doubles_rating REAL NOT NULL DEFAULT 1500.0, doubles_rd REAL NOT NULL DEFAULT 350.0, doubles_volatility REAL NOT NULL DEFAULT 0.06, created_at TEXT NOT NULL DEFAULT (datetime('now')), last_played TEXT NOT NULL DEFAULT (datetime('now')) )", // Sessions table: Groups matches that occurred during a play session "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 table: Individual games (singles or doubles) within a session "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 table: Records each player's participation and rating changes per match // Stores before/after ratings to allow recalculation and audit trails "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)), -- Rating state before match rating_before REAL NOT NULL, rd_before REAL NOT NULL, volatility_before REAL NOT NULL, -- Rating state after Glicko2 calculation rating_after REAL NOT NULL, rd_after REAL NOT NULL, volatility_after REAL NOT NULL, -- Net change in rating from this match 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 query 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)", ]; for statement in &statements { if !statement.trim().is_empty() { match sqlx::query(statement).execute(pool).await { Ok(_) => {}, Err(e) => { // Ignore "table already exists" errors if !e.to_string().contains("already exists") { eprintln!("Migration error: {}", e); } } } } } Ok(()) }