mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:31:13 -05:00
263 lines
9.5 KiB
SQL
263 lines
9.5 KiB
SQL
-- ============================================================================
|
|
-- PHASE 6: DROP JSONB COLUMNS (With View Dependencies Fixed)
|
|
-- ============================================================================
|
|
--
|
|
-- ⚠️⚠️⚠️ 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.
|
|
--
|
|
-- ============================================================================
|
|
|
|
-- 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 0: Drop views that depend on JSONB columns
|
|
-- ============================================================================
|
|
|
|
DROP VIEW IF EXISTS moderation_queue_with_entities CASCADE;
|
|
|
|
-- ============================================================================
|
|
-- 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
|
|
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
|
|
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
|
|
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
|
|
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: Recreate views without JSONB columns
|
|
-- ============================================================================
|
|
|
|
-- Recreate moderation_queue_with_entities view WITHOUT content column
|
|
CREATE VIEW moderation_queue_with_entities AS
|
|
SELECT
|
|
cs.id,
|
|
cs.submission_type,
|
|
cs.status,
|
|
|
|
-- Temporal fields (with backward compatibility alias)
|
|
cs.submitted_at AS created_at, -- Primary alias for frontend
|
|
cs.submitted_at, -- Also expose for semantic accuracy
|
|
cs.reviewed_at,
|
|
cs.assigned_at,
|
|
cs.escalated_at,
|
|
|
|
-- User relationships
|
|
cs.user_id as submitter_id,
|
|
cs.reviewer_id as reviewed_by,
|
|
cs.assigned_to,
|
|
cs.locked_until,
|
|
|
|
-- Flags and metadata
|
|
cs.escalated,
|
|
cs.escalation_reason,
|
|
cs.reviewer_notes,
|
|
cs.is_test_data,
|
|
-- NOTE: content column removed - use submission_metadata table instead
|
|
|
|
-- Submitter profile (matches frontend expectations)
|
|
CASE
|
|
WHEN sp.id IS NOT NULL THEN
|
|
jsonb_build_object(
|
|
'user_id', sp.user_id,
|
|
'username', sp.username,
|
|
'display_name', sp.display_name,
|
|
'avatar_url', sp.avatar_url
|
|
)
|
|
ELSE NULL
|
|
END as submitter_profile,
|
|
|
|
-- Reviewer profile
|
|
CASE
|
|
WHEN rp.id IS NOT NULL THEN
|
|
jsonb_build_object(
|
|
'user_id', rp.user_id,
|
|
'username', rp.username,
|
|
'display_name', rp.display_name,
|
|
'avatar_url', rp.avatar_url
|
|
)
|
|
ELSE NULL
|
|
END as reviewer_profile,
|
|
|
|
-- Assigned moderator profile
|
|
CASE
|
|
WHEN ap.id IS NOT NULL THEN
|
|
jsonb_build_object(
|
|
'user_id', ap.user_id,
|
|
'username', ap.username,
|
|
'display_name', ap.display_name,
|
|
'avatar_url', ap.avatar_url
|
|
)
|
|
ELSE NULL
|
|
END as assigned_profile,
|
|
|
|
-- Submission items with entity data
|
|
(
|
|
SELECT jsonb_agg(
|
|
jsonb_build_object(
|
|
'id', si.id,
|
|
'submission_id', si.submission_id,
|
|
'item_type', si.item_type,
|
|
'item_data_id', si.item_data_id,
|
|
'action_type', si.action_type,
|
|
'status', si.status,
|
|
'order_index', si.order_index,
|
|
'depends_on', si.depends_on,
|
|
'approved_entity_id', si.approved_entity_id,
|
|
'rejection_reason', si.rejection_reason,
|
|
'created_at', si.created_at,
|
|
'updated_at', si.updated_at,
|
|
'entity_data', get_submission_item_entity_data(si.item_type, si.item_data_id)
|
|
)
|
|
ORDER BY si.order_index
|
|
)
|
|
FROM submission_items si
|
|
WHERE si.submission_id = cs.id
|
|
) as submission_items
|
|
|
|
FROM content_submissions cs
|
|
LEFT JOIN profiles sp ON sp.user_id = cs.user_id
|
|
LEFT JOIN profiles rp ON rp.user_id = cs.reviewer_id
|
|
LEFT JOIN profiles ap ON ap.user_id = cs.assigned_to;
|
|
|
|
COMMENT ON VIEW moderation_queue_with_entities IS
|
|
'Optimized view for moderation queue with pre-joined profiles and entity data. Content metadata moved to submission_metadata table.';
|
|
|
|
-- ============================================================================
|
|
-- 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 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 $$; |