major-domo-database/app/dependencies.py
Cal Corum 54a1a407d0 CLAUDE: Season batting stats table and selective update system
Major database enhancement implementing fast-querying season batting stats:

Database Schema:
- Created seasonbattingstats table with composite primary key (player_id, season)
- All batting stats (counting + calculated): pa, ab, avg, obp, slg, ops, woba, etc.
- Proper foreign key constraints and performance indexes
- Production-ready SQL creation script included

Selective Update System:
- update_season_batting_stats() function with PostgreSQL upsert logic
- Triggers on game PATCH operations to update affected player stats
- Recalculates complete season stats from stratplay data
- Efficient updates of only players who participated in modified games

API Enhancements:
- Enhanced SeasonBattingStats.get_top_hitters() with full filtering support
- New /api/v3/views/season-stats/batting/refresh endpoint for season rebuilds
- Updated views endpoint to use centralized get_top_hitters() method
- Support for team, player, min PA, and pagination filtering

Infrastructure:
- Production database sync Docker service with SSH automation
- Comprehensive error handling and logging throughout
- Fixed Peewee model to match actual table structure (no auto-id)
- Updated CLAUDE.md with dev server info and sync commands

🤖 Generated with [Claude Code](https://claude.ai/code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-08-23 22:18:27 -05:00

268 lines
11 KiB
Python

import datetime
import logging
import os
from functools import wraps
from fastapi import HTTPException
from fastapi.security import OAuth2PasswordBearer
date = f'{datetime.datetime.now().year}-{datetime.datetime.now().month}-{datetime.datetime.now().day}'
logger = logging.getLogger('discord_app')
# date = f'{datetime.datetime.now().year}-{datetime.datetime.now().month}-{datetime.datetime.now().day}'
# log_level = logger.info if os.environ.get('LOG_LEVEL') == 'INFO' else 'WARN'
# logging.basicConfig(
# filename=f'logs/database/{date}.log',
# format='%(asctime)s - sba-database - %(levelname)s - %(message)s',
# level=log_level
# )
oauth2_scheme = OAuth2PasswordBearer(tokenUrl="token")
priv_help = False if not os.environ.get('PRIVATE_IN_SCHEMA') else os.environ.get('PRIVATE_IN_SCHEMA').upper()
PRIVATE_IN_SCHEMA = True if priv_help == 'TRUE' else False
def valid_token(token):
return token == os.environ.get('API_TOKEN')
def update_season_batting_stats(player_ids, season, db_connection):
"""
Update season batting stats for specific players in a given season.
Recalculates stats from stratplay data and upserts into seasonbattingstats table.
"""
if not player_ids:
logger.warning("update_season_batting_stats called with empty player_ids list")
return
# Convert single player_id to list for consistency
if isinstance(player_ids, int):
player_ids = [player_ids]
logger.info(f"Updating season batting stats for {len(player_ids)} players in season {season}")
try:
# SQL query to recalculate and upsert batting stats
query = """
WITH batting_stats AS (
SELECT
p.id AS player_id,
p.name,
p.sbaplayer_id,
p.team_id AS player_team_id,
t.abbrev AS player_team_abbrev,
sg.season,
-- Counting statistics (summed from StratPlays)
SUM(sp.pa) AS pa,
SUM(sp.ab) AS ab,
SUM(sp.run) AS run,
SUM(sp.hit) AS hit,
SUM(sp.double) AS double,
SUM(sp.triple) AS triple,
SUM(sp.homerun) AS homerun,
SUM(sp.rbi) AS rbi,
SUM(sp.bb) AS bb,
SUM(sp.so) AS so,
SUM(sp.bphr) AS bphr,
SUM(sp.bpfo) AS bpfo,
SUM(sp.bp1b) AS bp1b,
SUM(sp.bplo) AS bplo,
SUM(sp.gidp) AS gidp,
SUM(sp.hbp) AS hbp,
SUM(sp.sac) AS sac,
SUM(sp.ibb) AS ibb,
-- Calculated statistics using formulas
CASE
WHEN SUM(sp.ab) > 0
THEN ROUND(SUM(sp.hit)::DECIMAL / SUM(sp.ab), 3)
ELSE 0.000
END AS avg,
CASE
WHEN SUM(sp.pa) > 0
THEN ROUND((SUM(sp.hit) + SUM(sp.bb) + SUM(sp.hbp) + SUM(sp.ibb))::DECIMAL / SUM(sp.pa), 3)
ELSE 0.000
END AS obp,
CASE
WHEN SUM(sp.ab) > 0
THEN ROUND((SUM(sp.hit) + SUM(sp.double) + 2 * SUM(sp.triple) + 3 *
SUM(sp.homerun))::DECIMAL / SUM(sp.ab), 3)
ELSE 0.000
END AS slg,
CASE
WHEN SUM(sp.pa) > 0 AND SUM(sp.ab) > 0
THEN ROUND(
((SUM(sp.hit) + SUM(sp.bb) + SUM(sp.hbp) + SUM(sp.ibb))::DECIMAL / SUM(sp.pa)) +
((SUM(sp.hit) + SUM(sp.double) + 2 * SUM(sp.triple) + 3 *
SUM(sp.homerun))::DECIMAL / SUM(sp.ab)), 3)
ELSE 0.000
END AS ops,
-- wOBA calculation (simplified version)
CASE
WHEN SUM(sp.pa) > 0
THEN ROUND((0.690 * SUM(sp.bb) + 0.722 * SUM(sp.hbp) + 0.888 * (SUM(sp.hit) -
SUM(sp.double) - SUM(sp.triple) - SUM(sp.homerun)) +
1.271 * SUM(sp.double) + 1.616 * SUM(sp.triple) + 2.101 *
SUM(sp.homerun))::DECIMAL / SUM(sp.pa), 3)
ELSE 0.000
END AS woba,
CASE
WHEN SUM(sp.pa) > 0
THEN ROUND(SUM(sp.so)::DECIMAL / SUM(sp.pa) * 100, 1)
ELSE 0.0
END AS k_pct
FROM stratplay sp
JOIN stratgame sg ON sg.id = sp.game_id
JOIN player p ON p.id = sp.batter_id
JOIN team t ON t.id = p.team_id
WHERE sg.season = %s AND p.id = ANY(%s)
GROUP BY p.id, p.name, p.sbaplayer_id, p.team_id, t.abbrev, sg.season
),
running_stats AS (
SELECT
sp.runner_id AS player_id,
sg.season,
SUM(sp.sb) AS sb,
SUM(sp.cs) AS cs
FROM stratplay sp
JOIN stratgame sg ON sg.id = sp.game_id
WHERE sg.season = %s AND sp.runner_id IS NOT NULL AND sp.runner_id = ANY(%s)
GROUP BY sp.runner_id, sg.season
)
INSERT INTO seasonbattingstats (
player_id, sbaplayer_id, team_id, season, name, player_team_id, player_team_abbrev,
pa, ab, run, hit, double, triple, homerun, rbi, bb, so, bphr, bpfo, bp1b, bplo, gidp, hbp, sac, ibb,
avg, obp, slg, ops, woba, k_pct, sb, cs
)
SELECT
bs.player_id, bs.sbaplayer_id, bs.player_team_id, bs.season, bs.name, bs.player_team_id, bs.player_team_abbrev,
bs.pa, bs.ab, bs.run, bs.hit, bs.double, bs.triple, bs.homerun, bs.rbi, bs.bb, bs.so,
bs.bphr, bs.bpfo, bs.bp1b, bs.bplo, bs.gidp, bs.hbp, bs.sac, bs.ibb,
bs.avg, bs.obp, bs.slg, bs.ops, bs.woba, bs.k_pct,
COALESCE(rs.sb, 0) AS sb,
COALESCE(rs.cs, 0) AS cs
FROM batting_stats bs
LEFT JOIN running_stats rs ON bs.player_id = rs.player_id AND bs.season = rs.season
ON CONFLICT (player_id, season)
DO UPDATE SET
sbaplayer_id = EXCLUDED.sbaplayer_id,
team_id = EXCLUDED.team_id,
name = EXCLUDED.name,
player_team_id = EXCLUDED.player_team_id,
player_team_abbrev = EXCLUDED.player_team_abbrev,
pa = EXCLUDED.pa,
ab = EXCLUDED.ab,
run = EXCLUDED.run,
hit = EXCLUDED.hit,
double = EXCLUDED.double,
triple = EXCLUDED.triple,
homerun = EXCLUDED.homerun,
rbi = EXCLUDED.rbi,
bb = EXCLUDED.bb,
so = EXCLUDED.so,
bphr = EXCLUDED.bphr,
bpfo = EXCLUDED.bpfo,
bp1b = EXCLUDED.bp1b,
bplo = EXCLUDED.bplo,
gidp = EXCLUDED.gidp,
hbp = EXCLUDED.hbp,
sac = EXCLUDED.sac,
ibb = EXCLUDED.ibb,
avg = EXCLUDED.avg,
obp = EXCLUDED.obp,
slg = EXCLUDED.slg,
ops = EXCLUDED.ops,
woba = EXCLUDED.woba,
k_pct = EXCLUDED.k_pct,
sb = EXCLUDED.sb,
cs = EXCLUDED.cs;
"""
# Execute the query with parameters using the passed database connection
db_connection.execute_sql(query, [season, player_ids, season, player_ids])
logger.info(f"Successfully updated season batting stats for {len(player_ids)} players in season {season}")
except Exception as e:
logger.error(f"Error updating season batting stats: {e}")
raise
def handle_db_errors(func):
"""
Decorator to handle database connection errors and transaction rollbacks.
Ensures proper cleanup of database connections and provides consistent error handling.
Includes comprehensive logging with function context, timing, and stack traces.
"""
@wraps(func)
async def wrapper(*args, **kwargs):
import time
import traceback
from .db_engine import db # Import here to avoid circular imports
start_time = time.time()
func_name = f"{func.__module__}.{func.__name__}"
# Sanitize arguments for logging (exclude sensitive data)
safe_args = []
safe_kwargs = {}
try:
# Log sanitized arguments (avoid logging tokens, passwords, etc.)
for i, arg in enumerate(args):
if hasattr(arg, '__dict__') and hasattr(arg, 'url'): # FastAPI Request object
safe_args.append(f"Request({getattr(arg, 'method', 'UNKNOWN')} {getattr(arg, 'url', 'unknown')})")
else:
safe_args.append(str(arg)[:100]) # Truncate long values
for key, value in kwargs.items():
if key.lower() in ['token', 'password', 'secret', 'key']:
safe_kwargs[key] = '[REDACTED]'
else:
safe_kwargs[key] = str(value)[:100] # Truncate long values
logger.info(f"Starting {func_name} - args: {safe_args}, kwargs: {safe_kwargs}")
result = await func(*args, **kwargs)
elapsed_time = time.time() - start_time
logger.info(f"Completed {func_name} successfully in {elapsed_time:.3f}s")
return result
except Exception as e:
elapsed_time = time.time() - start_time
error_trace = traceback.format_exc()
logger.error(f"Database error in {func_name} after {elapsed_time:.3f}s")
logger.error(f"Function args: {safe_args}")
logger.error(f"Function kwargs: {safe_kwargs}")
logger.error(f"Exception: {str(e)}")
logger.error(f"Full traceback:\n{error_trace}")
try:
logger.info(f"Attempting database rollback for {func_name}")
db.rollback()
logger.info(f"Database rollback successful for {func_name}")
except Exception as rollback_error:
logger.error(f"Rollback failed in {func_name}: {rollback_error}")
finally:
try:
db.close()
logger.info(f"Database connection closed for {func_name}")
except Exception as close_error:
logger.error(f"Error closing database connection in {func_name}: {close_error}")
raise HTTPException(status_code=500, detail=f'Database error in {func_name}: {str(e)}')
return wrapper