-- Phase 1: Fix moderation_queue_with_entities view with proper column aliases and structure -- Drop existing view DROP VIEW IF EXISTS moderation_queue_with_entities CASCADE; -- Create corrected view with proper aliases and structure 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, cs.content, -- 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; -- Add comment for documentation COMMENT ON VIEW moderation_queue_with_entities IS 'Optimized view for moderation queue with pre-joined profiles and entity data. Exposes both created_at (alias) and submitted_at for backward compatibility.'; -- Performance indexes (if not already created) CREATE INDEX IF NOT EXISTS idx_content_submissions_queue ON content_submissions(status, escalated DESC, submitted_at ASC) WHERE status IN ('pending', 'flagged', 'partially_approved', 'approved', 'rejected'); CREATE INDEX IF NOT EXISTS idx_content_submissions_locks ON content_submissions(assigned_to, locked_until) WHERE assigned_to IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_submission_items_item_data_id ON submission_items(item_type, item_data_id) WHERE item_data_id IS NOT NULL;