diff --git a/CLAUDE.md b/CLAUDE.md new file mode 100644 index 0000000..9ad18eb --- /dev/null +++ b/CLAUDE.md @@ -0,0 +1,108 @@ +# CLAUDE.md + +This file provides guidance to Claude Code (claude.ai/code) when working with code in this repository. + +## Project Overview + +This is the Database API component of the Major Domo system - a FastAPI backend serving data for a Strat-o-Matic Baseball Association (SBA) fantasy league. It provides REST endpoints for Discord bots and web frontends to access league data. + +## Development Commands + +### Local Development +- **Dev server location**: `10.10.0.42` +- **Start all services**: `docker-compose up` (PostgreSQL + API + Adminer) +- **Build and start**: `docker-compose up --build` (rebuilds image with latest changes) +- **Sync from production**: `docker-compose --profile sync up sync-prod` (one-time production data sync) +- **Database migrations**: `python migrations.py` (uses files in root directory) +- **Database admin interface**: Available at `http://10.10.0.42:8080` (Adminer) + +### Docker Deployment +- **Production deployment**: Uses same `docker-compose up` workflow +- **Production server access**: `ssh akamai` then `cd container-data/sba-database` +- **Manual build**: `docker build -f Dockerfile -t major-domo-database .` + +## Architecture + +### Application Structure +``` +app/ +├── main.py # FastAPI application setup, router registration +├── db_engine.py # Peewee ORM models, database configuration +├── dependencies.py # Authentication, error handling decorators +└── routers_v3/ # API endpoints organized by domain + ├── awards.py # League awards and recognition endpoints + ├── battingstats.py # Batting statistics (seasonal and career) + ├── current.py # Current season/week status and configuration + ├── custom_commands.py # Custom command creation and management + ├── decisions.py # Strat-o-Matic game decisions and choices + ├── divisions.py # League division information + ├── draftdata.py # Draft status and current pick tracking + ├── draftlist.py # Team draft priority lists and rankings + ├── draftpicks.py # Draft pick ownership and trading + ├── fieldingstats.py # Fielding statistics (seasonal and career) + ├── injuries.py # Player injury tracking and management + ├── keepers.py # Keeper selection and management + ├── managers.py # Team manager information and profiles + ├── pitchingstats.py # Pitching statistics (seasonal and career) + ├── players.py # Player information, rosters, and statistics + ├── results.py # Game results and outcomes + ├── sbaplayers.py # SBA player pool and eligibility + ├── schedules.py # Game scheduling and matchups + ├── standings.py # League standings and team records + ├── stratgame.py # Strat-o-Matic game data and simulation + ├── stratplay.py # Individual play-by-play data and analysis + ├── teams.py # Team data, rosters, and organization + ├── transactions.py # Player transactions (trades, waivers, etc.) + └── views.py # Database views and aggregated statistics +``` + +### Database Configuration +- **Primary**: PostgreSQL via `PooledPostgresqlDatabase` (production) +- **Fallback**: SQLite with WAL mode (`storage/sba_master.db`) +- **ORM**: Peewee with model-based schema definition +- **Migrations**: Manual migrations via `playhouse.migrate` + +### Authentication & Error Handling +- **Authentication**: OAuth2 bearer token validation via `API_TOKEN` environment variable +- **Error Handling**: `@handle_db_errors` decorator provides comprehensive logging, rollback, and HTTP error responses +- **Logging**: Rotating file handler (`/tmp/sba-database.log`, 8MB max, 5 backups) + +### API Design Patterns +- **Routers**: Domain-based organization under `/api/v3/` prefix +- **Models**: Pydantic models for request/response validation +- **Database Access**: Direct Peewee ORM queries with automatic connection pooling +- **Response Format**: Consistent JSON with proper HTTP status codes + +### Environment Variables +**Required**: +- `API_TOKEN` - Authentication token for API access +- `DATABASE_TYPE` - 'postgresql' or 'sqlite' (defaults to sqlite) + +**PostgreSQL Configuration**: +- `POSTGRES_HOST`, `POSTGRES_DB`, `POSTGRES_USER`, `POSTGRES_PASSWORD`, `POSTGRES_PORT` + +**Optional**: +- `LOG_LEVEL` - INFO or WARNING (defaults to WARNING) +- `PRIVATE_IN_SCHEMA` - Include private endpoints in OpenAPI schema + +### Key Data Models +- **Current**: Season/week status, trade deadlines, playoff schedule +- **Player/Team**: Core entities with seasonal and career statistics +- **Statistics**: Separate models for batting, pitching, fielding (seasonal + career) +- **Draft System**: Draft picks, draft lists, keeper selections +- **Game Data**: Schedules, results, Strat-o-Matic play-by-play data +- **League Management**: Standings, transactions, injuries, decisions + +### Testing & Quality +- **No formal test framework currently configured** +- **API Documentation**: Auto-generated OpenAPI/Swagger at `/api/docs` +- **Health Checks**: Built into Docker configuration +- **Database Integrity**: Transaction rollback on errors via decorator + +## Important Notes + +- All active development occurs in the `/app` directory +- Root directory files (`main.py`, `db_engine.py`, etc.) are legacy and not in use +- The system supports both SQLite (development) and PostgreSQL (production) backends +- Database migrations must be manually coded using Peewee's migration system +- Authentication is required for all endpoints except documentation \ No newline at end of file diff --git a/app/db_engine.py b/app/db_engine.py index ccb9590..eecd1e3 100644 --- a/app/db_engine.py +++ b/app/db_engine.py @@ -3,7 +3,7 @@ import datetime import logging import math import os -from typing import Literal, List +from typing import Literal, List, Optional from pandas import DataFrame from peewee import * @@ -874,7 +874,7 @@ class Player(BaseModel): strat_code = CharField(max_length=100, null=True) bbref_id = CharField(max_length=50, null=True) injury_rating = CharField(max_length=50, null=True) - sbaplayer_id = ForeignKeyField(SbaPlayer, null=True) + sbaplayer = ForeignKeyField(SbaPlayer, null=True) @staticmethod def select_season(num): @@ -1994,24 +1994,24 @@ class StratGame(BaseModel): # else: # away_stan.div3_losses += 1 - # Used for one league with 3 divisions - # - update record v division - if away_div.division_abbrev == 'FD': + # Used for one league with 4 divisions + # - update record v division (check opponent's division) + if away_div.division_abbrev == 'TC': home_stan.div1_wins += 1 - elif away_div.division_abbrev == 'NLW': + elif away_div.division_abbrev == 'ETSOS': home_stan.div2_wins += 1 - elif away_div.division_abbrev == 'IWGP': + elif away_div.division_abbrev == 'APL': home_stan.div3_wins += 1 - else: + elif away_div.division_abbrev == 'BBC': home_stan.div4_wins += 1 - if home_div.division_abbrev == 'FD': + if home_div.division_abbrev == 'TC': away_stan.div1_losses += 1 - elif home_div.division_abbrev == 'NLW': + elif home_div.division_abbrev == 'ETSOS': away_stan.div2_losses += 1 - elif home_div.division_abbrev == 'IWGP': + elif home_div.division_abbrev == 'APL': away_stan.div3_losses += 1 - else: + elif home_div.division_abbrev == 'BBC': away_stan.div4_losses += 1 # Used for two league plus divisions @@ -2083,23 +2083,23 @@ class StratGame(BaseModel): # away_stan.div3_wins += 1 # Used for one league with 4 divisions - # - update record v division - if away_div.division_abbrev == 'FD': + # - update record v division (check opponent's division) + if away_div.division_abbrev == 'TC': home_stan.div1_losses += 1 - elif away_div.division_abbrev == 'NLW': + elif away_div.division_abbrev == 'ETSOS': home_stan.div2_losses += 1 - elif away_div.division_abbrev == 'IWGP': + elif away_div.division_abbrev == 'APL': home_stan.div3_losses += 1 - else: + elif away_div.division_abbrev == 'BBC': home_stan.div4_losses += 1 - if home_div.division_abbrev == 'FD': + if home_div.division_abbrev == 'TC': away_stan.div1_wins += 1 - elif home_div.division_abbrev == 'NLW': + elif home_div.division_abbrev == 'ETSOS': away_stan.div2_wins += 1 - elif home_div.division_abbrev == 'IWGP': + elif home_div.division_abbrev == 'APL': away_stan.div3_wins += 1 - else: + elif home_div.division_abbrev == 'BBC': away_stan.div4_wins += 1 # Used for two league plus divisions @@ -2355,6 +2355,158 @@ class CustomCommand(BaseModel): self.tags = None +class SeasonBattingStatsView(BaseModel): + name = CharField() + player_id = IntegerField() + sbaplayer_id = IntegerField() + season = IntegerField() + player_team_id = CharField() + pa = IntegerField() + ab = IntegerField() + run = IntegerField() + hit = IntegerField() + double = IntegerField() + triple = IntegerField() + hr = IntegerField() + rbi = IntegerField() + sb = IntegerField() + cs = IntegerField() + bb = IntegerField() + so = IntegerField() + avg = FloatField() + obp = FloatField() + slg = FloatField() + ops = FloatField() + woba = FloatField() + k_pct = FloatField() + bphr = IntegerField() + bpfo = IntegerField() + bp1b = IntegerField() + bplo = IntegerField() + gidp = IntegerField() + hbp = IntegerField() + sac = IntegerField() + ibb = IntegerField() + + class Meta: + table_name = 'season_batting_stats_view' + primary_key = False + + @staticmethod + def get_by_season(season): + return SeasonBattingStatsView.select().where(SeasonBattingStatsView.season == season) + + @staticmethod + def get_team_stats(season, team_id): + return (SeasonBattingStatsView.select() + .where(SeasonBattingStatsView.season == season, + SeasonBattingStatsView.player_team_id == team_id)) + + @staticmethod + def get_top_hitters(season, stat='avg', limit=10, desc=True): + """Get top hitters by specified stat (avg, hr, rbi, ops, etc.)""" + stat_field = getattr(SeasonBattingStatsView, stat, SeasonBattingStatsView.avg) + order_field = stat_field.desc() if desc else stat_field.asc() + return (SeasonBattingStatsView.select() + .where(SeasonBattingStatsView.season == season) + .order_by(order_field) + .limit(limit)) + + +class SeasonBattingStats(BaseModel): + player = ForeignKeyField(Player) + sbaplayer = ForeignKeyField(SbaPlayer, null=True) + team = ForeignKeyField(Team) + season = IntegerField() + name = CharField() + player_team_id = IntegerField() + player_team_abbrev = CharField() + + # Counting stats + pa = IntegerField() + ab = IntegerField() + run = IntegerField() + hit = IntegerField() + double = IntegerField() + triple = IntegerField() + homerun = IntegerField() + rbi = IntegerField() + bb = IntegerField() + so = IntegerField() + bphr = IntegerField() + bpfo = IntegerField() + bp1b = IntegerField() + bplo = IntegerField() + gidp = IntegerField() + hbp = IntegerField() + sac = IntegerField() + ibb = IntegerField() + + # Calculating stats + avg = FloatField() + obp = FloatField() + slg = FloatField() + ops = FloatField() + woba = FloatField() + k_pct = FloatField() + + # Running stats + sb = IntegerField() + cs = IntegerField() + + class Meta: + table_name = 'seasonbattingstats' + primary_key = CompositeKey('player', 'season') + + @staticmethod + def get_team_stats(season, team_id): + return (SeasonBattingStats.select() + .where(SeasonBattingStats.season == season, + SeasonBattingStats.player_team_id == team_id)) + + @staticmethod + def get_top_hitters(season: Optional[int] = None, stat: str = 'woba', limit: Optional[int] = 200, + desc: bool = True, team_id: Optional[int] = None, player_id: Optional[int] = None, + sbaplayer_id: Optional[int] = None, min_pa: Optional[int] = None, offset: int = 0): + """ + Get top hitters by specified stat with optional filtering. + + Args: + season: Season to filter by (None for all seasons) + stat: Stat field to sort by (default: woba) + limit: Maximum number of results (None for no limit) + desc: Sort descending if True, ascending if False + team_id: Filter by team ID + player_id: Filter by specific player ID + min_pa: Minimum plate appearances filter + offset: Number of results to skip for pagination + """ + stat_field = getattr(SeasonBattingStats, stat, SeasonBattingStats.woba) + order_field = stat_field.desc() if desc else stat_field.asc() + + query = SeasonBattingStats.select().order_by(order_field) + + # Apply filters + if season is not None: + query = query.where(SeasonBattingStats.season == season) + if team_id is not None: + query = query.where(SeasonBattingStats.player_team_id == team_id) + if player_id is not None: + query = query.where(SeasonBattingStats.player_id == player_id) + if sbaplayer_id is not None: + query = query.where(SeasonBattingStats.sbaplayer_id == sbaplayer_id) + if min_pa is not None: + query = query.where(SeasonBattingStats.pa >= min_pa) + + # Apply pagination + if offset > 0: + query = query.offset(offset) + if limit is not None and limit > 0: + query = query.limit(limit) + + return query + + # class Streak(BaseModel): # player = ForeignKeyField(Player) # streak_type = CharField() diff --git a/app/dependencies.py b/app/dependencies.py index e415e6b..0d0efb9 100644 --- a/app/dependencies.py +++ b/app/dependencies.py @@ -27,6 +27,176 @@ 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. diff --git a/app/routers_v3/stratgame.py b/app/routers_v3/stratgame.py index 2a00a5d..672153b 100644 --- a/app/routers_v3/stratgame.py +++ b/app/routers_v3/stratgame.py @@ -4,8 +4,8 @@ import copy import logging import pydantic -from ..db_engine import db, StratGame, Team, model_to_dict, chunked, fn -from ..dependencies import oauth2_scheme, valid_token, PRIVATE_IN_SCHEMA, handle_db_errors +from ..db_engine import db, StratGame, Team, StratPlay, model_to_dict, chunked, fn +from ..dependencies import oauth2_scheme, valid_token, PRIVATE_IN_SCHEMA, handle_db_errors, update_season_batting_stats logger = logging.getLogger('discord_app') @@ -146,11 +146,25 @@ async def patch_game( this_game.scorecard_url = scorecard_url if this_game.save() == 1: + # Update batting stats for all batters in this game + try: + # Get all unique batter IDs from stratplays in this game + batter_ids = [row.batter_id for row in StratPlay.select(StratPlay.batter_id.distinct()) + .where(StratPlay.game_id == game_id)] + + if batter_ids: + update_season_batting_stats(batter_ids, this_game.season, db) + logger.info(f'Updated batting stats for {len(batter_ids)} players from game {game_id}') + else: + logger.error(f'No batters found for game_id {game_id}') + + except Exception as e: + logger.error(f'Failed to update batting stats for game {game_id}: {e}') + # Don't fail the patch operation if stats update fails + g_result = model_to_dict(this_game) - db.close() return g_result else: - db.close() raise HTTPException(status_code=500, detail=f'Unable to patch game {game_id}') diff --git a/app/routers_v3/views.py b/app/routers_v3/views.py new file mode 100644 index 0000000..09cfab4 --- /dev/null +++ b/app/routers_v3/views.py @@ -0,0 +1,107 @@ +from fastapi import APIRouter, Response, HTTPException, Query, Depends +from typing import List, Literal, Optional +import logging +import pydantic + +from ..db_engine import SeasonBattingStats, db, Manager, Team, Current, model_to_dict, fn, query_to_csv, StratPlay, StratGame +from ..dependencies import oauth2_scheme, valid_token, PRIVATE_IN_SCHEMA, handle_db_errors, update_season_batting_stats + +logger = logging.getLogger('discord_app') + +router = APIRouter( + prefix='/api/v3/views', + tags=['views'] +) + +@router.get('/season-stats/batting') +@handle_db_errors +async def get_season_batting_stats( + season: Optional[int] = None, + team_id: Optional[int] = None, + player_id: Optional[int] = None, + sbaplayer_id: Optional[int] = None, + min_pa: Optional[int] = None, # Minimum plate appearances + sort_by: str = "woba", # Default sort field + sort_order: Literal['asc', 'desc'] = 'desc', # asc or desc + limit: Optional[int] = 200, + offset: int = 0, + csv: Optional[bool] = False +): + logger.info(f'Getting season {season} batting stats - team_id: {team_id}, player_id: {player_id}, min_pa: {min_pa}, sort_by: {sort_by}, sort_order: {sort_order}, limit: {limit}, offset: {offset}') + + # Use the enhanced get_top_hitters method + query = SeasonBattingStats.get_top_hitters( + season=season, + stat=sort_by, + limit=limit if limit != 0 else None, + desc=(sort_order.lower() == 'desc'), + team_id=team_id, + player_id=player_id, + sbaplayer_id=sbaplayer_id, + min_pa=min_pa, + offset=offset + ) + + # Build applied filters for response + applied_filters = {} + if season is not None: + applied_filters['season'] = season + if team_id is not None: + applied_filters['team_id'] = team_id + if player_id is not None: + applied_filters['player_id'] = player_id + if min_pa is not None: + applied_filters['min_pa'] = min_pa + + if csv: + return_val = query_to_csv(query) + return Response(content=return_val, media_type='text/csv') + else: + stat_list = [model_to_dict(stat) for stat in query] + return { + 'count': len(stat_list), + 'filters': applied_filters, + 'stats': stat_list + } + + +@router.post('/season-stats/batting/refresh', include_in_schema=PRIVATE_IN_SCHEMA) +@handle_db_errors +async def refresh_season_batting_stats( + season: int, + token: str = Depends(oauth2_scheme) +) -> dict: + """ + Refresh batting stats for all players in a specific season. + Useful for full season updates. + """ + if not valid_token(token): + logger.warning(f'refresh_season_batting_stats - Bad Token: {token}') + raise HTTPException(status_code=401, detail='Unauthorized') + + logger.info(f'Refreshing all batting stats for season {season}') + + try: + # Get all player IDs who have stratplay records in this season + batter_ids = [row.batter_id for row in + StratPlay.select(StratPlay.batter_id.distinct()) + .join(StratGame).where(StratGame.season == season)] + + if batter_ids: + update_season_batting_stats(batter_ids, season, db) + logger.info(f'Successfully refreshed {len(batter_ids)} players for season {season}') + + return { + 'message': f'Season {season} batting stats refreshed', + 'players_updated': len(batter_ids) + } + else: + logger.warning(f'No batting data found for season {season}') + return { + 'message': f'No batting data found for season {season}', + 'players_updated': 0 + } + + except Exception as e: + logger.error(f'Error refreshing season {season}: {e}') + raise HTTPException(status_code=500, detail=f'Refresh failed: {str(e)}') diff --git a/create_season_batting_stats_table.sql b/create_season_batting_stats_table.sql new file mode 100644 index 0000000..86fd348 --- /dev/null +++ b/create_season_batting_stats_table.sql @@ -0,0 +1,63 @@ +-- Create season batting stats table for production +-- This table stores aggregated seasonal batting statistics for fast querying +-- Updated with proper columns and constraints based on dev testing + +CREATE TABLE seasonbattingstats ( + -- Primary identifiers (composite primary key) + player_id INTEGER NOT NULL, + season INTEGER NOT NULL, + + -- Additional identifiers and metadata + name VARCHAR(255), + sbaplayer_id INTEGER, + team_id INTEGER NOT NULL, + player_team_id INTEGER, + player_team_abbrev VARCHAR(10), + + -- Counting statistics (summed from StratPlays) + pa INTEGER NOT NULL DEFAULT 0, + ab INTEGER NOT NULL DEFAULT 0, + run INTEGER NOT NULL DEFAULT 0, + hit INTEGER NOT NULL DEFAULT 0, + double INTEGER NOT NULL DEFAULT 0, + triple INTEGER NOT NULL DEFAULT 0, + homerun INTEGER NOT NULL DEFAULT 0, + rbi INTEGER NOT NULL DEFAULT 0, + bb INTEGER NOT NULL DEFAULT 0, + so INTEGER NOT NULL DEFAULT 0, + bphr INTEGER NOT NULL DEFAULT 0, + bpfo INTEGER NOT NULL DEFAULT 0, + bp1b INTEGER NOT NULL DEFAULT 0, + bplo INTEGER NOT NULL DEFAULT 0, + gidp INTEGER NOT NULL DEFAULT 0, + hbp INTEGER NOT NULL DEFAULT 0, + sac INTEGER NOT NULL DEFAULT 0, + ibb INTEGER NOT NULL DEFAULT 0, + sb INTEGER NOT NULL DEFAULT 0, + cs INTEGER NOT NULL DEFAULT 0, + + -- Calculated statistics + avg REAL NOT NULL DEFAULT 0.000, + obp REAL NOT NULL DEFAULT 0.000, + slg REAL NOT NULL DEFAULT 0.000, + ops REAL NOT NULL DEFAULT 0.000, + woba REAL NOT NULL DEFAULT 0.000, + k_pct REAL NOT NULL DEFAULT 0.0, + + -- Constraints + PRIMARY KEY (player_id, season), + FOREIGN KEY (player_id) REFERENCES player(id), + FOREIGN KEY (sbaplayer_id) REFERENCES sbaplayer(id), + FOREIGN KEY (team_id) REFERENCES team(id) +); + +-- Create indexes for better query performance +CREATE INDEX idx_seasonbattingstats_season ON seasonbattingstats (season); +CREATE INDEX idx_seasonbattingstats_teamseason ON seasonbattingstats (season, team_id); +CREATE INDEX idx_seasonbattingstats_sbaplayer ON seasonbattingstats (sbaplayer_id); + +-- Comments for documentation +COMMENT ON TABLE seasonbattingstats IS 'Aggregated seasonal batting statistics for fast querying. Updated via selective updates when games are posted.'; +COMMENT ON COLUMN seasonbattingstats.player_id IS 'Player ID - part of composite primary key'; +COMMENT ON COLUMN seasonbattingstats.season IS 'Season number - part of composite primary key'; +COMMENT ON COLUMN seasonbattingstats.sbaplayer_id IS 'SBA Player ID - can be NULL for some players'; \ No newline at end of file diff --git a/docker-compose.yml b/docker-compose.yml index 50e98bb..1909268 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -68,5 +68,29 @@ services: depends_on: - postgres + sync-prod: + image: alpine:latest + container_name: sba_sync_prod + volumes: + - ./scripts:/scripts + - /home/cal/.ssh:/tmp/ssh:ro + environment: + - SBA_DB_USER=${SBA_DB_USER} + - SBA_DATABASE=${SBA_DATABASE} + - SBA_DB_USER_PASSWORD=${SBA_DB_USER_PASSWORD} + command: > + sh -c " + cp -r /tmp/ssh /root/.ssh && + chmod 700 /root/.ssh && + chmod 600 /root/.ssh/* && + chown -R root:root /root/.ssh && + /scripts/sync_from_prod.sh + " + profiles: ["sync"] + depends_on: + - postgres + networks: + - default + volumes: postgres_data: \ No newline at end of file diff --git a/scripts/sync_from_prod.sh b/scripts/sync_from_prod.sh new file mode 100755 index 0000000..f0ce63d --- /dev/null +++ b/scripts/sync_from_prod.sh @@ -0,0 +1,58 @@ +#!/bin/sh +set -e + +# Error handling function +error_exit() { + echo "ERROR: $1" >&2 + exit 1 +} + +# Cleanup function +cleanup() { + if [ -f "/tmp/prod_dump.sql" ]; then + echo "Cleaning up temporary files..." + rm -f /tmp/prod_dump.sql + fi +} + +# Set trap for cleanup on exit +trap cleanup EXIT + +echo "Starting production database sync..." + +# Validate required environment variables +[ -z "$SBA_DB_USER" ] && error_exit "SBA_DB_USER environment variable not set" +[ -z "$SBA_DATABASE" ] && error_exit "SBA_DATABASE environment variable not set" + +echo "Production server: akamai" +echo "Target database: ${SBA_DATABASE}" +echo "Target user: ${SBA_DB_USER}" + +# Install necessary packages +echo "Installing required packages..." +apk add --no-cache openssh-client postgresql-client || error_exit "Failed to install required packages" + +# Test SSH connection first +echo "Testing SSH connection to production server..." +ssh -o StrictHostKeyChecking=no -o ConnectTimeout=10 akamai "echo 'SSH connection successful'" || error_exit "Failed to connect to production server" + +# Test local database connection +echo "Testing local database connection..." +pg_isready -h sba_postgres -U ${SBA_DB_USER} -d ${SBA_DATABASE} || error_exit "Local database is not ready" + +# Create dump from production server first (safer than direct pipe) +echo "Creating dump from production server..." +ssh -o StrictHostKeyChecking=no akamai \ + "cd container-data/sba-database && source .env && docker exec -e PGPASSWORD=\$SBA_DB_USER_PASSWORD sba_postgres pg_dump -U \$SBA_DB_USER -d \$SBA_DATABASE" \ + > /tmp/prod_dump.sql || error_exit "Failed to create production database dump" + +# Verify dump file is not empty +[ ! -s "/tmp/prod_dump.sql" ] && error_exit "Production dump file is empty" + +echo "Dump created successfully ($(wc -l < /tmp/prod_dump.sql) lines)" + +# Restore to local database +echo "Restoring to local database..." +PGPASSWORD=${SBA_DB_USER_PASSWORD} psql -h sba_postgres -U ${SBA_DB_USER} -d ${SBA_DATABASE} -f /tmp/prod_dump.sql || error_exit "Failed to restore database dump" + +echo "Database sync completed successfully!" \ No newline at end of file