From ea5c047b15b58b0b2ee3fa19328808332dd1b38d Mon Sep 17 00:00:00 2001 From: Cal Corum Date: Tue, 27 Jan 2026 14:03:05 -0600 Subject: [PATCH] Update migration guide with finalized production plan - Updated test results with final migration metrics (549,788 records) - Documented all tested endpoints with status - Added complete step-by-step production migration plan - Included rollback procedures and deployment checklist - Documented known limitations and connection details --- docs/POSTGRES_MIGRATION_GUIDE.md | 394 +++++++++++++++---------------- 1 file changed, 196 insertions(+), 198 deletions(-) diff --git a/docs/POSTGRES_MIGRATION_GUIDE.md b/docs/POSTGRES_MIGRATION_GUIDE.md index da59610..113fe6e 100644 --- a/docs/POSTGRES_MIGRATION_GUIDE.md +++ b/docs/POSTGRES_MIGRATION_GUIDE.md @@ -10,15 +10,57 @@ This document captures lessons learned from test migrations and provides a step- --- -## Code Changes Required +## Final Test Results -### 1. BigIntegerField for Discord IDs +### Migration Summary (January 27, 2026) -Discord snowflake IDs exceed PostgreSQL INTEGER max (2.1 billion). Changed to BIGINT: +| Metric | Value | +|--------|-------| +| **Tables Successful** | 21/27 | +| **Records Inserted** | 549,788 | +| **Records Skipped** | 168,463 (orphaned FK) | +| **Duration** | ~21 minutes | +| **gamerewards** | 10/10 ✅ | +### Tables with Orphaned Data (Expected) + +These tables have records that reference deleted teams/games - PostgreSQL correctly rejects them: + +| Table | SQLite | PostgreSQL | Skipped | Reason | +|-------|--------|------------|---------|--------| +| pack | 25,224 | 14,708 | 10,516 | Deleted teams | +| card | 71,380 | 33,412 | 37,968 | Deleted packs/teams | +| result | 2,235 | 1,224 | 1,011 | Deleted teams | +| stratgame | 5,292 | 3,760 | 1,532 | Deleted teams | +| stratplay | 418,523 | 13,963 | 404,560 | Deleted games | +| decision | 36,900 | 24,551 | 12,349 | Deleted games | + +### All Tested Endpoints ✅ + +| Endpoint | Status | +|----------|--------| +| `/api/v2/teams` | ✅ 200 | +| `/api/v2/players` | ✅ 200 | +| `/api/v2/cards` | ✅ 200 | +| `/api/v2/cardsets` | ✅ 200 | +| `/api/v2/games` | ✅ 200 | +| `/api/v2/decisions` | ✅ 200 | +| `/api/v2/decisions/rest` | ✅ 200 | +| `/api/v2/current` | ✅ 200 | +| `/api/v2/gamerewards` | ✅ 200 | +| `/api/v2/plays` | ✅ 200 | +| `/api/v2/plays/batting?group_by=player` | ✅ 200 | +| `/api/v2/plays/pitching?group_by=player` | ✅ 200 | +| `/api/v2/plays/game-summary/{id}` | ✅ 200 | + +--- + +## Code Changes Summary + +### 1. Database Schema (`app/db_engine.py`) + +**BigIntegerField for Discord IDs** (exceed INTEGER max of 2.1 billion): ```python -# app/db_engine.py - # Line 179 - Current.live_scoreboard live_scoreboard = BigIntegerField() # Discord channel ID @@ -26,175 +68,138 @@ live_scoreboard = BigIntegerField() # Discord channel ID gmid = BigIntegerField() # Discord user ID ``` -### 2. Nullable DateTimeField for Optional Timestamps - +**Nullable DateTimeField**: ```python # Line 715 - GauntletRun.ended ended = DateTimeField(null=True) # NULL means run not yet ended ``` -### 3. Migration Script Type Conversions +### 2. PostgreSQL Query Compatibility (`app/routers_v2/stratplays.py`) -The migration script (`scripts/migrate_to_postgres.py`) handles: +**FK NULL checks** - use `_id` suffix to avoid FK lookup: +```python +# Wrong (triggers FK lookup, fails if row missing): +if x.batter: + model_to_dict(x.batter) -**Boolean Columns** (SQLite 0/1 → PostgreSQL True/False): -- event.active -- cardset.for_purchase, in_packs, ranked_legal -- team.has_guide -- packtype.available -- result.ranked, short_game -- stratgame.ranked, short_game, forfeit -- stratplay.is_go_ahead, is_tied, is_new_inning -- decision.is_start -- battingcard.steal_auto -- notification.ack +# Correct: +if x.batter_id: + model_to_dict(x.batter) +``` -**DateTime Columns** (Unix ms → PostgreSQL timestamp): -- pack.open_time -- battingstat.created -- pitchingstat.created -- result.created -- stratgame.created, ended -- notification.created -- gauntletrun.created, ended -- paperdex.created -- reward.created -- award.created +**Boolean aggregation** - PostgreSQL can't sum booleans: +```python +# Wrong: +fn.SUM(Decision.is_start) -**Reserved Words** (quoted in SQL): -- notification.desc → "desc" +# Correct: +fn.SUM(Case(None, [(Decision.is_start == True, 1)], 0)) +``` + +**Explicit GROUP BY** - PostgreSQL requires all non-aggregated columns: +```python +# Added .group_by(Decision.pitcher) to aggregate queries +``` + +### 3. PostgreSQL Query Compatibility (`app/routers_v2/decisions.py`) + +**Missing GROUP BY on aggregate query**: +```python +# Added .group_by(StratPlay.pitcher, StratPlay.game) to the rest endpoint query +``` + +### 4. Migration Script (`scripts/migrate_to_postgres.py`) + +**Migration order fix** - `gamerewards` moved after `player`: +```python +MIGRATION_ORDER = [ + ... + "player", # Tier 3 + "gamerewards", # Tier 3b - depends on player + ... +] +``` + +**Type conversions handled**: +- Boolean columns: SQLite 0/1 → PostgreSQL True/False +- DateTime columns: Unix ms → PostgreSQL timestamp +- Reserved words: `notification.desc` → `"desc"` --- -## Pre-Migration Data Cleanup +## Production Migration Plan -### Required Cleanup Steps +### Prerequisites -Run these SQL commands on SQLite before migration to maximize data integrity: +1. **PostgreSQL Server Running** + - Container: `sba_postgres` (PostgreSQL 17) + - Network: `dev-sba-database_default` -```sql --- 1. Fix orphaned cards with invalid pack_id (set to NULL) -UPDATE card SET pack_id = NULL -WHERE pack_id IS NOT NULL -AND pack_id NOT IN (SELECT id FROM pack); +2. **Docker Image Built and Pushed** + ```bash + docker build -t manticorum67/paper-dynasty-database:postgres-migration . + docker push manticorum67/paper-dynasty-database:postgres-migration + ``` --- 2. Delete packs from deleted teams -DELETE FROM pack -WHERE team_id NOT IN (SELECT id FROM team); - --- 3. Delete cards from deleted teams -DELETE FROM card -WHERE team_id NOT IN (SELECT id FROM team); - --- 4. Delete duplicate stratplay records (keep lowest id) -DELETE FROM stratplay WHERE id NOT IN ( - SELECT MIN(id) FROM stratplay GROUP BY game_id, play_num -); - --- 5. Delete roster entries for deleted cards -DELETE FROM roster -WHERE card_1 NOT IN (SELECT id FROM card) - OR card_2 NOT IN (SELECT id FROM card) - -- ... continue for all 26 card positions -; - --- 6. Delete battingstat for deleted cards -DELETE FROM battingstat -WHERE card_id NOT IN (SELECT id FROM card); - --- 7. Delete pitchingstat for deleted cards -DELETE FROM pitchingstat -WHERE card_id NOT IN (SELECT id FROM card); - --- 8. Delete stratplay for deleted games -DELETE FROM stratplay -WHERE game_id NOT IN (SELECT id FROM stratgame); - --- 9. Delete decision for deleted games -DELETE FROM decision -WHERE game_id NOT IN (SELECT id FROM stratgame); -``` - -### Orphan Analysis Queries - -Before cleanup, run these to understand scope: - -```sql --- Count orphaned packs -SELECT COUNT(*) FROM pack WHERE team_id NOT IN (SELECT id FROM team); - --- Count orphaned cards (team) -SELECT COUNT(*) FROM card WHERE team_id NOT IN (SELECT id FROM team); - --- Count orphaned cards (pack) -SELECT COUNT(*) FROM card WHERE pack_id IS NOT NULL AND pack_id NOT IN (SELECT id FROM pack); - --- Count duplicate stratplays -SELECT COUNT(*) FROM ( - SELECT game_id, play_num FROM stratplay - GROUP BY game_id, play_num HAVING COUNT(*) > 1 -); - --- Count orphaned battingstats -SELECT COUNT(*) FROM battingstat WHERE card_id NOT IN (SELECT id FROM card); - --- Count orphaned pitchingstats -SELECT COUNT(*) FROM pitchingstat WHERE card_id NOT IN (SELECT id FROM card); -``` - ---- - -## Migration Execution Steps - -### Phase 1: Build Docker Image (Local) - -```bash -cd /mnt/NV2/Development/paper-dynasty/database -git checkout postgres-migration -docker build -t manticorum67/paper-dynasty-database:postgres-migration . -docker push manticorum67/paper-dynasty-database:postgres-migration -``` - -### Phase 2: Create PostgreSQL Database (Dev Server) +### Step 1: Create Database and User ```bash ssh sba-db -# Create user and database +# Create user docker exec sba_postgres psql -U sba_admin -d postgres -c \ - "CREATE USER pd_admin WITH PASSWORD 'YOUR_PASSWORD';" + "CREATE USER pd_admin WITH PASSWORD 'YOUR_SECURE_PASSWORD';" + +# Create database docker exec sba_postgres psql -U sba_admin -d postgres -c \ "CREATE DATABASE pd_master OWNER pd_admin;" + docker exec sba_postgres psql -U sba_admin -d postgres -c \ "GRANT ALL PRIVILEGES ON DATABASE pd_master TO pd_admin;" ``` -### Phase 3: Create Schema +### Step 2: Create Logs Directory + +```bash +mkdir -p /path/to/logs/database +chmod 777 /path/to/logs /path/to/logs/database +``` + +### Step 3: Create Schema ```bash docker pull manticorum67/paper-dynasty-database:postgres-migration docker run --rm \ --network dev-sba-database_default \ - -v /home/cal/container-data/dev-sba-database/logs:/usr/src/app/logs \ + -v /path/to/logs:/usr/src/app/logs \ -e DATABASE_TYPE=postgresql \ -e POSTGRES_HOST=sba_postgres \ -e POSTGRES_DB=pd_master \ -e POSTGRES_USER=pd_admin \ - -e POSTGRES_PASSWORD='YOUR_PASSWORD' \ + -e POSTGRES_PASSWORD='YOUR_SECURE_PASSWORD' \ -e POSTGRES_PORT=5432 \ manticorum67/paper-dynasty-database:postgres-migration \ python -c " from app.db_engine import db, Current, Rarity, Event, Cardset, MlbPlayer, Player, Team, PackType, Pack, Card, Roster, Result, BattingStat, PitchingStat, Award, Paperdex, Reward, GameRewards, Notification, GauntletReward, GauntletRun, BattingCard, BattingCardRatings, PitchingCard, PitchingCardRatings, CardPosition, StratGame, StratPlay, Decision db.create_tables([Current, Rarity, Event, Cardset, MlbPlayer, Player, Team, PackType, Pack, Card, Roster, Result, BattingStat, PitchingStat, Award, Paperdex, Reward, GameRewards, Notification, GauntletReward, GauntletRun, BattingCard, BattingCardRatings, PitchingCard, PitchingCardRatings, CardPosition, StratGame, StratPlay, Decision]) +print('Tables created successfully') db.close() " ``` -### Phase 4: Run Migration +### Step 4: Copy Production SQLite ```bash -docker run --rm \ +# Copy from production container +docker cp pd_database_v2:/usr/src/app/storage/pd_master.db /path/to/storage/pd_master.db +``` + +### Step 5: Run Migration + +```bash +# Run in background (takes ~21 minutes) +nohup docker run --rm \ --network dev-sba-database_default \ -v /path/to/storage:/usr/src/app/storage \ -v /path/to/logs:/usr/src/app/logs \ @@ -203,24 +208,33 @@ docker run --rm \ -e POSTGRES_HOST=sba_postgres \ -e POSTGRES_DB=pd_master \ -e POSTGRES_USER=pd_admin \ - -e POSTGRES_PASSWORD='YOUR_PASSWORD' \ + -e POSTGRES_PASSWORD='YOUR_SECURE_PASSWORD' \ -e POSTGRES_PORT=5432 \ manticorum67/paper-dynasty-database:postgres-migration \ - python scripts/migrate_to_postgres.py --sqlite-path storage/pd_master.db + python scripts/migrate_to_postgres.py --sqlite-path storage/pd_master.db > /tmp/migration.log 2>&1 & + +# Monitor progress +tail -f /tmp/migration.log ``` -### Phase 5: Verify Migration +### Step 6: Verify Migration -```sql --- Check table counts +```bash +# Check summary +grep -E '(MIGRATION SUMMARY|Tables:|Records:|Duration:)' /tmp/migration.log + +# Check key table counts +docker exec sba_postgres psql -U pd_admin -d pd_master -c " SELECT 'player' as tbl, COUNT(*) FROM player UNION ALL SELECT 'team', COUNT(*) FROM team UNION ALL SELECT 'card', COUNT(*) FROM card +UNION ALL SELECT 'gamerewards', COUNT(*) FROM gamerewards UNION ALL SELECT 'stratplay', COUNT(*) FROM stratplay ORDER BY tbl; +" ``` -### Phase 6: Start API with PostgreSQL +### Step 7: Start API Container ```bash docker run -d \ @@ -231,64 +245,26 @@ docker run -d \ -e POSTGRES_HOST=sba_postgres \ -e POSTGRES_DB=pd_master \ -e POSTGRES_USER=pd_admin \ - -e POSTGRES_PASSWORD='YOUR_PASSWORD' \ + -e POSTGRES_PASSWORD='YOUR_SECURE_PASSWORD' \ -e POSTGRES_PORT=5432 \ - -e API_TOKEN=$API_TOKEN \ + -v /path/to/logs:/usr/src/app/logs \ manticorum67/paper-dynasty-database:postgres-migration ``` ---- +### Step 8: Test Endpoints -## Test Results Summary +```bash +# Basic endpoints +for ep in "teams?limit=1" "players?limit=1" "cards?limit=1" "games?limit=1" "current" "gamerewards"; do + echo -n "$ep: " + curl -s -o /dev/null -w "%{http_code}" "http://localhost:8100/api/v2/$ep" + echo +done -### Test Migration #3 (Fresh Production Copy + Minimal Cleanup) - -| Metric | Value | -|--------|-------| -| Tables Successful | 23/29 (79%) | -| Records Inserted | 562,489 | -| Records Skipped | 218,387 | -| Duration | 25 minutes | - -**Pre-migration cleanup performed:** -- Deleted 1,953 orphaned battingstats (invalid card_id) -- Deleted 437 orphaned pitchingstats (invalid card_id) - -**Records skipped during migration (expected):** -- These are historical records from deleted teams/cards from previous seasons -- FK integrity is enforced in PostgreSQL, so orphaned records are correctly rejected -- The API functions correctly with the migrated data - -### Working Endpoints (All Tested) -- /api/v2/current -- /api/v2/teams -- /api/v2/players -- /api/v2/cards -- /api/v2/cardsets -- /api/v2/games -- /api/v2/decisions -- /api/v2/plays/batting (with group_by=player) -- /api/v2/plays/pitching (with group_by=player) - -### Fixed Issues (This Session) - -1. **NULL handling for GROUP BY foreign keys** (`app/routers_v2/stratplays.py`) - - Changed `if x.batter` → `if x.batter_id` (line ~718) - - Changed `if x.batter_team` → `if x.batter_team_id` (line ~725) - - Changed `if x.pitcher` → `if x.pitcher_id` (line ~1100) - - Changed `if x.pitcher_team` → `if x.pitcher_team_id` (line ~1103) - - **Why:** Checking `x.foreign_key` triggers FK lookup which fails if the referenced row doesn't exist. Checking `x.foreign_key_id` only checks the raw integer value. - -2. **Boolean SUM for PostgreSQL** (`app/routers_v2/stratplays.py`) - - Changed `fn.SUM(Decision.is_start)` → `fn.SUM(Case(None, [(Decision.is_start == True, 1)], 0))` - - **Why:** PostgreSQL cannot sum booleans directly; must cast to integer first. - -3. **Missing GROUP BY on Decision query** (`app/routers_v2/stratplays.py`) - - Added `.group_by(Decision.pitcher)` to the `all_dec` query - - **Why:** PostgreSQL requires explicit GROUP BY for all non-aggregate columns (SQLite was lenient). - -4. **Import Case from db_engine** (`app/routers_v2/stratplays.py`) - - Added `Case` to imports for PostgreSQL-compatible boolean aggregation +# GROUP BY endpoints (critical) +curl -s "http://localhost:8100/api/v2/plays/batting?season=10&group_by=player&limit=1" | head -c 200 +curl -s "http://localhost:8100/api/v2/plays/pitching?season=10&group_by=player&limit=1" | head -c 200 +``` --- @@ -297,16 +273,14 @@ docker run -d \ To switch back to SQLite: ```bash -# Stop PostgreSQL container +# Stop PostgreSQL API docker stop pd_postgres_api -# Start with SQLite +# Start SQLite API (original image) docker run -d \ --name pd_sqlite_api \ -p 8100:80 \ -v /path/to/storage:/usr/src/app/storage \ - -e DATABASE_TYPE=sqlite \ - -e API_TOKEN=$API_TOKEN \ manticorum67/paper-dynasty-database:latest ``` @@ -314,14 +288,38 @@ docker run -d \ ## Production Deployment Checklist -- [ ] Backup production SQLite -- [ ] Run orphan analysis on production data -- [ ] Execute cleanup SQL -- [ ] Verify cleanup counts -- [ ] Schedule maintenance window -- [ ] Run migration -- [ ] Verify record counts -- [ ] Test all endpoints -- [ ] Update docker-compose.yml with PostgreSQL config +- [ ] Backup production SQLite database +- [ ] Schedule maintenance window (~30 minutes) +- [ ] Create PostgreSQL database and user +- [ ] Create schema +- [ ] Copy fresh SQLite from production +- [ ] Run migration script +- [ ] Verify migration summary (21/27 tables, ~550K records) +- [ ] Verify gamerewards has 10 records +- [ ] Start PostgreSQL API container +- [ ] Test all endpoints (especially GROUP BY endpoints) +- [ ] Update DNS/load balancer to point to new container - [ ] Monitor for 24 hours -- [ ] Remove SQLite dependency (optional) +- [ ] Remove old SQLite container + +--- + +## Known Limitations + +1. **Orphaned historical data not migrated** - Records from deleted teams/games are correctly rejected by PostgreSQL FK constraints. This is expected and doesn't affect current gameplay. + +2. **Legacy tables excluded** - `battingstat` and `pitchingstat` are not migrated (legacy, unused by current app). + +3. **Roster table mostly empty** - Most roster records reference deleted cards. Current rosters work correctly. + +--- + +## Connection Details (Dev Environment) + +``` +PostgreSQL Host: sba_postgres +PostgreSQL Port: 5432 +Database: pd_master +User: pd_admin +Network: dev-sba-database_default +```