diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index 3a5b2460..412f5d01 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -97,7 +97,6 @@ export type Database = { admin_user_id: string auth0_event_type: string | null created_at: string - details: Json | null id: string target_user_id: string } @@ -106,7 +105,6 @@ export type Database = { admin_user_id: string auth0_event_type?: string | null created_at?: string - details?: Json | null id?: string target_user_id: string } @@ -115,7 +113,6 @@ export type Database = { admin_user_id?: string auth0_event_type?: string | null created_at?: string - details?: Json | null id?: string target_user_id?: string } @@ -536,7 +533,6 @@ export type Database = { } conflict_resolutions: { Row: { - conflict_details: Json | null created_at: string detected_at: string id: string @@ -545,7 +541,6 @@ export type Database = { submission_id: string } Insert: { - conflict_details?: Json | null created_at?: string detected_at?: string id?: string @@ -554,7 +549,6 @@ export type Database = { submission_id: string } Update: { - conflict_details?: Json | null created_at?: string detected_at?: string id?: string @@ -592,7 +586,6 @@ export type Database = { in_reply_to: string | null is_auto_reply: boolean | null message_id: string - metadata: Json | null reference_chain: string[] | null sent_by: string | null smtp_message_id: string | null @@ -613,7 +606,6 @@ export type Database = { in_reply_to?: string | null is_auto_reply?: boolean | null message_id: string - metadata?: Json | null reference_chain?: string[] | null sent_by?: string | null smtp_message_id?: string | null @@ -634,7 +626,6 @@ export type Database = { in_reply_to?: string | null is_auto_reply?: boolean | null message_id?: string - metadata?: Json | null reference_chain?: string[] | null sent_by?: string | null smtp_message_id?: string | null @@ -701,7 +692,6 @@ export type Database = { response_count: number | null status: string subject: string - submitter_profile_data: Json | null submitter_profile_id: string | null submitter_reputation: number | null submitter_username: string | null @@ -730,7 +720,6 @@ export type Database = { response_count?: number | null status?: string subject: string - submitter_profile_data?: Json | null submitter_profile_id?: string | null submitter_reputation?: number | null submitter_username?: string | null @@ -759,7 +748,6 @@ export type Database = { response_count?: number | null status?: string subject?: string - submitter_profile_data?: Json | null submitter_profile_id?: string | null submitter_reputation?: number | null submitter_username?: string | null @@ -791,7 +779,6 @@ export type Database = { approval_mode: string | null assigned_at: string | null assigned_to: string | null - content: Json created_at: string escalated: boolean | null escalated_at: string | null @@ -819,7 +806,6 @@ export type Database = { approval_mode?: string | null assigned_at?: string | null assigned_to?: string | null - content: Json created_at?: string escalated?: boolean | null escalated_at?: string | null @@ -847,7 +833,6 @@ export type Database = { approval_mode?: string | null assigned_at?: string | null assigned_to?: string | null - content?: Json created_at?: string escalated?: boolean | null escalated_at?: string | null @@ -1489,21 +1474,18 @@ export type Database = { } item_edit_history: { Row: { - changes: Json edited_at: string editor_id: string id: string item_id: string } Insert: { - changes: Json edited_at?: string editor_id: string id?: string item_id: string } Update: { - changes?: Json edited_at?: string editor_id?: string id?: string @@ -1605,7 +1587,6 @@ export type Database = { created_at: string id: string is_test_data: boolean | null - metadata: Json | null moderator_id: string new_status: string | null notes: string | null @@ -1617,7 +1598,6 @@ export type Database = { created_at?: string id?: string is_test_data?: boolean | null - metadata?: Json | null moderator_id: string new_status?: string | null notes?: string | null @@ -1629,7 +1609,6 @@ export type Database = { created_at?: string id?: string is_test_data?: boolean | null - metadata?: Json | null moderator_id?: string new_status?: string | null notes?: string | null @@ -1787,7 +1766,6 @@ export type Database = { idempotency_key: string | null is_duplicate: boolean novu_transaction_id: string | null - payload: Json | null read_at: string | null status: string template_id: string | null @@ -1802,7 +1780,6 @@ export type Database = { idempotency_key?: string | null is_duplicate?: boolean novu_transaction_id?: string | null - payload?: Json | null read_at?: string | null status?: string template_id?: string | null @@ -1817,7 +1794,6 @@ export type Database = { idempotency_key?: string | null is_duplicate?: boolean novu_transaction_id?: string | null - payload?: Json | null read_at?: string | null status?: string template_id?: string | null @@ -2513,7 +2489,6 @@ export type Database = { Row: { action: string changed_by: string - changes: Json created_at: string id: string ip_address_hash: string | null @@ -2523,7 +2498,6 @@ export type Database = { Insert: { action: string changed_by: string - changes: Json created_at?: string id?: string ip_address_hash?: string | null @@ -2533,7 +2507,6 @@ export type Database = { Update: { action?: string changed_by?: string - changes?: Json created_at?: string id?: string ip_address_hash?: string | null @@ -2809,13 +2782,11 @@ export type Database = { } request_metadata: { Row: { - breadcrumbs: Json | null client_version: string | null completed_at: string | null created_at: string duration_ms: number | null endpoint: string - environment_context: Json | null error_message: string | null error_stack: string | null error_type: string | null @@ -2837,13 +2808,11 @@ export type Database = { user_id: string | null } Insert: { - breadcrumbs?: Json | null client_version?: string | null completed_at?: string | null created_at?: string duration_ms?: number | null endpoint: string - environment_context?: Json | null error_message?: string | null error_stack?: string | null error_type?: string | null @@ -2865,13 +2834,11 @@ export type Database = { user_id?: string | null } Update: { - breadcrumbs?: Json | null client_version?: string | null completed_at?: string | null created_at?: string duration_ms?: number | null endpoint?: string - environment_context?: Json | null error_message?: string | null error_stack?: string | null error_type?: string | null @@ -3003,7 +2970,6 @@ export type Database = { moderated_by: string | null moderation_status: string park_id: string | null - photos: Json | null rating: number report_count: number ride_id: string | null @@ -3024,7 +2990,6 @@ export type Database = { moderated_by?: string | null moderation_status?: string park_id?: string | null - photos?: Json | null rating: number report_count?: number ride_id?: string | null @@ -3045,7 +3010,6 @@ export type Database = { moderated_by?: string | null moderation_status?: string park_id?: string | null - photos?: Json | null rating?: number report_count?: number ride_id?: string | null @@ -5294,7 +5258,6 @@ export type Database = { assigned_at: string | null assigned_profile: Json | null assigned_to: string | null - content: Json | null created_at: string | null escalated: boolean | null escalated_at: string | null diff --git a/supabase/migrations/20251103211311_cd3ad325-b56e-4f9a-93fb-7fe02b444b77.sql b/supabase/migrations/20251103211311_cd3ad325-b56e-4f9a-93fb-7fe02b444b77.sql new file mode 100644 index 00000000..5df10fa9 --- /dev/null +++ b/supabase/migrations/20251103211311_cd3ad325-b56e-4f9a-93fb-7fe02b444b77.sql @@ -0,0 +1,263 @@ +-- ============================================================================ +-- 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 $$; \ No newline at end of file