mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-22 17:31:15 -05:00
5.1 KiB
5.1 KiB
Migration Guide
Migrating from JSONB entity_versions to relational version tables
Status
✅ Migration Complete - The relational versioning system is now active. This guide documents the migration for reference.
Overview
The old system stored versions in a single entity_versions table using JSONB:
- ❌ Not queryable
- ❌ No type safety
- ❌ Poor performance
- ❌ Complex RLS
The new system uses dedicated relational tables:
- ✅ Fully queryable
- ✅ Type-safe with foreign keys
- ✅ Indexed and performant
- ✅ Standard RLS policies
Migration Timeline
- Phase 1: Create relational tables ✅ Complete
- Phase 2: Enable triggers ✅ Complete
- Phase 3: Dual-write period ✅ Complete
- Phase 4: Backfill historical data ⏸️ Optional
- Phase 5: Monitor 🔄 Ongoing
- Phase 6: Deprecate JSONB table 📅 Future
Current State
- ✅ All new versions written to relational tables
- ✅ Triggers active on all entity tables
- ✅ Automated cleanup scheduled via pg_cron
- ⚠️ Old
entity_versionstable retained for backward compatibility - ⚠️
src/lib/versioningHelpers.tsdeprecated but not removed (scheduled for removal: 2025-12-01)
Migration Timeline
✅ Phase 1: New System Deployed (Completed)
- Relational version tables created (
park_versions,ride_versions, etc.) - Triggers enabled on all entity tables
- RLS policies active and tested
- Frontend integrated with new hooks
- Complete documentation suite created
🟡 Phase 2: Parallel Operation (Current - Days 1-30)
- Both old and new systems exist side-by-side
- New triggers create versions in relational tables
- Old JSONB table receives no new data
- Monitoring for issues and edge cases
versioningHelpers.tsmarked as deprecated
Action Items:
- Monitor version creation in new tables
- Verify no new inserts to old
entity_versionstable - Search codebase for deprecated function usage
- Collect feedback from team
🔵 Phase 3: Archive Legacy Data (Day 30)
- Archive old
entity_versionstoentity_versions_archive - Verify data integrity and counts match
- Keep archive for 60 more days as safety net
- Document archive location and access procedures
SQL Migration:
-- See supabase/migrations/*_archive_legacy_versions.sql
CREATE TABLE entity_versions_archive (LIKE entity_versions INCLUDING ALL);
INSERT INTO entity_versions_archive SELECT * FROM entity_versions;
🟢 Phase 4: Drop Legacy Tables (Day 90)
- Drop old
entity_versionstable - Drop old RPC functions (
create_entity_version,compare_versions, etc.) - Remove
src/lib/versioningHelpers.tsfile - Remove archive table (or retain indefinitely for audit)
- Update all documentation to remove references to old system
SQL Migration:
-- See supabase/migrations/*_drop_legacy_versions.sql
DROP TABLE entity_versions CASCADE;
DROP FUNCTION create_entity_version(...);
🚀 Phase 5: Optimization (Ongoing)
- Automated cleanup via pg_cron (monthly)
- Performance monitoring and index tuning
- Documentation updates based on usage patterns
- Version retention policy adjustments as needed
Backfill Script (Optional)
If you need to migrate historical JSONB versions to relational:
-- Backfill park versions
INSERT INTO park_versions (
version_id, park_id, version_number, created_at, created_by,
change_type, submission_id, is_current,
name, slug, description, park_type, status,
opening_date, opening_date_precision, closing_date, closing_date_precision,
location_id, operator_id, property_owner_id,
website_url, phone, email,
banner_image_url, banner_image_id, card_image_url, card_image_id
)
SELECT
ev.id, ev.entity_id, ev.version_number, ev.changed_at, ev.changed_by,
ev.change_type, ev.submission_id, ev.is_current,
ev.version_data->>'name',
ev.version_data->>'slug',
ev.version_data->>'description',
ev.version_data->>'park_type',
ev.version_data->>'status',
(ev.version_data->>'opening_date')::date,
ev.version_data->>'opening_date_precision',
(ev.version_data->>'closing_date')::date,
ev.version_data->>'closing_date_precision',
(ev.version_data->>'location_id')::uuid,
(ev.version_data->>'operator_id')::uuid,
(ev.version_data->>'property_owner_id')::uuid,
ev.version_data->>'website_url',
ev.version_data->>'phone',
ev.version_data->>'email',
ev.version_data->>'banner_image_url',
ev.version_data->>'banner_image_id',
ev.version_data->>'card_image_url',
ev.version_data->>'card_image_id'
FROM entity_versions ev
WHERE ev.entity_type = 'park'
ON CONFLICT DO NOTHING;
Cleanup (Future)
When ready to fully deprecate JSONB system:
-- 1. Verify all versions migrated
SELECT COUNT(*) FROM entity_versions; -- Should match relational tables
-- 2. Drop old table (IRREVERSIBLE)
DROP TABLE IF EXISTS entity_versions CASCADE;
-- 3. Remove deprecated helpers
-- Delete src/lib/versioningHelpers.ts
Rollback Plan
If issues arise, rollback steps:
- Disable triggers on entity tables
- Revert edge functions to use old JSONB system
- Keep relational tables for future retry
Note: Not recommended - new system is production-ready.