#!/usr/bin/env python3 """ Major Database Migration: Account/Player Separation ==================================================== This migration separates authentication (accounts) from gameplay (characters): - Creates new 'accounts' table for login credentials - Creates new 'characters' table for game data - Migrates existing 'players' data to both tables - Updates foreign keys in related tables - Drops old 'players' table IMPORTANT: This is a breaking change. Backup your database first! """ import asyncio import asyncpg import os from datetime import datetime # Database connection DB_USER = os.getenv("POSTGRES_USER") DB_PASS = os.getenv("POSTGRES_PASSWORD") DB_NAME = os.getenv("POSTGRES_DB") DB_HOST = os.getenv("POSTGRES_HOST", "echoes_of_the_ashes_db") DB_PORT = os.getenv("POSTGRES_PORT", "5432") DATABASE_URL = f"postgresql://{DB_USER}:{DB_PASS}@{DB_HOST}:{DB_PORT}/{DB_NAME}" async def main(): print("=" * 70) print("ACCOUNT/PLAYER SEPARATION MIGRATION") print("=" * 70) print() conn = await asyncpg.connect(DATABASE_URL) try: # Step 0: Check if migration already ran print("Step 0: Checking migration status...") tables_exist = await conn.fetchval(""" SELECT EXISTS ( SELECT FROM information_schema.tables WHERE table_name = 'accounts' ) """) if tables_exist: print("⚠️ Accounts table already exists. Migration may have already run.") print(" Cleaning up previous migration attempt...") await conn.execute("DROP TABLE IF EXISTS characters CASCADE;") await conn.execute("DROP TABLE IF EXISTS accounts CASCADE;") await conn.execute("DROP TABLE IF EXISTS players_backup_20251109 CASCADE;") print("✅ Cleaned up existing tables") print() # Step 1: Backup existing players table print("Step 1: Creating backup of players table...") await conn.execute(""" CREATE TABLE IF NOT EXISTS players_backup_20251109 AS SELECT * FROM players; """) backup_count = await conn.fetchval( "SELECT COUNT(*) FROM players_backup_20251109" ) print(f"✅ Backed up {backup_count} players to players_backup_20251109") print() # Step 2: Create temporary mapping table print("Step 2: Creating temporary mapping table...") await conn.execute(""" CREATE TEMP TABLE IF NOT EXISTS player_character_mapping ( old_player_id INTEGER, new_character_id INTEGER ); """) print("✅ Created temporary mapping table") print() # Step 3: Create accounts table print("Step 3: Creating accounts table...") await conn.execute(""" CREATE TABLE IF NOT EXISTS accounts ( id SERIAL PRIMARY KEY, email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255), steam_id VARCHAR(255) UNIQUE, account_type VARCHAR(20) DEFAULT 'web', premium_expires_at REAL, email_verified BOOLEAN DEFAULT FALSE, email_verification_token VARCHAR(255), password_reset_token VARCHAR(255), password_reset_expires REAL, created_at REAL DEFAULT EXTRACT(EPOCH FROM NOW()), last_login_at REAL, CONSTRAINT check_account_type CHECK (account_type IN ('web', 'steam')) ); """) print("✅ Created accounts table") # Create indexes for accounts await conn.execute(""" CREATE INDEX IF NOT EXISTS idx_accounts_email ON accounts(email); """) await conn.execute(""" CREATE INDEX IF NOT EXISTS idx_accounts_steam_id ON accounts(steam_id); """) print("✅ Created indexes on accounts table") print() # Step 4: Create characters table print("Step 4: Creating characters table...") await conn.execute(""" CREATE TABLE IF NOT EXISTS characters ( id SERIAL PRIMARY KEY, account_id INTEGER NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, name VARCHAR(100) UNIQUE NOT NULL, avatar_data TEXT, -- RPG Stats level INTEGER DEFAULT 1, xp INTEGER DEFAULT 0, hp INTEGER DEFAULT 100, max_hp INTEGER DEFAULT 100, stamina INTEGER DEFAULT 100, max_stamina INTEGER DEFAULT 100, -- Base Attributes strength INTEGER DEFAULT 0, agility INTEGER DEFAULT 0, endurance INTEGER DEFAULT 0, intellect INTEGER DEFAULT 0, unspent_points INTEGER DEFAULT 0, -- Game State location_id VARCHAR(255) DEFAULT 'cabin', is_dead BOOLEAN DEFAULT FALSE, last_movement_time REAL DEFAULT 0, -- Timestamps created_at REAL DEFAULT EXTRACT(EPOCH FROM NOW()), last_played_at REAL DEFAULT EXTRACT(EPOCH FROM NOW()), CONSTRAINT check_unspent_points CHECK (unspent_points >= 0) ); """) print("✅ Created characters table") # Create indexes for characters await conn.execute(""" CREATE INDEX IF NOT EXISTS idx_characters_account_id ON characters(account_id); """) await conn.execute(""" CREATE INDEX IF NOT EXISTS idx_characters_name ON characters(name); """) await conn.execute(""" CREATE INDEX IF NOT EXISTS idx_characters_location_id ON characters(location_id); """) print("✅ Created indexes on characters table") print() # Step 5: Migrate existing players to accounts and characters print("Step 5: Migrating existing players...") # Get all existing players players = await conn.fetch("SELECT * FROM players ORDER BY id") print(f"Found {len(players)} players to migrate") migrated = 0 character_names_used = set() for player in players: # Generate email if not present email = player['email'] if not email: username = player['username'] or f"player_{player['id']}" email = f"{username}@echoes-migrated.local" # Ensure unique character name char_name = player['name'] if char_name in character_names_used or char_name == "Survivor": # Make it unique char_name = f"{player['username'] or 'Survivor'}_{player['id']}" character_names_used.add(char_name) # Convert to timestamp (float) now_timestamp = datetime.utcnow().timestamp() # Create account account_id = await conn.fetchval(""" INSERT INTO accounts ( email, password_hash, steam_id, account_type, premium_expires_at, created_at, last_login_at ) VALUES ($1, $2, $3, $4, $5, $6, $7) RETURNING id """, email, player['password_hash'], player.get('steam_id'), player.get('account_type', 'web'), player.get('premium_expires_at'), # Keep as is (NULL or timestamp) now_timestamp, now_timestamp ) # Create character from player data character_id = await conn.fetchval(""" INSERT INTO characters ( account_id, name, avatar_data, level, xp, hp, max_hp, stamina, max_stamina, strength, agility, endurance, intellect, unspent_points, location_id, is_dead, last_movement_time, created_at, last_played_at ) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19) RETURNING id """, account_id, char_name, # Use unique character name None, # avatar_data player['level'], player['xp'], player['hp'], player['max_hp'], player['stamina'], player['max_stamina'], player['strength'], player['agility'], player['endurance'], player['intellect'], player['unspent_points'], player['location_id'], player['is_dead'], player['last_movement_time'], now_timestamp, now_timestamp ) # Store mapping for foreign key updates await conn.execute(""" INSERT INTO player_character_mapping (old_player_id, new_character_id) VALUES ($1, $2) """, player['id'], character_id) migrated += 1 if migrated % 10 == 0: print(f" Migrated {migrated}/{len(players)} players...") print("✅ Migrated {migrated} players to accounts and characters") print() # Step 6: Update foreign keys in related tables print("Step 6: Updating foreign keys in related tables...") # Update inventory table if await conn.fetchval(""" SELECT EXISTS ( SELECT FROM information_schema.tables WHERE table_name = 'inventory' ) """): print(" Updating inventory.player_id -> character_id...") # Add new character_id column await conn.execute(""" ALTER TABLE inventory ADD COLUMN IF NOT EXISTS character_id INTEGER; """) # Copy player_id to character_id using mapping await conn.execute(""" UPDATE inventory i SET character_id = m.new_character_id FROM player_character_mapping m WHERE i.player_id = m.old_player_id; """) # Drop old player_id column and rename await conn.execute(""" ALTER TABLE inventory DROP COLUMN IF EXISTS player_id; """) # Add foreign key constraint await conn.execute(""" ALTER TABLE inventory ADD CONSTRAINT fk_inventory_character FOREIGN KEY (character_id) REFERENCES characters(id) ON DELETE CASCADE; """) print(" ✅ Updated inventory table") # Update equipment table if await conn.fetchval(""" SELECT EXISTS ( SELECT FROM information_schema.tables WHERE table_name = 'equipment' ) """): print(" Updating equipment.player_id -> character_id...") await conn.execute(""" ALTER TABLE equipment ADD COLUMN IF NOT EXISTS character_id INTEGER; """) await conn.execute(""" UPDATE equipment e SET character_id = m.new_character_id FROM player_character_mapping m WHERE e.player_id = m.old_player_id; """) await conn.execute(""" ALTER TABLE equipment DROP COLUMN IF EXISTS player_id; """) await conn.execute(""" ALTER TABLE equipment ADD CONSTRAINT fk_equipment_character FOREIGN KEY (character_id) REFERENCES characters(id) ON DELETE CASCADE; """) print(" ✅ Updated equipment table") # Update dropped_items table if await conn.fetchval(""" SELECT EXISTS ( SELECT FROM information_schema.tables WHERE table_name = 'dropped_items' ) """): # Check if column exists has_player_col = await conn.fetchval(""" SELECT EXISTS ( SELECT FROM information_schema.columns WHERE table_name = 'dropped_items' AND column_name = 'dropped_by_player_id' ) """) if has_player_col: print(" Updating dropped_items.dropped_by_player_id -> dropped_by_character_id...") await conn.execute(""" ALTER TABLE dropped_items ADD COLUMN IF NOT EXISTS dropped_by_character_id INTEGER; """) await conn.execute(""" UPDATE dropped_items d SET dropped_by_character_id = m.new_character_id FROM player_character_mapping m WHERE d.dropped_by_player_id = m.old_player_id; """) await conn.execute(""" ALTER TABLE dropped_items DROP COLUMN IF EXISTS dropped_by_player_id; """) print(" ✅ Updated dropped_items table") else: print(" ⏭️ Skipping dropped_items (no dropped_by_player_id column)") print("✅ Updated all foreign key references") print() # Step 7: Drop old players table print("Step 7: Dropping old players table...") print("⚠️ WARNING: About to drop players table (backup exists as players_backup_20251109)") print(" Press Ctrl+C within 5 seconds to cancel...") await asyncio.sleep(5) await conn.execute("DROP TABLE IF EXISTS players;") print("✅ Dropped players table") print() # Step 8: Summary print("=" * 70) print("MIGRATION COMPLETED SUCCESSFULLY!") print("=" * 70) account_count = await conn.fetchval("SELECT COUNT(*) FROM accounts") character_count = await conn.fetchval("SELECT COUNT(*) FROM characters") print(f"✅ Created {account_count} accounts") print(f"✅ Created {character_count} characters") print(f"✅ Backup preserved in: players_backup_20251109") print() print("Next steps:") print("1. Update application code to use new schema") print("2. Rebuild and restart API container") print("3. Test authentication and character selection") print("4. Update frontend to show character selection screen") print() except Exception as e: print(f"\n❌ ERROR: {e}") print("\nRolling back changes...") await conn.execute("ROLLBACK;") print("Migration failed. Database unchanged.") raise finally: await conn.close() if __name__ == "__main__": asyncio.run(main())