-- Add typed foreign key columns to submission_items for proper relational integrity -- This replaces the generic item_data_id with specific FK columns -- Step 0: Drop dependent view DROP VIEW IF EXISTS moderation_queue_with_entities CASCADE; -- Step 1: Add typed foreign key columns ALTER TABLE public.submission_items ADD COLUMN park_submission_id UUID REFERENCES public.park_submissions(id) ON DELETE CASCADE, ADD COLUMN ride_submission_id UUID REFERENCES public.ride_submissions(id) ON DELETE CASCADE, ADD COLUMN photo_submission_id UUID REFERENCES public.photo_submissions(id) ON DELETE CASCADE, ADD COLUMN company_submission_id UUID REFERENCES public.company_submissions(id) ON DELETE CASCADE, ADD COLUMN ride_model_submission_id UUID REFERENCES public.ride_model_submissions(id) ON DELETE CASCADE, ADD COLUMN timeline_event_submission_id UUID REFERENCES public.timeline_event_submissions(id) ON DELETE CASCADE; -- Step 2: Migrate existing data from item_data_id to typed columns based on item_type UPDATE public.submission_items SET park_submission_id = item_data_id WHERE item_type = 'park' AND item_data_id IS NOT NULL; UPDATE public.submission_items SET ride_submission_id = item_data_id WHERE item_type = 'ride' AND item_data_id IS NOT NULL; UPDATE public.submission_items SET photo_submission_id = item_data_id WHERE item_type = 'photo' AND item_data_id IS NOT NULL; UPDATE public.submission_items SET company_submission_id = item_data_id WHERE item_type IN ('manufacturer', 'operator', 'designer', 'property_owner') AND item_data_id IS NOT NULL; UPDATE public.submission_items SET ride_model_submission_id = item_data_id WHERE item_type = 'ride_model' AND item_data_id IS NOT NULL; UPDATE public.submission_items SET timeline_event_submission_id = item_data_id WHERE item_type IN ('milestone', 'timeline_event') AND item_data_id IS NOT NULL; -- Step 3: Add check constraint to ensure only one FK is populated per row ALTER TABLE public.submission_items ADD CONSTRAINT submission_items_single_fk_check CHECK ( (CASE WHEN park_submission_id IS NOT NULL THEN 1 ELSE 0 END + CASE WHEN ride_submission_id IS NOT NULL THEN 1 ELSE 0 END + CASE WHEN photo_submission_id IS NOT NULL THEN 1 ELSE 0 END + CASE WHEN company_submission_id IS NOT NULL THEN 1 ELSE 0 END + CASE WHEN ride_model_submission_id IS NOT NULL THEN 1 ELSE 0 END + CASE WHEN timeline_event_submission_id IS NOT NULL THEN 1 ELSE 0 END) <= 1 ); -- Step 4: Drop the old generic item_data_id column ALTER TABLE public.submission_items DROP COLUMN item_data_id; -- Step 5: Recreate moderation_queue_with_entities view 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, cs.submitted_at, cs.reviewed_at, cs.resolved_at, cs.assigned_at, cs.escalated_at, cs.last_modified_at, cs.first_reviewed_at, -- User IDs cs.user_id AS submitted_by, cs.reviewer_id AS reviewed_by, cs.assigned_to, cs.escalated_by, cs.last_modified_by, -- State flags cs.escalated, cs.escalation_reason, cs.reviewer_notes AS review_notes, cs.approval_mode, cs.review_count, cs.locked_until, cs.is_test_data, -- Submitter profile (aliased for backward compatibility) sp.id AS submitter_profile_id, sp.username AS submitter_username, sp.display_name AS submitter_display_name, sp.avatar_url AS submitter_avatar_url, sp.reputation_score AS submitter_reputation, -- Reviewer profile rp.id AS reviewer_profile_id, rp.username AS reviewer_username, rp.display_name AS reviewer_display_name, rp.avatar_url AS reviewer_avatar_url, -- Assignee profile ap.id AS assignee_profile_id, ap.username AS assignee_username, ap.display_name AS assignee_display_name, ap.avatar_url AS assignee_avatar_url, -- Submission items (aggregated with new typed FK columns) ( SELECT json_agg(si.*) 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. Uses typed FK columns for submission_items.'; -- Add helpful comments COMMENT ON COLUMN public.submission_items.park_submission_id IS 'Foreign key to park_submissions for park-type items'; COMMENT ON COLUMN public.submission_items.ride_submission_id IS 'Foreign key to ride_submissions for ride-type items'; COMMENT ON COLUMN public.submission_items.photo_submission_id IS 'Foreign key to photo_submissions for photo-type items'; COMMENT ON COLUMN public.submission_items.company_submission_id IS 'Foreign key to company_submissions for company-type items (manufacturer, operator, designer, property_owner)'; COMMENT ON COLUMN public.submission_items.ride_model_submission_id IS 'Foreign key to ride_model_submissions for ride_model-type items'; COMMENT ON COLUMN public.submission_items.timeline_event_submission_id IS 'Foreign key to timeline_event_submissions for timeline/milestone items'; COMMENT ON CONSTRAINT submission_items_single_fk_check ON public.submission_items IS 'Ensures only one typed foreign key is populated per row';