Files
thrilltrack-explorer/docs/PHASE_6_DROP_JSONB_COLUMNS.sql
2025-11-03 20:58:52 +00:00

243 lines
8.9 KiB
PL/PgSQL

-- ============================================================================
-- PHASE 6: DROP JSONB COLUMNS
-- ============================================================================
--
-- ⚠️⚠️⚠️ DANGER: THIS MIGRATION IS IRREVERSIBLE ⚠️⚠️⚠️
--
-- This migration drops all JSONB columns from production tables.
-- Once executed, there is NO WAY to recover the JSONB data without a backup.
--
-- DO NOT RUN until:
-- 1. All application code has been thoroughly tested
-- 2. All queries are verified to use relational tables
-- 3. No JSONB-related errors in production logs for 2+ weeks
-- 4. Database backup has been created
-- 5. Rollback plan is prepared
-- 6. Change has been approved by technical leadership
--
-- ============================================================================
BEGIN;
-- Log this critical operation
DO $$
BEGIN
RAISE NOTICE 'Starting Phase 6: Dropping JSONB columns';
RAISE NOTICE 'This operation is IRREVERSIBLE';
RAISE NOTICE 'Timestamp: %', NOW();
END $$;
-- ============================================================================
-- STEP 1: Drop JSONB columns from audit tables
-- ============================================================================
-- admin_audit_log.details → admin_audit_details table
ALTER TABLE admin_audit_log
DROP COLUMN IF EXISTS details;
COMMENT ON TABLE admin_audit_log IS 'Admin audit log (details migrated to admin_audit_details table)';
-- moderation_audit_log.metadata → moderation_audit_metadata table
ALTER TABLE moderation_audit_log
DROP COLUMN IF EXISTS metadata;
COMMENT ON TABLE moderation_audit_log IS 'Moderation audit log (metadata migrated to moderation_audit_metadata table)';
-- profile_audit_log.changes → profile_change_fields table
ALTER TABLE profile_audit_log
DROP COLUMN IF EXISTS changes;
COMMENT ON TABLE profile_audit_log IS 'Profile audit log (changes migrated to profile_change_fields table)';
-- item_edit_history.changes → item_change_fields table
ALTER TABLE item_edit_history
DROP COLUMN IF EXISTS changes;
COMMENT ON TABLE item_edit_history IS 'Item edit history (changes migrated to item_change_fields table)';
-- ============================================================================
-- STEP 2: Drop JSONB columns from request tracking
-- ============================================================================
-- request_metadata.breadcrumbs → request_breadcrumbs table
ALTER TABLE request_metadata
DROP COLUMN IF EXISTS breadcrumbs;
-- request_metadata.environment_context (kept minimal for now, but can be dropped if not needed)
ALTER TABLE request_metadata
DROP COLUMN IF EXISTS environment_context;
COMMENT ON TABLE request_metadata IS 'Request metadata (breadcrumbs migrated to request_breadcrumbs table)';
-- ============================================================================
-- STEP 3: Drop JSONB columns from notification system
-- ============================================================================
-- notification_logs.payload → notification_event_data table
-- NOTE: Verify edge functions don't use this before dropping
ALTER TABLE notification_logs
DROP COLUMN IF EXISTS payload;
COMMENT ON TABLE notification_logs IS 'Notification logs (payload migrated to notification_event_data table)';
-- ============================================================================
-- STEP 4: Drop JSONB columns from moderation system
-- ============================================================================
-- conflict_resolutions.conflict_details → conflict_detail_fields table
ALTER TABLE conflict_resolutions
DROP COLUMN IF EXISTS conflict_details;
COMMENT ON TABLE conflict_resolutions IS 'Conflict resolutions (details migrated to conflict_detail_fields table)';
-- ============================================================================
-- STEP 5: Drop JSONB columns from contact system
-- ============================================================================
-- contact_email_threads.metadata (minimal usage, safe to drop)
ALTER TABLE contact_email_threads
DROP COLUMN IF EXISTS metadata;
-- contact_submissions.submitter_profile_data → FK to profiles table
ALTER TABLE contact_submissions
DROP COLUMN IF EXISTS submitter_profile_data;
COMMENT ON TABLE contact_submissions IS 'Contact submissions (profile data accessed via FK to profiles table)';
-- ============================================================================
-- STEP 6: Drop JSONB columns from content system
-- ============================================================================
-- content_submissions.content → submission_metadata table
-- ⚠️ CRITICAL: This is the most important change - verify thoroughly
ALTER TABLE content_submissions
DROP COLUMN IF EXISTS content;
COMMENT ON TABLE content_submissions IS 'Content submissions (metadata migrated to submission_metadata table)';
-- ============================================================================
-- STEP 7: Drop JSONB columns from review system
-- ============================================================================
-- reviews.photos → review_photos table
ALTER TABLE reviews
DROP COLUMN IF EXISTS photos;
COMMENT ON TABLE reviews IS 'Reviews (photos migrated to review_photos table)';
-- ============================================================================
-- STEP 8: Historical data tables (OPTIONAL - keep for now)
-- ============================================================================
-- Historical tables use JSONB for archive purposes - this is acceptable
-- We can keep these columns or drop them based on data retention policy
-- OPTION 1: Keep for historical reference (RECOMMENDED)
-- No action needed - historical data can use JSONB
-- OPTION 2: Drop if historical snapshots are not needed
/*
ALTER TABLE historical_parks
DROP COLUMN IF EXISTS final_state_data;
ALTER TABLE historical_rides
DROP COLUMN IF EXISTS final_state_data;
*/
-- ============================================================================
-- STEP 9: Verify no JSONB columns remain (except approved)
-- ============================================================================
DO $$
DECLARE
jsonb_count INTEGER;
BEGIN
SELECT COUNT(*) INTO jsonb_count
FROM information_schema.columns
WHERE table_schema = 'public'
AND data_type = 'jsonb'
AND table_name NOT IN (
'admin_settings', -- System config (approved)
'user_preferences', -- UI config (approved)
'user_notification_preferences', -- Notification config (approved)
'notification_channels', -- Channel config (approved)
'test_data_registry', -- Test metadata (approved)
'entity_versions_archive', -- Archive table (approved)
'historical_parks', -- Historical data (approved)
'historical_rides' -- Historical data (approved)
);
IF jsonb_count > 0 THEN
RAISE WARNING 'Found % unexpected JSONB columns still in database', jsonb_count;
ELSE
RAISE NOTICE 'SUCCESS: All production JSONB columns have been dropped';
END IF;
END $$;
-- ============================================================================
-- STEP 10: Update database comments and documentation
-- ============================================================================
COMMENT ON DATABASE postgres IS 'ThrillWiki Database - JSONB elimination completed';
-- Log completion
DO $$
BEGIN
RAISE NOTICE 'Phase 6 Complete: All JSONB columns dropped';
RAISE NOTICE 'Timestamp: %', NOW();
RAISE NOTICE 'Next steps: Update TypeScript types and documentation';
END $$;
COMMIT;
-- ============================================================================
-- POST-MIGRATION VERIFICATION QUERIES
-- ============================================================================
-- Run these queries AFTER the migration to verify success:
-- 1. List all remaining JSONB columns
/*
SELECT
table_name,
column_name,
data_type
FROM information_schema.columns
WHERE table_schema = 'public'
AND data_type = 'jsonb'
ORDER BY table_name, column_name;
*/
-- 2. Verify relational data exists
/*
SELECT
'admin_audit_details' as table_name, COUNT(*) as row_count FROM admin_audit_details
UNION ALL
SELECT 'moderation_audit_metadata', COUNT(*) FROM moderation_audit_metadata
UNION ALL
SELECT 'profile_change_fields', COUNT(*) FROM profile_change_fields
UNION ALL
SELECT 'item_change_fields', COUNT(*) FROM item_change_fields
UNION ALL
SELECT 'request_breadcrumbs', COUNT(*) FROM request_breadcrumbs
UNION ALL
SELECT 'submission_metadata', COUNT(*) FROM submission_metadata
UNION ALL
SELECT 'review_photos', COUNT(*) FROM review_photos
UNION ALL
SELECT 'conflict_detail_fields', COUNT(*) FROM conflict_detail_fields;
*/
-- 3. Check for any application errors in logs
/*
SELECT
error_type,
COUNT(*) as error_count,
MAX(created_at) as last_occurred
FROM request_metadata
WHERE error_type IS NOT NULL
AND created_at > NOW() - INTERVAL '1 hour'
GROUP BY error_type
ORDER BY error_count DESC;
*/