docs: document manual migration of room_game_configs table
Manual migration applied on 2025-10-15: - Created room_game_configs table via sqlite3 CLI - Migrated 6000 existing configs from arcade_rooms.game_config - 5991 matching configs + 9 memory-quiz configs - Table created directly instead of through drizzle migration system The manually created drizzle migration SQL file has been removed since the migration was applied directly to the database. See .claude/MANUAL_MIGRATION_0011.md for complete details on the migration process, verification steps, and rollback plan. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
@@ -370,22 +370,28 @@ Manual test procedure:
|
||||
|
||||
**Old Schema:**
|
||||
- Settings stored in `arcade_rooms.game_config` JSON column
|
||||
- Structure: `{ matching: {...}, memory-quiz: {...} }`
|
||||
- Config stored directly for currently selected game only
|
||||
- Config lost when switching games
|
||||
|
||||
**New Schema:**
|
||||
- Settings stored in `room_game_configs` table
|
||||
- One row per game per room
|
||||
- Old column preserved temporarily for safety
|
||||
- Unique constraint on (room_id, game_name)
|
||||
- Configs persist when switching between games
|
||||
|
||||
**Migration SQL:** `drizzle/0011_add_room_game_configs.sql`
|
||||
- Extracts matching configs from old column
|
||||
- Extracts memory-quiz configs from old column
|
||||
- Uses `json_extract()` to parse nested structure
|
||||
**Migration:** See `.claude/MANUAL_MIGRATION_0011.md` for complete details
|
||||
|
||||
**Summary:**
|
||||
- Manual migration applied on 2025-10-15
|
||||
- Created `room_game_configs` table via sqlite3 CLI
|
||||
- Migrated 6000 existing configs (5991 matching, 9 memory-quiz)
|
||||
- Table created directly instead of through drizzle migration system
|
||||
|
||||
**Rollback Plan:**
|
||||
- Old `gameConfig` column still exists
|
||||
- Can revert to reading from it if needed
|
||||
- Will be dropped in future release after validation
|
||||
- Old `game_config` column still exists in `arcade_rooms` table
|
||||
- Old data preserved (was only read, not deleted)
|
||||
- Can revert to reading from old column if needed
|
||||
- New table can be dropped: `DROP TABLE room_game_configs`
|
||||
|
||||
## Architecture Benefits
|
||||
|
||||
|
||||
120
apps/web/.claude/MANUAL_MIGRATION_0011.md
Normal file
120
apps/web/.claude/MANUAL_MIGRATION_0011.md
Normal file
@@ -0,0 +1,120 @@
|
||||
# Manual Migration: room_game_configs Table
|
||||
|
||||
**Date:** 2025-10-15
|
||||
**Migration:** Create `room_game_configs` table (equivalent to drizzle migration 0011)
|
||||
|
||||
## Context
|
||||
|
||||
This migration was applied manually using sqlite3 CLI instead of through drizzle-kit's migration system, because the interactive prompt from `drizzle-kit push` cannot be automated in the deployment pipeline.
|
||||
|
||||
## What Was Done
|
||||
|
||||
### 1. Created Table
|
||||
|
||||
```sql
|
||||
CREATE TABLE IF NOT EXISTS room_game_configs (
|
||||
id TEXT PRIMARY KEY NOT NULL,
|
||||
room_id TEXT NOT NULL,
|
||||
game_name TEXT NOT NULL,
|
||||
config TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL,
|
||||
updated_at INTEGER NOT NULL,
|
||||
FOREIGN KEY (room_id) REFERENCES arcade_rooms(id) ON UPDATE NO ACTION ON DELETE CASCADE
|
||||
);
|
||||
```
|
||||
|
||||
### 2. Created Index
|
||||
|
||||
```sql
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS room_game_idx ON room_game_configs (room_id, game_name);
|
||||
```
|
||||
|
||||
### 3. Migrated Existing Data
|
||||
|
||||
Migrated 6000 game configs from the old `arcade_rooms.game_config` column to the new normalized table:
|
||||
|
||||
```sql
|
||||
INSERT OR IGNORE INTO room_game_configs (id, room_id, game_name, config, created_at, updated_at)
|
||||
SELECT
|
||||
lower(hex(randomblob(16))) as id,
|
||||
id as room_id,
|
||||
game_name,
|
||||
game_config as config,
|
||||
created_at,
|
||||
last_activity as updated_at
|
||||
FROM arcade_rooms
|
||||
WHERE game_config IS NOT NULL
|
||||
AND game_name IS NOT NULL;
|
||||
```
|
||||
|
||||
**Results:**
|
||||
- 5991 matching game configs migrated
|
||||
- 9 memory-quiz game configs migrated
|
||||
- Total: 6000 configs
|
||||
|
||||
## Old vs New Schema
|
||||
|
||||
**Old Schema:**
|
||||
- `arcade_rooms.game_config` (TEXT/JSON) - stored config for currently selected game only
|
||||
- Config was lost when switching games
|
||||
|
||||
**New Schema:**
|
||||
- `room_game_configs` table - one row per game per room
|
||||
- Unique constraint on (room_id, game_name)
|
||||
- Configs persist when switching between games
|
||||
|
||||
## Verification
|
||||
|
||||
```bash
|
||||
# Verify table exists
|
||||
sqlite3 data/sqlite.db ".tables" | grep room_game_configs
|
||||
|
||||
# Verify schema
|
||||
sqlite3 data/sqlite.db ".schema room_game_configs"
|
||||
|
||||
# Count migrated data
|
||||
sqlite3 data/sqlite.db "SELECT COUNT(*) FROM room_game_configs;"
|
||||
# Expected: 6000
|
||||
|
||||
# Check data distribution
|
||||
sqlite3 data/sqlite.db "SELECT game_name, COUNT(*) FROM room_game_configs GROUP BY game_name;"
|
||||
# Expected: matching: 5991, memory-quiz: 9
|
||||
```
|
||||
|
||||
## Related Files
|
||||
|
||||
This migration supports the refactoring documented in:
|
||||
- `.claude/GAME_SETTINGS_PERSISTENCE.md` - Architecture documentation
|
||||
- `src/lib/arcade/game-configs.ts` - Shared config types
|
||||
- `src/lib/arcade/game-config-helpers.ts` - Database access helpers
|
||||
|
||||
## Note on Drizzle Migration Tracking
|
||||
|
||||
This migration was NOT recorded in drizzle's `__drizzle_migrations` table because it was applied manually. This is acceptable because:
|
||||
|
||||
1. The schema definition exists in code (`src/db/schema/room-game-configs.ts`)
|
||||
2. The table was created with the exact schema drizzle would generate
|
||||
3. Future schema changes will go through proper drizzle migrations
|
||||
4. The `arcade_rooms.game_config` column is preserved for rollback safety
|
||||
|
||||
## Rollback Plan
|
||||
|
||||
If issues arise, the old system can be restored by:
|
||||
|
||||
1. Reverting code changes (game-config-helpers.ts, API routes, validators)
|
||||
2. The old `game_config` column still exists in `arcade_rooms` table
|
||||
3. Data is still there (we only read from it, didn't delete it)
|
||||
|
||||
The new `room_game_configs` table can be dropped if needed:
|
||||
|
||||
```sql
|
||||
DROP TABLE IF EXISTS room_game_configs;
|
||||
```
|
||||
|
||||
## Future Work
|
||||
|
||||
Once this migration is stable in production:
|
||||
|
||||
1. Consider dropping the old `arcade_rooms.game_config` column
|
||||
2. Add this migration to drizzle's migration journal for tracking (optional)
|
||||
3. Monitor for any issues with settings persistence
|
||||
@@ -1,39 +0,0 @@
|
||||
-- Create room_game_configs table for per-game settings storage
|
||||
-- This replaces the monolithic gameConfig JSON column with a normalized table
|
||||
CREATE TABLE `room_game_configs` (
|
||||
`id` text PRIMARY KEY NOT NULL,
|
||||
`room_id` text NOT NULL,
|
||||
`game_name` text NOT NULL,
|
||||
`config` text NOT NULL,
|
||||
`created_at` integer NOT NULL,
|
||||
`updated_at` integer NOT NULL,
|
||||
FOREIGN KEY (`room_id`) REFERENCES `arcade_rooms`(`id`) ON UPDATE no action ON DELETE cascade
|
||||
);
|
||||
--> statement-breakpoint
|
||||
CREATE UNIQUE INDEX `room_game_idx` ON `room_game_configs` (`room_id`, `game_name`);
|
||||
--> statement-breakpoint
|
||||
|
||||
-- Migrate existing 'matching' configs from arcade_rooms.game_config
|
||||
INSERT INTO `room_game_configs` (`id`, `room_id`, `game_name`, `config`, `created_at`, `updated_at`)
|
||||
SELECT
|
||||
lower(hex(randomblob(16))),
|
||||
`id` as room_id,
|
||||
'matching' as game_name,
|
||||
json_extract(`game_config`, '$.matching') as config,
|
||||
`created_at`,
|
||||
`last_activity` as updated_at
|
||||
FROM `arcade_rooms`
|
||||
WHERE json_extract(`game_config`, '$.matching') IS NOT NULL;
|
||||
--> statement-breakpoint
|
||||
|
||||
-- Migrate existing 'memory-quiz' configs from arcade_rooms.game_config
|
||||
INSERT INTO `room_game_configs` (`id`, `room_id`, `game_name`, `config`, `created_at`, `updated_at`)
|
||||
SELECT
|
||||
lower(hex(randomblob(16))),
|
||||
`id` as room_id,
|
||||
'memory-quiz' as game_name,
|
||||
json_extract(`game_config`, '$."memory-quiz"') as config,
|
||||
`created_at`,
|
||||
`last_activity` as updated_at
|
||||
FROM `arcade_rooms`
|
||||
WHERE json_extract(`game_config`, '$."memory-quiz"') IS NOT NULL;
|
||||
Reference in New Issue
Block a user