-- Performance Optimization Indexes -- Date: October 21, 2025 -- Purpose: Add indexes to improve background task performance at scale -- ============================================ -- 1. Stamina Regeneration Index -- ============================================ -- Speeds up: regenerate_all_players_stamina() -- Query: WHERE is_dead = FALSE AND stamina < max_stamina -- -- Before: Full table scan on every cycle (5 minutes) -- After: Index scan only on relevant rows -- -- Impact at 10K players: -- - Without index: ~100-500ms to find eligible players -- - With index: ~10-20ms to find eligible players CREATE INDEX IF NOT EXISTS idx_players_stamina_regen ON players(is_dead, stamina) WHERE is_dead = FALSE AND stamina < max_stamina; -- Partial index only includes living players below max stamina -- Much smaller than full index, faster to maintain -- ============================================ -- 2. Combat Timer Index -- ============================================ -- Speeds up: check_combat_timers() -- Query: WHERE turn_started_at < idle_threshold -- -- Before: Full table scan every 30 seconds -- After: Index scan on timestamp -- -- Impact at 500 active combats: -- - Without index: ~50-100ms to find idle combats -- - With index: ~5-10ms to find idle combats CREATE INDEX IF NOT EXISTS idx_combat_turn_time ON active_combats(turn_started_at); -- Simple timestamp index for range queries -- Used for finding combats idle > 5 minutes -- ============================================ -- 3. Dropped Items Cleanup Index -- ============================================ -- Speeds up: decay_dropped_items() -- Query: WHERE drop_timestamp < timestamp_limit -- -- Note: This is likely already optimal, but adding for completeness -- -- Impact: Minimal (single DELETE query already efficient) -- But helps with very large item tables (100K+ items) CREATE INDEX IF NOT EXISTS idx_dropped_items_timestamp ON dropped_items(drop_timestamp); -- ============================================ -- 4. Player Corpse Cleanup Index -- ============================================ -- Speeds up: decay_corpses() -- Query: WHERE death_timestamp < timestamp_limit CREATE INDEX IF NOT EXISTS idx_player_corpses_timestamp ON player_corpses(death_timestamp); CREATE INDEX IF NOT EXISTS idx_npc_corpses_timestamp ON npc_corpses(death_timestamp); -- ============================================ -- 5. Combat State Index (Composite) -- ============================================ -- Speeds up queries that check both turn and timestamp -- Useful for more complex idle combat logic CREATE INDEX IF NOT EXISTS idx_combat_turn_state ON active_combats(turn, turn_started_at); -- Composite index: can answer "WHERE turn = 'player' AND turn_started_at < X" -- More specific than single-column index -- ============================================ -- Verification Queries -- ============================================ -- Run these to verify indexes are being used: -- 1. Check stamina regen query plan: -- EXPLAIN ANALYZE -- SELECT telegram_id, stamina, max_stamina, endurance -- FROM players -- WHERE is_dead = FALSE AND stamina < max_stamina; -- -- Should show: "Index Scan using idx_players_stamina_regen" -- 2. Check combat timer query plan: -- EXPLAIN ANALYZE -- SELECT * FROM active_combats -- WHERE turn_started_at < (EXTRACT(EPOCH FROM NOW()) - 300); -- -- Should show: "Index Scan using idx_combat_turn_time" -- 3. Check index sizes: -- SELECT -- schemaname, -- tablename, -- indexname, -- pg_size_pretty(pg_relation_size(indexrelid)) AS index_size -- FROM pg_stat_user_indexes -- WHERE schemaname = 'public' -- ORDER BY pg_relation_size(indexrelid) DESC; -- ============================================ -- Performance Impact Summary -- ============================================ -- -- Expected improvements at 10,000 players: -- -- regenerate_stamina(): -- - Before: 50+ seconds (10K individual UPDATEs) -- - After optimization: 0.5s (single UPDATE) -- - Index adds: ~100ms improvement in WHERE clause -- - Total: 500-600ms per cycle -- -- check_combat_timers() (500 active combats): -- - Before: 50-100ms to find idle combats -- - After: 5-10ms to find idle combats -- - 10x faster SELECT -- -- decay_dropped_items(): -- - Before: Already fast (~100ms) -- - After: Minimal change (~80ms) -- - Already optimal design -- -- TOTAL BACKGROUND TASK TIME: -- - Before all optimizations: 60+ seconds every 5 minutes -- - After all optimizations: <1 second every 5 minutes -- - 60x improvement! -- -- ============================================ -- Maintenance Notes -- ============================================ -- -- These indexes will be automatically maintained by PostgreSQL. -- -- Index bloat monitoring: -- SELECT -- schemaname, -- tablename, -- indexname, -- pg_size_pretty(pg_relation_size(indexrelid)) AS size, -- idx_scan AS scans, -- idx_tup_read AS tuples_read, -- idx_tup_fetch AS tuples_fetched -- FROM pg_stat_user_indexes -- WHERE schemaname = 'public' -- ORDER BY pg_relation_size(indexrelid) DESC; -- -- If index is large but rarely used (low idx_scan), consider dropping it. -- All indexes above should have high scan counts in production.