Files
thrilltrack-explorer/supabase/migrations/20251015120658_73b14cb1-9fe0-473d-aaa4-4e440590bccc.sql
2025-10-15 12:09:23 +00:00

126 lines
4.7 KiB
SQL

-- Phase 2: Critical Database Indexes for Moderation Performance
-- These indexes optimize the most frequently queried patterns in the moderation system
-- ================================================================
-- 1. CONTENT_SUBMISSIONS INDEXES
-- ================================================================
-- Primary moderation queue query: status + escalated + created_at
-- Supports: WHERE status IN (...) ORDER BY escalated DESC, created_at ASC
CREATE INDEX IF NOT EXISTS idx_content_submissions_queue
ON content_submissions(status, escalated DESC, created_at ASC)
WHERE status IN ('pending', 'partially_approved');
-- Lock management queries: assigned_to + locked_until
-- Supports: WHERE assigned_to = ? AND locked_until > now()
CREATE INDEX IF NOT EXISTS idx_content_submissions_locks
ON content_submissions(assigned_to, locked_until)
WHERE assigned_to IS NOT NULL;
-- User's own submissions lookup
-- Supports: WHERE user_id = ? ORDER BY created_at DESC
CREATE INDEX IF NOT EXISTS idx_content_submissions_user
ON content_submissions(user_id, created_at DESC);
-- Submission type filtering
-- Supports: WHERE submission_type = ? AND status = ?
CREATE INDEX IF NOT EXISTS idx_content_submissions_type
ON content_submissions(submission_type, status);
-- ================================================================
-- 2. REPORTS INDEXES
-- ================================================================
-- Reports queue query: status + created_at
-- Supports: WHERE status = ? ORDER BY created_at DESC
CREATE INDEX IF NOT EXISTS idx_reports_status_created
ON reports(status, created_at DESC);
-- Reported entity lookups
-- Supports: WHERE reported_entity_type = ? AND reported_entity_id = ?
CREATE INDEX IF NOT EXISTS idx_reports_entity
ON reports(reported_entity_type, reported_entity_id);
-- Reporter history lookups
-- Supports: WHERE reporter_id = ? ORDER BY created_at DESC
CREATE INDEX IF NOT EXISTS idx_reports_reporter
ON reports(reporter_id, created_at DESC);
-- ================================================================
-- 3. USER_ROLES INDEXES
-- ================================================================
-- Role checks (most critical for RLS)
-- Supports: WHERE user_id = ? AND role = ?
CREATE INDEX IF NOT EXISTS idx_user_roles_user_role
ON user_roles(user_id, role);
-- All roles for a user (for permission checks)
-- Supports: WHERE user_id = ?
CREATE INDEX IF NOT EXISTS idx_user_roles_user
ON user_roles(user_id);
-- ================================================================
-- 4. SUBMISSION_ITEMS INDEXES
-- ================================================================
-- Items by submission
-- Supports: WHERE submission_id = ? ORDER BY created_at
CREATE INDEX IF NOT EXISTS idx_submission_items_submission
ON submission_items(submission_id, created_at);
-- Dependency lookups
-- Supports: WHERE depends_on = ?
CREATE INDEX IF NOT EXISTS idx_submission_items_depends_on
ON submission_items(depends_on)
WHERE depends_on IS NOT NULL;
-- Status-based filtering
-- Supports: WHERE status = ? AND submission_id = ?
CREATE INDEX IF NOT EXISTS idx_submission_items_status
ON submission_items(status, submission_id);
-- ================================================================
-- 5. PHOTO_SUBMISSIONS INDEXES
-- ================================================================
-- Photos by submission
-- Supports: WHERE submission_id = ?
CREATE INDEX IF NOT EXISTS idx_photo_submissions_submission
ON photo_submissions(submission_id);
-- Photos by entity
-- Supports: WHERE entity_type = ? AND entity_id = ?
CREATE INDEX IF NOT EXISTS idx_photo_submissions_entity
ON photo_submissions(entity_type, entity_id);
-- ================================================================
-- 6. ADMIN_AUDIT_LOG INDEXES
-- ================================================================
-- Admin actions on user
-- Supports: WHERE target_user_id = ? ORDER BY created_at DESC
CREATE INDEX IF NOT EXISTS idx_admin_audit_target
ON admin_audit_log(target_user_id, created_at DESC);
-- Admin's actions
-- Supports: WHERE admin_user_id = ? ORDER BY created_at DESC
CREATE INDEX IF NOT EXISTS idx_admin_audit_admin
ON admin_audit_log(admin_user_id, created_at DESC);
-- Action type filtering
-- Supports: WHERE action = ? ORDER BY created_at DESC
CREATE INDEX IF NOT EXISTS idx_admin_audit_action
ON admin_audit_log(action, created_at DESC);
-- ================================================================
-- ANALYSIS
-- ================================================================
-- Run ANALYZE to update query planner statistics
ANALYZE content_submissions;
ANALYZE reports;
ANALYZE user_roles;
ANALYZE submission_items;
ANALYZE photo_submissions;
ANALYZE admin_audit_log;