Files
thrilltrack-explorer/supabase/migrations/20251102214153_e9ebb0e0-c554-46cc-b3fe-27f17a19cf4c.sql
gpt-engineer-app[bot] a9644c0bee Approve tool use
2025-11-02 21:46:47 +00:00

265 lines
7.8 KiB
PL/PgSQL

-- ============================================
-- CRITICAL SECURITY: Moderation Action Validation & Audit
-- ============================================
-- This migration adds:
-- 1. validate_moderation_action() - Backend validation for all moderation actions
-- 2. moderation_audit_log - Comprehensive audit trail for all moderation decisions
-- 3. Enhanced RLS policies with lock enforcement
-- 4. Rate limiting to prevent abuse
-- ============================================
-- 1. Create Audit Log Table
-- ============================================
CREATE TABLE IF NOT EXISTS public.moderation_audit_log (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
submission_id UUID REFERENCES public.content_submissions(id) ON DELETE CASCADE,
moderator_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
action TEXT NOT NULL CHECK (action IN ('approve', 'reject', 'delete', 'reset', 'claim', 'release', 'extend_lock', 'retry_failed')),
previous_status TEXT,
new_status TEXT,
notes TEXT,
metadata JSONB DEFAULT '{}'::jsonb,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
is_test_data BOOLEAN DEFAULT FALSE
);
-- Create indexes for performance
CREATE INDEX IF NOT EXISTS idx_audit_moderator_time ON public.moderation_audit_log(moderator_id, created_at DESC);
CREATE INDEX IF NOT EXISTS idx_audit_submission ON public.moderation_audit_log(submission_id, created_at DESC);
CREATE INDEX IF NOT EXISTS idx_audit_action_time ON public.moderation_audit_log(action, created_at DESC);
-- Enable RLS
ALTER TABLE public.moderation_audit_log ENABLE ROW LEVEL SECURITY;
-- RLS Policies for audit log
CREATE POLICY "Moderators can view audit log"
ON public.moderation_audit_log FOR SELECT
TO authenticated
USING (
EXISTS (
SELECT 1 FROM public.user_roles
WHERE user_id = auth.uid()
AND role IN ('moderator', 'admin', 'superuser')
)
);
CREATE POLICY "System can insert audit log"
ON public.moderation_audit_log FOR INSERT
TO authenticated
WITH CHECK (moderator_id = auth.uid());
-- ============================================
-- 2. Validation Function with Lock & Rate Limiting
-- ============================================
CREATE OR REPLACE FUNCTION public.validate_moderation_action(
_submission_id UUID,
_user_id UUID,
_action TEXT
)
RETURNS BOOLEAN
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
_is_moderator BOOLEAN;
_locked_by UUID;
_locked_until TIMESTAMPTZ;
_action_count INTEGER;
BEGIN
-- Check if user has moderator/admin/superuser role
SELECT EXISTS (
SELECT 1 FROM public.user_roles
WHERE user_id = _user_id
AND role IN ('moderator', 'admin', 'superuser')
) INTO _is_moderator;
IF NOT _is_moderator THEN
RAISE EXCEPTION 'Unauthorized: User does not have moderation privileges';
END IF;
-- Check lock status (only for approve/reject/delete actions)
IF _action IN ('approve', 'reject', 'delete') THEN
SELECT assigned_to, locked_until
INTO _locked_by, _locked_until
FROM public.content_submissions
WHERE id = _submission_id;
-- If locked by another user and lock hasn't expired, reject
IF _locked_by IS NOT NULL
AND _locked_by != _user_id
AND _locked_until > NOW() THEN
RAISE EXCEPTION 'Forbidden: Submission is locked by another moderator until %', _locked_until;
END IF;
END IF;
-- Rate limiting: max 10 actions per minute per user
SELECT COUNT(*)
INTO _action_count
FROM public.moderation_audit_log
WHERE moderator_id = _user_id
AND created_at > NOW() - INTERVAL '1 minute';
IF _action_count >= 10 THEN
RAISE EXCEPTION 'Rate limit exceeded: Maximum 10 moderation actions per minute';
END IF;
RETURN TRUE;
END;
$$;
-- Grant execute permission
GRANT EXECUTE ON FUNCTION public.validate_moderation_action(UUID, UUID, TEXT) TO authenticated;
-- ============================================
-- 3. Helper Function to Log Actions
-- ============================================
CREATE OR REPLACE FUNCTION public.log_moderation_action(
_submission_id UUID,
_action TEXT,
_previous_status TEXT DEFAULT NULL,
_new_status TEXT DEFAULT NULL,
_notes TEXT DEFAULT NULL,
_metadata JSONB DEFAULT '{}'::jsonb
)
RETURNS UUID
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
_log_id UUID;
BEGIN
INSERT INTO public.moderation_audit_log (
submission_id,
moderator_id,
action,
previous_status,
new_status,
notes,
metadata
) VALUES (
_submission_id,
auth.uid(),
_action,
_previous_status,
_new_status,
_notes,
_metadata
)
RETURNING id INTO _log_id;
RETURN _log_id;
END;
$$;
GRANT EXECUTE ON FUNCTION public.log_moderation_action(UUID, TEXT, TEXT, TEXT, TEXT, JSONB) TO authenticated;
-- ============================================
-- 4. Enhanced RLS Policies with Lock Enforcement
-- ============================================
-- Drop existing update policy if it exists (to recreate with validation)
DROP POLICY IF EXISTS "Moderators can update submissions" ON public.content_submissions;
-- Recreate update policy with validation
CREATE POLICY "Moderators can update with validation"
ON public.content_submissions FOR UPDATE
TO authenticated
USING (
-- User must be moderator/admin/superuser
EXISTS (
SELECT 1 FROM public.user_roles
WHERE user_id = auth.uid()
AND role IN ('moderator', 'admin', 'superuser')
)
)
WITH CHECK (
-- Validate the action before allowing update
-- This is checked on the NEW row after the update
EXISTS (
SELECT 1 FROM public.user_roles
WHERE user_id = auth.uid()
AND role IN ('moderator', 'admin', 'superuser')
)
AND (
-- If being locked/unlocked, allow
(assigned_to IS NOT NULL AND locked_until IS NOT NULL)
OR (assigned_to IS NULL AND locked_until IS NULL)
OR
-- If status is changing, ensure not locked by another user
(assigned_to IS NULL OR assigned_to = auth.uid() OR locked_until < NOW())
)
);
-- ============================================
-- 5. Trigger to Auto-Log Moderation Actions
-- ============================================
CREATE OR REPLACE FUNCTION public.auto_log_submission_changes()
RETURNS TRIGGER
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
_action TEXT;
BEGIN
-- Determine action type
IF OLD.status != NEW.status THEN
_action := CASE
WHEN NEW.status = 'approved' THEN 'approve'
WHEN NEW.status = 'rejected' THEN 'reject'
WHEN NEW.status = 'pending' THEN 'reset'
ELSE 'update'
END;
-- Log the status change
PERFORM log_moderation_action(
NEW.id,
_action,
OLD.status,
NEW.status,
NEW.reviewer_notes
);
ELSIF OLD.assigned_to IS NULL AND NEW.assigned_to IS NOT NULL THEN
-- Submission was claimed
PERFORM log_moderation_action(
NEW.id,
'claim',
NULL,
NULL,
NULL,
jsonb_build_object('locked_until', NEW.locked_until)
);
ELSIF OLD.assigned_to IS NOT NULL AND NEW.assigned_to IS NULL THEN
-- Submission was released
PERFORM log_moderation_action(
NEW.id,
'release',
NULL,
NULL,
NULL,
jsonb_build_object('previous_lock', OLD.locked_until)
);
ELSIF OLD.locked_until IS NOT NULL AND NEW.locked_until IS NOT NULL AND NEW.locked_until > OLD.locked_until THEN
-- Lock was extended
PERFORM log_moderation_action(
NEW.id,
'extend_lock',
NULL,
NULL,
NULL,
jsonb_build_object('old_expiry', OLD.locked_until, 'new_expiry', NEW.locked_until)
);
END IF;
RETURN NEW;
END;
$$;
-- Create trigger
DROP TRIGGER IF EXISTS trigger_auto_log_submission_changes ON public.content_submissions;
CREATE TRIGGER trigger_auto_log_submission_changes
AFTER UPDATE ON public.content_submissions
FOR EACH ROW
EXECUTE FUNCTION public.auto_log_submission_changes();