"""Create materialized views for game statistics Revision ID: 004 Revises: 003 Create Date: 2025-11-07 Creates three materialized views for statistics aggregation: 1. batting_game_stats - Player batting stats per game 2. pitching_game_stats - Player pitching stats per game 3. game_stats - Team totals and linescore per game Following legacy API pattern from major-domo /plays/batting and /plays/pitching. Stats are derived from plays table, making it single source of truth. """ from alembic import op # revision identifiers, used by Alembic. revision = '004' down_revision = '003' branch_labels = None depends_on = None def upgrade(): """Create materialized views for statistics.""" # 1. Batting Game Stats View op.execute(""" CREATE MATERIALIZED VIEW batting_game_stats AS SELECT l.game_id, l.id AS lineup_id, l.card_id AS player_card_id, l.team_id, -- Aggregate batting stats COUNT(*) FILTER (WHERE p.pa = 1) AS pa, COUNT(*) FILTER (WHERE p.ab = 1) AS ab, SUM(p.run) AS run, SUM(p.hit) AS hit, SUM(p.rbi) AS rbi, SUM(p.double) AS double, SUM(p.triple) AS triple, SUM(p.homerun) AS hr, SUM(p.bb) AS bb, SUM(p.so) AS so, SUM(p.hbp) AS hbp, SUM(p.sac) AS sac, SUM(p.sb) AS sb, SUM(p.cs) AS cs, SUM(p.gidp) AS gidp FROM lineups l JOIN plays p ON p.batter_id = l.id WHERE l.is_active = TRUE OR l.is_starter = TRUE GROUP BY l.game_id, l.id, l.card_id, l.team_id """) # Create unique index for fast lookups op.execute(""" CREATE UNIQUE INDEX idx_batting_game_stats_lineup ON batting_game_stats(lineup_id) """) op.execute(""" CREATE INDEX idx_batting_game_stats_game ON batting_game_stats(game_id) """) op.execute(""" CREATE INDEX idx_batting_game_stats_player ON batting_game_stats(player_card_id) """) # 2. Pitching Game Stats View op.execute(""" CREATE MATERIALIZED VIEW pitching_game_stats AS SELECT l.game_id, l.id AS lineup_id, l.card_id AS player_card_id, l.team_id, -- Aggregate pitching stats COUNT(*) FILTER (WHERE p.pa = 1) AS batters_faced, SUM(p.hit) AS hit_allowed, SUM(p.run) AS run_allowed, SUM(p.run) AS erun, -- TODO: Calculate earned runs (needs error tracking) SUM(p.bb) AS bb, SUM(p.so) AS so, SUM(p.hbp) AS hbp, SUM(p.homerun) AS hr_allowed, SUM(p.wild_pitch) AS wp, -- Calculate innings pitched from outs (IP = outs / 3.0) (SUM(p.outs_recorded)::float / 3.0) AS ip FROM lineups l JOIN plays p ON p.pitcher_id = l.id WHERE l.position = 'P' AND (l.is_active = TRUE OR l.is_starter = TRUE) GROUP BY l.game_id, l.id, l.card_id, l.team_id """) # Create indexes op.execute(""" CREATE UNIQUE INDEX idx_pitching_game_stats_lineup ON pitching_game_stats(lineup_id) """) op.execute(""" CREATE INDEX idx_pitching_game_stats_game ON pitching_game_stats(game_id) """) op.execute(""" CREATE INDEX idx_pitching_game_stats_player ON pitching_game_stats(player_card_id) """) # 3. Game Stats View (Team totals + Linescore) op.execute(""" CREATE MATERIALIZED VIEW game_stats AS WITH inning_scores AS ( -- Calculate runs scored per team per inning SELECT game_id, inning, half, SUM(run) AS runs_scored FROM plays GROUP BY game_id, inning, half ), linescores AS ( -- Build linescore JSON arrays SELECT game_id, json_agg(runs_scored ORDER BY inning) FILTER (WHERE half = 'top') AS away_linescore, json_agg(runs_scored ORDER BY inning) FILTER (WHERE half = 'bottom') AS home_linescore FROM inning_scores GROUP BY game_id ), batting_totals AS ( -- Team batting totals SELECT p.game_id, l.team_id, SUM(p.hit) AS hits, SUM(p.error) AS errors FROM plays p JOIN lineups l ON p.batter_id = l.id GROUP BY p.game_id, l.team_id ) SELECT g.id AS game_id, g.home_score AS home_runs, g.away_score AS away_runs, -- Linescore COALESCE(ls.home_linescore, '[]'::json) AS home_linescore, COALESCE(ls.away_linescore, '[]'::json) AS away_linescore, -- Home team totals MAX(bth.hits) AS home_hits, MAX(bth.errors) AS home_errors, -- Away team totals MAX(bta.hits) AS away_hits, MAX(bta.errors) AS away_errors FROM games g LEFT JOIN linescores ls ON g.id = ls.game_id LEFT JOIN batting_totals bth ON g.id = bth.game_id AND bth.team_id = g.home_team_id LEFT JOIN batting_totals bta ON g.id = bta.game_id AND bta.team_id = g.away_team_id GROUP BY g.id, ls.home_linescore, ls.away_linescore """) # Create index op.execute(""" CREATE UNIQUE INDEX idx_game_stats_game ON game_stats(game_id) """) def downgrade(): """Drop materialized views.""" op.execute("DROP MATERIALIZED VIEW IF EXISTS game_stats") op.execute("DROP MATERIALIZED VIEW IF EXISTS pitching_game_stats") op.execute("DROP MATERIALIZED VIEW IF EXISTS batting_game_stats")