Files
thrilltrack-explorer/supabase/migrations/20250930133412_2f5109fc-60c8-4f1c-89bd-3d5c995cf1e0.sql
2025-09-30 13:34:24 +00:00

165 lines
5.2 KiB
PL/PgSQL

-- Create submission_items table for normalized approval workflow
CREATE TABLE IF NOT EXISTS public.submission_items (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
submission_id UUID NOT NULL REFERENCES public.content_submissions(id) ON DELETE CASCADE,
item_type TEXT NOT NULL CHECK (item_type IN ('photo', 'park', 'ride', 'manufacturer', 'ride_model', 'operator', 'property_owner', 'designer')),
item_data JSONB NOT NULL,
depends_on UUID REFERENCES public.submission_items(id) ON DELETE SET NULL,
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'rejected', 'modified')),
rejection_reason TEXT,
original_data JSONB,
order_index INTEGER DEFAULT 0,
approved_entity_id UUID,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Add indexes for performance
CREATE INDEX idx_submission_items_submission_id ON public.submission_items(submission_id);
CREATE INDEX idx_submission_items_status ON public.submission_items(status);
CREATE INDEX idx_submission_items_depends_on ON public.submission_items(depends_on);
CREATE INDEX idx_submission_items_item_type ON public.submission_items(item_type);
-- Add columns to content_submissions for enhanced workflow
ALTER TABLE public.content_submissions
ADD COLUMN IF NOT EXISTS original_submission_id UUID REFERENCES public.content_submissions(id) ON DELETE SET NULL,
ADD COLUMN IF NOT EXISTS escalated_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
ADD COLUMN IF NOT EXISTS escalation_reason TEXT,
ADD COLUMN IF NOT EXISTS approval_mode TEXT DEFAULT 'full' CHECK (approval_mode IN ('full', 'selective', 'edited'));
-- Add new status values for escalation workflow
ALTER TABLE public.content_submissions DROP CONSTRAINT IF EXISTS content_submissions_status_check;
ALTER TABLE public.content_submissions ADD CONSTRAINT content_submissions_status_check
CHECK (status IN ('pending', 'approved', 'rejected', 'pending_admin_review', 'partially_approved', 'pending_changes'));
-- Enable RLS on submission_items
ALTER TABLE public.submission_items ENABLE ROW LEVEL SECURITY;
-- RLS Policies for submission_items
CREATE POLICY "Users can view their own submission items"
ON public.submission_items
FOR SELECT
USING (
EXISTS (
SELECT 1 FROM public.content_submissions
WHERE content_submissions.id = submission_items.submission_id
AND content_submissions.user_id = auth.uid()
)
);
CREATE POLICY "Moderators can view all submission items"
ON public.submission_items
FOR SELECT
USING (is_moderator(auth.uid()));
CREATE POLICY "Moderators can update submission items"
ON public.submission_items
FOR UPDATE
USING (is_moderator(auth.uid()));
CREATE POLICY "Moderators can insert submission items"
ON public.submission_items
FOR INSERT
WITH CHECK (is_moderator(auth.uid()));
CREATE POLICY "Moderators can delete submission items"
ON public.submission_items
FOR DELETE
USING (is_moderator(auth.uid()));
-- Function to get submission item dependencies
CREATE OR REPLACE FUNCTION public.get_submission_item_dependencies(item_id UUID)
RETURNS TABLE (
dependent_item_id UUID,
dependent_item_type TEXT,
dependency_level INTEGER
)
LANGUAGE SQL
STABLE
SECURITY DEFINER
SET search_path = public
AS $$
WITH RECURSIVE dependency_chain AS (
-- Base case: direct dependencies
SELECT
id as dependent_item_id,
item_type as dependent_item_type,
1 as dependency_level
FROM submission_items
WHERE depends_on = item_id
UNION ALL
-- Recursive case: transitive dependencies
SELECT
si.id,
si.item_type,
dc.dependency_level + 1
FROM submission_items si
INNER JOIN dependency_chain dc ON si.depends_on = dc.dependent_item_id
)
SELECT * FROM dependency_chain;
$$;
-- Function to validate item approval
CREATE OR REPLACE FUNCTION public.can_approve_submission_item(item_id UUID)
RETURNS BOOLEAN
LANGUAGE PLPGSQL
STABLE
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
parent_item_id UUID;
parent_status TEXT;
BEGIN
-- Get the parent item this item depends on
SELECT depends_on INTO parent_item_id
FROM public.submission_items
WHERE id = item_id;
-- If no parent dependency, can approve
IF parent_item_id IS NULL THEN
RETURN TRUE;
END IF;
-- Check if parent is approved
SELECT status INTO parent_status
FROM public.submission_items
WHERE id = parent_item_id;
RETURN parent_status = 'approved';
END;
$$;
-- Function to check if rejecting an item would break dependencies
CREATE OR REPLACE FUNCTION public.has_pending_dependents(item_id UUID)
RETURNS BOOLEAN
LANGUAGE SQL
STABLE
SECURITY DEFINER
SET search_path = public
AS $$
SELECT EXISTS (
SELECT 1
FROM public.submission_items
WHERE depends_on = item_id
AND status = 'pending'
);
$$;
-- Trigger to update updated_at timestamp
CREATE OR REPLACE FUNCTION public.update_submission_items_updated_at()
RETURNS TRIGGER
LANGUAGE PLPGSQL
AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$;
CREATE TRIGGER trigger_update_submission_items_updated_at
BEFORE UPDATE ON public.submission_items
FOR EACH ROW
EXECUTE FUNCTION public.update_submission_items_updated_at();