feat: Implement normalized submission items table

This commit is contained in:
gpt-engineer-app[bot]
2025-09-30 13:34:24 +00:00
parent 9f9c35a7b6
commit 04c5ef58ff
2 changed files with 262 additions and 1 deletions

View File

@@ -127,9 +127,13 @@ export type Database = {
} }
content_submissions: { content_submissions: {
Row: { Row: {
approval_mode: string | null
content: Json content: Json
created_at: string created_at: string
escalated_by: string | null
escalation_reason: string | null
id: string id: string
original_submission_id: string | null
reviewed_at: string | null reviewed_at: string | null
reviewer_id: string | null reviewer_id: string | null
reviewer_notes: string | null reviewer_notes: string | null
@@ -139,9 +143,13 @@ export type Database = {
user_id: string user_id: string
} }
Insert: { Insert: {
approval_mode?: string | null
content: Json content: Json
created_at?: string created_at?: string
escalated_by?: string | null
escalation_reason?: string | null
id?: string id?: string
original_submission_id?: string | null
reviewed_at?: string | null reviewed_at?: string | null
reviewer_id?: string | null reviewer_id?: string | null
reviewer_notes?: string | null reviewer_notes?: string | null
@@ -151,9 +159,13 @@ export type Database = {
user_id: string user_id: string
} }
Update: { Update: {
approval_mode?: string | null
content?: Json content?: Json
created_at?: string created_at?: string
escalated_by?: string | null
escalation_reason?: string | null
id?: string id?: string
original_submission_id?: string | null
reviewed_at?: string | null reviewed_at?: string | null
reviewer_id?: string | null reviewer_id?: string | null
reviewer_notes?: string | null reviewer_notes?: string | null
@@ -162,7 +174,15 @@ export type Database = {
updated_at?: string updated_at?: string
user_id?: string user_id?: string
} }
Relationships: [] Relationships: [
{
foreignKeyName: "content_submissions_original_submission_id_fkey"
columns: ["original_submission_id"]
isOneToOne: false
referencedRelation: "content_submissions"
referencedColumns: ["id"]
},
]
} }
locations: { locations: {
Row: { Row: {
@@ -768,6 +788,66 @@ export type Database = {
}, },
] ]
} }
submission_items: {
Row: {
approved_entity_id: string | null
created_at: string
depends_on: string | null
id: string
item_data: Json
item_type: string
order_index: number | null
original_data: Json | null
rejection_reason: string | null
status: string
submission_id: string
updated_at: string
}
Insert: {
approved_entity_id?: string | null
created_at?: string
depends_on?: string | null
id?: string
item_data: Json
item_type: string
order_index?: number | null
original_data?: Json | null
rejection_reason?: string | null
status?: string
submission_id: string
updated_at?: string
}
Update: {
approved_entity_id?: string | null
created_at?: string
depends_on?: string | null
id?: string
item_data?: Json
item_type?: string
order_index?: number | null
original_data?: Json | null
rejection_reason?: string | null
status?: string
submission_id?: string
updated_at?: string
}
Relationships: [
{
foreignKeyName: "submission_items_depends_on_fkey"
columns: ["depends_on"]
isOneToOne: false
referencedRelation: "submission_items"
referencedColumns: ["id"]
},
{
foreignKeyName: "submission_items_submission_id_fkey"
columns: ["submission_id"]
isOneToOne: false
referencedRelation: "content_submissions"
referencedColumns: ["id"]
},
]
}
user_blocks: { user_blocks: {
Row: { Row: {
blocked_id: string blocked_id: string
@@ -970,6 +1050,10 @@ export type Database = {
[_ in never]: never [_ in never]: never
} }
Functions: { Functions: {
can_approve_submission_item: {
Args: { item_id: string }
Returns: boolean
}
can_manage_user: { can_manage_user: {
Args: { _manager_id: string; _target_user_id: string } Args: { _manager_id: string; _target_user_id: string }
Returns: boolean Returns: boolean
@@ -990,10 +1074,22 @@ export type Database = {
Args: { _profile_user_id: string; _viewer_id?: string } Args: { _profile_user_id: string; _viewer_id?: string }
Returns: Json Returns: Json
} }
get_submission_item_dependencies: {
Args: { item_id: string }
Returns: {
dependency_level: number
dependent_item_id: string
dependent_item_type: string
}[]
}
get_user_management_permissions: { get_user_management_permissions: {
Args: { _user_id: string } Args: { _user_id: string }
Returns: Json Returns: Json
} }
has_pending_dependents: {
Args: { item_id: string }
Returns: boolean
}
has_role: { has_role: {
Args: { Args: {
_role: Database["public"]["Enums"]["app_role"] _role: Database["public"]["Enums"]["app_role"]

View File

@@ -0,0 +1,165 @@
-- 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();