mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 08:11:13 -05:00
Approve tool use
Approve tool use based on context.
This commit is contained in:
@@ -151,6 +151,63 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
Relationships: []
|
Relationships: []
|
||||||
}
|
}
|
||||||
|
approval_transaction_metrics: {
|
||||||
|
Row: {
|
||||||
|
created_at: string | null
|
||||||
|
duration_ms: number | null
|
||||||
|
error_message: string | null
|
||||||
|
id: string
|
||||||
|
items_count: number
|
||||||
|
moderator_id: string
|
||||||
|
request_id: string | null
|
||||||
|
rollback_triggered: boolean | null
|
||||||
|
submission_id: string
|
||||||
|
submitter_id: string
|
||||||
|
success: boolean
|
||||||
|
}
|
||||||
|
Insert: {
|
||||||
|
created_at?: string | null
|
||||||
|
duration_ms?: number | null
|
||||||
|
error_message?: string | null
|
||||||
|
id?: string
|
||||||
|
items_count: number
|
||||||
|
moderator_id: string
|
||||||
|
request_id?: string | null
|
||||||
|
rollback_triggered?: boolean | null
|
||||||
|
submission_id: string
|
||||||
|
submitter_id: string
|
||||||
|
success: boolean
|
||||||
|
}
|
||||||
|
Update: {
|
||||||
|
created_at?: string | null
|
||||||
|
duration_ms?: number | null
|
||||||
|
error_message?: string | null
|
||||||
|
id?: string
|
||||||
|
items_count?: number
|
||||||
|
moderator_id?: string
|
||||||
|
request_id?: string | null
|
||||||
|
rollback_triggered?: boolean | null
|
||||||
|
submission_id?: string
|
||||||
|
submitter_id?: string
|
||||||
|
success?: boolean
|
||||||
|
}
|
||||||
|
Relationships: [
|
||||||
|
{
|
||||||
|
foreignKeyName: "approval_transaction_metrics_submission_id_fkey"
|
||||||
|
columns: ["submission_id"]
|
||||||
|
isOneToOne: false
|
||||||
|
referencedRelation: "content_submissions"
|
||||||
|
referencedColumns: ["id"]
|
||||||
|
},
|
||||||
|
{
|
||||||
|
foreignKeyName: "approval_transaction_metrics_submission_id_fkey"
|
||||||
|
columns: ["submission_id"]
|
||||||
|
isOneToOne: false
|
||||||
|
referencedRelation: "moderation_queue_with_entities"
|
||||||
|
referencedColumns: ["id"]
|
||||||
|
},
|
||||||
|
]
|
||||||
|
}
|
||||||
blog_posts: {
|
blog_posts: {
|
||||||
Row: {
|
Row: {
|
||||||
author_id: string
|
author_id: string
|
||||||
@@ -5960,6 +6017,10 @@ export type Database = {
|
|||||||
oldest_deleted_date: string
|
oldest_deleted_date: string
|
||||||
}[]
|
}[]
|
||||||
}
|
}
|
||||||
|
create_entity_from_submission: {
|
||||||
|
Args: { p_created_by: string; p_data: Json; p_entity_type: string }
|
||||||
|
Returns: string
|
||||||
|
}
|
||||||
create_submission_with_items:
|
create_submission_with_items:
|
||||||
| {
|
| {
|
||||||
Args: {
|
Args: {
|
||||||
@@ -5980,6 +6041,14 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
Returns: string
|
Returns: string
|
||||||
}
|
}
|
||||||
|
delete_entity_from_submission: {
|
||||||
|
Args: {
|
||||||
|
p_deleted_by: string
|
||||||
|
p_entity_id: string
|
||||||
|
p_entity_type: string
|
||||||
|
}
|
||||||
|
Returns: undefined
|
||||||
|
}
|
||||||
detect_orphaned_images: { Args: never; Returns: number }
|
detect_orphaned_images: { Args: never; Returns: number }
|
||||||
detect_orphaned_images_with_logging: { Args: never; Returns: undefined }
|
detect_orphaned_images_with_logging: { Args: never; Returns: undefined }
|
||||||
extend_submission_lock: {
|
extend_submission_lock: {
|
||||||
@@ -6172,6 +6241,16 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
migrate_ride_technical_data: { Args: never; Returns: undefined }
|
migrate_ride_technical_data: { Args: never; Returns: undefined }
|
||||||
migrate_user_list_items: { Args: never; Returns: undefined }
|
migrate_user_list_items: { Args: never; Returns: undefined }
|
||||||
|
process_approval_transaction: {
|
||||||
|
Args: {
|
||||||
|
p_item_ids: string[]
|
||||||
|
p_moderator_id: string
|
||||||
|
p_request_id?: string
|
||||||
|
p_submission_id: string
|
||||||
|
p_submitter_id: string
|
||||||
|
}
|
||||||
|
Returns: Json
|
||||||
|
}
|
||||||
release_expired_locks: { Args: never; Returns: number }
|
release_expired_locks: { Args: never; Returns: number }
|
||||||
release_submission_lock: {
|
release_submission_lock: {
|
||||||
Args: { moderator_id: string; submission_id: string }
|
Args: { moderator_id: string; submission_id: string }
|
||||||
@@ -6216,6 +6295,15 @@ export type Database = {
|
|||||||
Args: { target_company_id: string }
|
Args: { target_company_id: string }
|
||||||
Returns: undefined
|
Returns: undefined
|
||||||
}
|
}
|
||||||
|
update_entity_from_submission: {
|
||||||
|
Args: {
|
||||||
|
p_data: Json
|
||||||
|
p_entity_id: string
|
||||||
|
p_entity_type: string
|
||||||
|
p_updated_by: string
|
||||||
|
}
|
||||||
|
Returns: string
|
||||||
|
}
|
||||||
update_entity_view_counts: { Args: never; Returns: undefined }
|
update_entity_view_counts: { Args: never; Returns: undefined }
|
||||||
update_park_ratings: {
|
update_park_ratings: {
|
||||||
Args: { target_park_id: string }
|
Args: { target_park_id: string }
|
||||||
|
|||||||
@@ -0,0 +1,676 @@
|
|||||||
|
-- ============================================================================
|
||||||
|
-- ATOMIC APPROVAL TRANSACTION - Phase 1 Implementation
|
||||||
|
-- ============================================================================
|
||||||
|
-- This migration creates RPC functions that wrap the entire approval flow
|
||||||
|
-- in a single PostgreSQL transaction for true atomic rollback.
|
||||||
|
--
|
||||||
|
-- Key Benefits:
|
||||||
|
-- 1. True ACID transactions - all-or-nothing guarantee
|
||||||
|
-- 2. Automatic rollback on ANY error (no manual cleanup needed)
|
||||||
|
-- 3. Network-resilient (edge function crash = auto rollback)
|
||||||
|
-- 4. Eliminates orphaned entities
|
||||||
|
-- 5. Simplifies edge function from 2,759 lines to ~200 lines
|
||||||
|
-- ============================================================================
|
||||||
|
|
||||||
|
-- Create metrics table for monitoring transaction performance
|
||||||
|
CREATE TABLE IF NOT EXISTS approval_transaction_metrics (
|
||||||
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||||
|
submission_id UUID NOT NULL REFERENCES content_submissions(id) ON DELETE CASCADE,
|
||||||
|
moderator_id UUID NOT NULL,
|
||||||
|
submitter_id UUID NOT NULL,
|
||||||
|
items_count INTEGER NOT NULL,
|
||||||
|
duration_ms INTEGER,
|
||||||
|
success BOOLEAN NOT NULL,
|
||||||
|
error_message TEXT,
|
||||||
|
rollback_triggered BOOLEAN DEFAULT FALSE,
|
||||||
|
request_id TEXT,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_approval_metrics_submission ON approval_transaction_metrics(submission_id);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_approval_metrics_created ON approval_transaction_metrics(created_at DESC);
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_approval_metrics_success ON approval_transaction_metrics(success);
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
-- HELPER FUNCTION: Create entity from submission data
|
||||||
|
-- ============================================================================
|
||||||
|
CREATE OR REPLACE FUNCTION create_entity_from_submission(
|
||||||
|
p_entity_type TEXT,
|
||||||
|
p_data JSONB,
|
||||||
|
p_created_by UUID
|
||||||
|
)
|
||||||
|
RETURNS UUID
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
v_entity_id UUID;
|
||||||
|
BEGIN
|
||||||
|
CASE p_entity_type
|
||||||
|
WHEN 'park' THEN
|
||||||
|
INSERT INTO parks (
|
||||||
|
name, slug, description, park_type, status,
|
||||||
|
location_id, operator_id, property_owner_id,
|
||||||
|
opening_date, closing_date,
|
||||||
|
opening_date_precision, closing_date_precision,
|
||||||
|
website_url, phone, email,
|
||||||
|
banner_image_url, banner_image_id,
|
||||||
|
card_image_url, card_image_id
|
||||||
|
) VALUES (
|
||||||
|
p_data->>'name',
|
||||||
|
p_data->>'slug',
|
||||||
|
p_data->>'description',
|
||||||
|
p_data->>'park_type',
|
||||||
|
p_data->>'status',
|
||||||
|
(p_data->>'location_id')::UUID,
|
||||||
|
(p_data->>'operator_id')::UUID,
|
||||||
|
(p_data->>'property_owner_id')::UUID,
|
||||||
|
(p_data->>'opening_date')::DATE,
|
||||||
|
(p_data->>'closing_date')::DATE,
|
||||||
|
p_data->>'opening_date_precision',
|
||||||
|
p_data->>'closing_date_precision',
|
||||||
|
p_data->>'website_url',
|
||||||
|
p_data->>'phone',
|
||||||
|
p_data->>'email',
|
||||||
|
p_data->>'banner_image_url',
|
||||||
|
p_data->>'banner_image_id',
|
||||||
|
p_data->>'card_image_url',
|
||||||
|
p_data->>'card_image_id'
|
||||||
|
)
|
||||||
|
RETURNING id INTO v_entity_id;
|
||||||
|
|
||||||
|
WHEN 'ride' THEN
|
||||||
|
INSERT INTO rides (
|
||||||
|
name, slug, park_id, ride_type, status,
|
||||||
|
manufacturer_id, ride_model_id,
|
||||||
|
opening_date, closing_date,
|
||||||
|
opening_date_precision, closing_date_precision,
|
||||||
|
description,
|
||||||
|
banner_image_url, banner_image_id,
|
||||||
|
card_image_url, card_image_id
|
||||||
|
) VALUES (
|
||||||
|
p_data->>'name',
|
||||||
|
p_data->>'slug',
|
||||||
|
(p_data->>'park_id')::UUID,
|
||||||
|
p_data->>'ride_type',
|
||||||
|
p_data->>'status',
|
||||||
|
(p_data->>'manufacturer_id')::UUID,
|
||||||
|
(p_data->>'ride_model_id')::UUID,
|
||||||
|
(p_data->>'opening_date')::DATE,
|
||||||
|
(p_data->>'closing_date')::DATE,
|
||||||
|
p_data->>'opening_date_precision',
|
||||||
|
p_data->>'closing_date_precision',
|
||||||
|
p_data->>'description',
|
||||||
|
p_data->>'banner_image_url',
|
||||||
|
p_data->>'banner_image_id',
|
||||||
|
p_data->>'card_image_url',
|
||||||
|
p_data->>'card_image_id'
|
||||||
|
)
|
||||||
|
RETURNING id INTO v_entity_id;
|
||||||
|
|
||||||
|
WHEN 'manufacturer', 'operator', 'property_owner', 'designer' THEN
|
||||||
|
INSERT INTO companies (
|
||||||
|
name, slug, company_type, description,
|
||||||
|
website_url, founded_year,
|
||||||
|
banner_image_url, banner_image_id,
|
||||||
|
card_image_url, card_image_id
|
||||||
|
) VALUES (
|
||||||
|
p_data->>'name',
|
||||||
|
p_data->>'slug',
|
||||||
|
p_entity_type,
|
||||||
|
p_data->>'description',
|
||||||
|
p_data->>'website_url',
|
||||||
|
(p_data->>'founded_year')::INTEGER,
|
||||||
|
p_data->>'banner_image_url',
|
||||||
|
p_data->>'banner_image_id',
|
||||||
|
p_data->>'card_image_url',
|
||||||
|
p_data->>'card_image_id'
|
||||||
|
)
|
||||||
|
RETURNING id INTO v_entity_id;
|
||||||
|
|
||||||
|
WHEN 'ride_model' THEN
|
||||||
|
INSERT INTO ride_models (
|
||||||
|
name, slug, manufacturer_id, ride_type,
|
||||||
|
description,
|
||||||
|
banner_image_url, banner_image_id,
|
||||||
|
card_image_url, card_image_id
|
||||||
|
) VALUES (
|
||||||
|
p_data->>'name',
|
||||||
|
p_data->>'slug',
|
||||||
|
(p_data->>'manufacturer_id')::UUID,
|
||||||
|
p_data->>'ride_type',
|
||||||
|
p_data->>'description',
|
||||||
|
p_data->>'banner_image_url',
|
||||||
|
p_data->>'banner_image_id',
|
||||||
|
p_data->>'card_image_url',
|
||||||
|
p_data->>'card_image_id'
|
||||||
|
)
|
||||||
|
RETURNING id INTO v_entity_id;
|
||||||
|
|
||||||
|
ELSE
|
||||||
|
RAISE EXCEPTION 'Unsupported entity type for creation: %', p_entity_type
|
||||||
|
USING ERRCODE = '22023';
|
||||||
|
END CASE;
|
||||||
|
|
||||||
|
RETURN v_entity_id;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
-- HELPER FUNCTION: Update entity from submission data
|
||||||
|
-- ============================================================================
|
||||||
|
CREATE OR REPLACE FUNCTION update_entity_from_submission(
|
||||||
|
p_entity_type TEXT,
|
||||||
|
p_data JSONB,
|
||||||
|
p_entity_id UUID,
|
||||||
|
p_updated_by UUID
|
||||||
|
)
|
||||||
|
RETURNS UUID
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
CASE p_entity_type
|
||||||
|
WHEN 'park' THEN
|
||||||
|
UPDATE parks SET
|
||||||
|
name = COALESCE(p_data->>'name', name),
|
||||||
|
slug = COALESCE(p_data->>'slug', slug),
|
||||||
|
description = COALESCE(p_data->>'description', description),
|
||||||
|
park_type = COALESCE(p_data->>'park_type', park_type),
|
||||||
|
status = COALESCE(p_data->>'status', status),
|
||||||
|
location_id = COALESCE((p_data->>'location_id')::UUID, location_id),
|
||||||
|
operator_id = COALESCE((p_data->>'operator_id')::UUID, operator_id),
|
||||||
|
property_owner_id = COALESCE((p_data->>'property_owner_id')::UUID, property_owner_id),
|
||||||
|
opening_date = COALESCE((p_data->>'opening_date')::DATE, opening_date),
|
||||||
|
closing_date = COALESCE((p_data->>'closing_date')::DATE, closing_date),
|
||||||
|
opening_date_precision = COALESCE(p_data->>'opening_date_precision', opening_date_precision),
|
||||||
|
closing_date_precision = COALESCE(p_data->>'closing_date_precision', closing_date_precision),
|
||||||
|
website_url = COALESCE(p_data->>'website_url', website_url),
|
||||||
|
phone = COALESCE(p_data->>'phone', phone),
|
||||||
|
email = COALESCE(p_data->>'email', email),
|
||||||
|
banner_image_url = COALESCE(p_data->>'banner_image_url', banner_image_url),
|
||||||
|
banner_image_id = COALESCE(p_data->>'banner_image_id', banner_image_id),
|
||||||
|
card_image_url = COALESCE(p_data->>'card_image_url', card_image_url),
|
||||||
|
card_image_id = COALESCE(p_data->>'card_image_id', card_image_id),
|
||||||
|
updated_at = NOW()
|
||||||
|
WHERE id = p_entity_id;
|
||||||
|
|
||||||
|
WHEN 'ride' THEN
|
||||||
|
UPDATE rides SET
|
||||||
|
name = COALESCE(p_data->>'name', name),
|
||||||
|
slug = COALESCE(p_data->>'slug', slug),
|
||||||
|
park_id = COALESCE((p_data->>'park_id')::UUID, park_id),
|
||||||
|
ride_type = COALESCE(p_data->>'ride_type', ride_type),
|
||||||
|
status = COALESCE(p_data->>'status', status),
|
||||||
|
manufacturer_id = COALESCE((p_data->>'manufacturer_id')::UUID, manufacturer_id),
|
||||||
|
ride_model_id = COALESCE((p_data->>'ride_model_id')::UUID, ride_model_id),
|
||||||
|
opening_date = COALESCE((p_data->>'opening_date')::DATE, opening_date),
|
||||||
|
closing_date = COALESCE((p_data->>'closing_date')::DATE, closing_date),
|
||||||
|
opening_date_precision = COALESCE(p_data->>'opening_date_precision', opening_date_precision),
|
||||||
|
closing_date_precision = COALESCE(p_data->>'closing_date_precision', closing_date_precision),
|
||||||
|
description = COALESCE(p_data->>'description', description),
|
||||||
|
banner_image_url = COALESCE(p_data->>'banner_image_url', banner_image_url),
|
||||||
|
banner_image_id = COALESCE(p_data->>'banner_image_id', banner_image_id),
|
||||||
|
card_image_url = COALESCE(p_data->>'card_image_url', card_image_url),
|
||||||
|
card_image_id = COALESCE(p_data->>'card_image_id', card_image_id),
|
||||||
|
updated_at = NOW()
|
||||||
|
WHERE id = p_entity_id;
|
||||||
|
|
||||||
|
WHEN 'manufacturer', 'operator', 'property_owner', 'designer' THEN
|
||||||
|
UPDATE companies SET
|
||||||
|
name = COALESCE(p_data->>'name', name),
|
||||||
|
slug = COALESCE(p_data->>'slug', slug),
|
||||||
|
description = COALESCE(p_data->>'description', description),
|
||||||
|
website_url = COALESCE(p_data->>'website_url', website_url),
|
||||||
|
founded_year = COALESCE((p_data->>'founded_year')::INTEGER, founded_year),
|
||||||
|
banner_image_url = COALESCE(p_data->>'banner_image_url', banner_image_url),
|
||||||
|
banner_image_id = COALESCE(p_data->>'banner_image_id', banner_image_id),
|
||||||
|
card_image_url = COALESCE(p_data->>'card_image_url', card_image_url),
|
||||||
|
card_image_id = COALESCE(p_data->>'card_image_id', card_image_id),
|
||||||
|
updated_at = NOW()
|
||||||
|
WHERE id = p_entity_id;
|
||||||
|
|
||||||
|
WHEN 'ride_model' THEN
|
||||||
|
UPDATE ride_models SET
|
||||||
|
name = COALESCE(p_data->>'name', name),
|
||||||
|
slug = COALESCE(p_data->>'slug', slug),
|
||||||
|
manufacturer_id = COALESCE((p_data->>'manufacturer_id')::UUID, manufacturer_id),
|
||||||
|
ride_type = COALESCE(p_data->>'ride_type', ride_type),
|
||||||
|
description = COALESCE(p_data->>'description', description),
|
||||||
|
banner_image_url = COALESCE(p_data->>'banner_image_url', banner_image_url),
|
||||||
|
banner_image_id = COALESCE(p_data->>'banner_image_id', banner_image_id),
|
||||||
|
card_image_url = COALESCE(p_data->>'card_image_url', card_image_url),
|
||||||
|
card_image_id = COALESCE(p_data->>'card_image_id', card_image_id),
|
||||||
|
updated_at = NOW()
|
||||||
|
WHERE id = p_entity_id;
|
||||||
|
|
||||||
|
ELSE
|
||||||
|
RAISE EXCEPTION 'Unsupported entity type for update: %', p_entity_type
|
||||||
|
USING ERRCODE = '22023';
|
||||||
|
END CASE;
|
||||||
|
|
||||||
|
RETURN p_entity_id;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
-- HELPER FUNCTION: Delete entity from submission
|
||||||
|
-- ============================================================================
|
||||||
|
CREATE OR REPLACE FUNCTION delete_entity_from_submission(
|
||||||
|
p_entity_type TEXT,
|
||||||
|
p_entity_id UUID,
|
||||||
|
p_deleted_by UUID
|
||||||
|
)
|
||||||
|
RETURNS VOID
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
CASE p_entity_type
|
||||||
|
WHEN 'park' THEN
|
||||||
|
DELETE FROM parks WHERE id = p_entity_id;
|
||||||
|
WHEN 'ride' THEN
|
||||||
|
DELETE FROM rides WHERE id = p_entity_id;
|
||||||
|
WHEN 'manufacturer', 'operator', 'property_owner', 'designer' THEN
|
||||||
|
DELETE FROM companies WHERE id = p_entity_id;
|
||||||
|
WHEN 'ride_model' THEN
|
||||||
|
DELETE FROM ride_models WHERE id = p_entity_id;
|
||||||
|
ELSE
|
||||||
|
RAISE EXCEPTION 'Unsupported entity type for deletion: %', p_entity_type
|
||||||
|
USING ERRCODE = '22023';
|
||||||
|
END CASE;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- ============================================================================
|
||||||
|
-- MAIN TRANSACTION FUNCTION: Process approval in single atomic transaction
|
||||||
|
-- ============================================================================
|
||||||
|
CREATE OR REPLACE FUNCTION process_approval_transaction(
|
||||||
|
p_submission_id UUID,
|
||||||
|
p_item_ids UUID[],
|
||||||
|
p_moderator_id UUID,
|
||||||
|
p_submitter_id UUID,
|
||||||
|
p_request_id TEXT DEFAULT NULL
|
||||||
|
)
|
||||||
|
RETURNS JSONB
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
v_start_time TIMESTAMPTZ;
|
||||||
|
v_result JSONB;
|
||||||
|
v_item RECORD;
|
||||||
|
v_item_data JSONB;
|
||||||
|
v_entity_id UUID;
|
||||||
|
v_approval_results JSONB[] := ARRAY[]::JSONB[];
|
||||||
|
v_final_status TEXT;
|
||||||
|
v_all_approved BOOLEAN := TRUE;
|
||||||
|
v_some_approved BOOLEAN := FALSE;
|
||||||
|
v_items_processed INTEGER := 0;
|
||||||
|
BEGIN
|
||||||
|
v_start_time := clock_timestamp();
|
||||||
|
|
||||||
|
RAISE NOTICE '[%] Starting atomic approval transaction for submission %',
|
||||||
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
||||||
|
p_submission_id;
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 1: Set session variables (transaction-scoped with is_local=true)
|
||||||
|
-- ========================================================================
|
||||||
|
PERFORM set_config('app.current_user_id', p_submitter_id::text, true);
|
||||||
|
PERFORM set_config('app.submission_id', p_submission_id::text, true);
|
||||||
|
PERFORM set_config('app.moderator_id', p_moderator_id::text, true);
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 2: Validate submission ownership and lock status
|
||||||
|
-- ========================================================================
|
||||||
|
IF NOT EXISTS (
|
||||||
|
SELECT 1 FROM content_submissions
|
||||||
|
WHERE id = p_submission_id
|
||||||
|
AND (assigned_to = p_moderator_id OR assigned_to IS NULL)
|
||||||
|
AND status IN ('pending', 'partially_approved')
|
||||||
|
) THEN
|
||||||
|
RAISE EXCEPTION 'Submission not found, locked by another moderator, or already processed'
|
||||||
|
USING ERRCODE = '42501';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 3: Process each item sequentially within this transaction
|
||||||
|
-- ========================================================================
|
||||||
|
FOR v_item IN
|
||||||
|
SELECT
|
||||||
|
si.*,
|
||||||
|
ps.name as park_name,
|
||||||
|
ps.slug as park_slug,
|
||||||
|
ps.description as park_description,
|
||||||
|
ps.park_type,
|
||||||
|
ps.status as park_status,
|
||||||
|
ps.location_id,
|
||||||
|
ps.operator_id,
|
||||||
|
ps.property_owner_id,
|
||||||
|
ps.opening_date as park_opening_date,
|
||||||
|
ps.closing_date as park_closing_date,
|
||||||
|
ps.opening_date_precision as park_opening_date_precision,
|
||||||
|
ps.closing_date_precision as park_closing_date_precision,
|
||||||
|
ps.website_url as park_website_url,
|
||||||
|
ps.phone as park_phone,
|
||||||
|
ps.email as park_email,
|
||||||
|
ps.banner_image_url as park_banner_image_url,
|
||||||
|
ps.banner_image_id as park_banner_image_id,
|
||||||
|
ps.card_image_url as park_card_image_url,
|
||||||
|
ps.card_image_id as park_card_image_id,
|
||||||
|
rs.name as ride_name,
|
||||||
|
rs.slug as ride_slug,
|
||||||
|
rs.park_id as ride_park_id,
|
||||||
|
rs.ride_type,
|
||||||
|
rs.status as ride_status,
|
||||||
|
rs.manufacturer_id,
|
||||||
|
rs.ride_model_id,
|
||||||
|
rs.opening_date as ride_opening_date,
|
||||||
|
rs.closing_date as ride_closing_date,
|
||||||
|
rs.opening_date_precision as ride_opening_date_precision,
|
||||||
|
rs.closing_date_precision as ride_closing_date_precision,
|
||||||
|
rs.description as ride_description,
|
||||||
|
rs.banner_image_url as ride_banner_image_url,
|
||||||
|
rs.banner_image_id as ride_banner_image_id,
|
||||||
|
rs.card_image_url as ride_card_image_url,
|
||||||
|
rs.card_image_id as ride_card_image_id,
|
||||||
|
cs.name as company_name,
|
||||||
|
cs.slug as company_slug,
|
||||||
|
cs.description as company_description,
|
||||||
|
cs.website_url as company_website_url,
|
||||||
|
cs.founded_year,
|
||||||
|
cs.banner_image_url as company_banner_image_url,
|
||||||
|
cs.banner_image_id as company_banner_image_id,
|
||||||
|
cs.card_image_url as company_card_image_url,
|
||||||
|
cs.card_image_id as company_card_image_id,
|
||||||
|
rms.name as ride_model_name,
|
||||||
|
rms.slug as ride_model_slug,
|
||||||
|
rms.manufacturer_id as ride_model_manufacturer_id,
|
||||||
|
rms.ride_type as ride_model_ride_type,
|
||||||
|
rms.description as ride_model_description,
|
||||||
|
rms.banner_image_url as ride_model_banner_image_url,
|
||||||
|
rms.banner_image_id as ride_model_banner_image_id,
|
||||||
|
rms.card_image_url as ride_model_card_image_url,
|
||||||
|
rms.card_image_id as ride_model_card_image_id
|
||||||
|
FROM submission_items si
|
||||||
|
LEFT JOIN park_submissions ps ON si.park_submission_id = ps.id
|
||||||
|
LEFT JOIN ride_submissions rs ON si.ride_submission_id = rs.id
|
||||||
|
LEFT JOIN company_submissions cs ON si.company_submission_id = cs.id
|
||||||
|
LEFT JOIN ride_model_submissions rms ON si.ride_model_submission_id = rms.id
|
||||||
|
WHERE si.id = ANY(p_item_ids)
|
||||||
|
ORDER BY si.order_index, si.created_at
|
||||||
|
LOOP
|
||||||
|
BEGIN
|
||||||
|
v_items_processed := v_items_processed + 1;
|
||||||
|
|
||||||
|
-- Build item data based on entity type
|
||||||
|
IF v_item.item_type = 'park' THEN
|
||||||
|
v_item_data := jsonb_build_object(
|
||||||
|
'name', v_item.park_name,
|
||||||
|
'slug', v_item.park_slug,
|
||||||
|
'description', v_item.park_description,
|
||||||
|
'park_type', v_item.park_type,
|
||||||
|
'status', v_item.park_status,
|
||||||
|
'location_id', v_item.location_id,
|
||||||
|
'operator_id', v_item.operator_id,
|
||||||
|
'property_owner_id', v_item.property_owner_id,
|
||||||
|
'opening_date', v_item.park_opening_date,
|
||||||
|
'closing_date', v_item.park_closing_date,
|
||||||
|
'opening_date_precision', v_item.park_opening_date_precision,
|
||||||
|
'closing_date_precision', v_item.park_closing_date_precision,
|
||||||
|
'website_url', v_item.park_website_url,
|
||||||
|
'phone', v_item.park_phone,
|
||||||
|
'email', v_item.park_email,
|
||||||
|
'banner_image_url', v_item.park_banner_image_url,
|
||||||
|
'banner_image_id', v_item.park_banner_image_id,
|
||||||
|
'card_image_url', v_item.park_card_image_url,
|
||||||
|
'card_image_id', v_item.park_card_image_id
|
||||||
|
);
|
||||||
|
ELSIF v_item.item_type = 'ride' THEN
|
||||||
|
v_item_data := jsonb_build_object(
|
||||||
|
'name', v_item.ride_name,
|
||||||
|
'slug', v_item.ride_slug,
|
||||||
|
'park_id', v_item.ride_park_id,
|
||||||
|
'ride_type', v_item.ride_type,
|
||||||
|
'status', v_item.ride_status,
|
||||||
|
'manufacturer_id', v_item.manufacturer_id,
|
||||||
|
'ride_model_id', v_item.ride_model_id,
|
||||||
|
'opening_date', v_item.ride_opening_date,
|
||||||
|
'closing_date', v_item.ride_closing_date,
|
||||||
|
'opening_date_precision', v_item.ride_opening_date_precision,
|
||||||
|
'closing_date_precision', v_item.ride_closing_date_precision,
|
||||||
|
'description', v_item.ride_description,
|
||||||
|
'banner_image_url', v_item.ride_banner_image_url,
|
||||||
|
'banner_image_id', v_item.ride_banner_image_id,
|
||||||
|
'card_image_url', v_item.ride_card_image_url,
|
||||||
|
'card_image_id', v_item.ride_card_image_id
|
||||||
|
);
|
||||||
|
ELSIF v_item.item_type IN ('manufacturer', 'operator', 'property_owner', 'designer') THEN
|
||||||
|
v_item_data := jsonb_build_object(
|
||||||
|
'name', v_item.company_name,
|
||||||
|
'slug', v_item.company_slug,
|
||||||
|
'description', v_item.company_description,
|
||||||
|
'website_url', v_item.company_website_url,
|
||||||
|
'founded_year', v_item.founded_year,
|
||||||
|
'banner_image_url', v_item.company_banner_image_url,
|
||||||
|
'banner_image_id', v_item.company_banner_image_id,
|
||||||
|
'card_image_url', v_item.company_card_image_url,
|
||||||
|
'card_image_id', v_item.company_card_image_id
|
||||||
|
);
|
||||||
|
ELSIF v_item.item_type = 'ride_model' THEN
|
||||||
|
v_item_data := jsonb_build_object(
|
||||||
|
'name', v_item.ride_model_name,
|
||||||
|
'slug', v_item.ride_model_slug,
|
||||||
|
'manufacturer_id', v_item.ride_model_manufacturer_id,
|
||||||
|
'ride_type', v_item.ride_model_ride_type,
|
||||||
|
'description', v_item.ride_model_description,
|
||||||
|
'banner_image_url', v_item.ride_model_banner_image_url,
|
||||||
|
'banner_image_id', v_item.ride_model_banner_image_id,
|
||||||
|
'card_image_url', v_item.ride_model_card_image_url,
|
||||||
|
'card_image_id', v_item.ride_model_card_image_id
|
||||||
|
);
|
||||||
|
ELSE
|
||||||
|
RAISE EXCEPTION 'Unsupported item_type: %', v_item.item_type;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Execute action based on action_type
|
||||||
|
IF v_item.action_type = 'create' THEN
|
||||||
|
v_entity_id := create_entity_from_submission(
|
||||||
|
v_item.item_type,
|
||||||
|
v_item_data,
|
||||||
|
p_submitter_id
|
||||||
|
);
|
||||||
|
ELSIF v_item.action_type = 'update' THEN
|
||||||
|
v_entity_id := update_entity_from_submission(
|
||||||
|
v_item.item_type,
|
||||||
|
v_item_data,
|
||||||
|
v_item.target_entity_id,
|
||||||
|
p_submitter_id
|
||||||
|
);
|
||||||
|
ELSIF v_item.action_type = 'delete' THEN
|
||||||
|
PERFORM delete_entity_from_submission(
|
||||||
|
v_item.item_type,
|
||||||
|
v_item.target_entity_id,
|
||||||
|
p_submitter_id
|
||||||
|
);
|
||||||
|
v_entity_id := v_item.target_entity_id;
|
||||||
|
ELSE
|
||||||
|
RAISE EXCEPTION 'Unknown action_type: %', v_item.action_type;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Update submission_item to approved status
|
||||||
|
UPDATE submission_items
|
||||||
|
SET
|
||||||
|
status = 'approved',
|
||||||
|
approved_entity_id = v_entity_id,
|
||||||
|
updated_at = NOW()
|
||||||
|
WHERE id = v_item.id;
|
||||||
|
|
||||||
|
-- Track success
|
||||||
|
v_approval_results := array_append(
|
||||||
|
v_approval_results,
|
||||||
|
jsonb_build_object(
|
||||||
|
'itemId', v_item.id,
|
||||||
|
'entityId', v_entity_id,
|
||||||
|
'itemType', v_item.item_type,
|
||||||
|
'actionType', v_item.action_type,
|
||||||
|
'success', true
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
v_some_approved := TRUE;
|
||||||
|
|
||||||
|
RAISE NOTICE '[%] Approved item % (type=%s, action=%s, entityId=%s)',
|
||||||
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
||||||
|
v_item.id,
|
||||||
|
v_item.item_type,
|
||||||
|
v_item.action_type,
|
||||||
|
v_entity_id;
|
||||||
|
|
||||||
|
EXCEPTION WHEN OTHERS THEN
|
||||||
|
-- Log error but continue processing remaining items
|
||||||
|
RAISE WARNING '[%] Item % failed: % (SQLSTATE: %)',
|
||||||
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
||||||
|
v_item.id,
|
||||||
|
SQLERRM,
|
||||||
|
SQLSTATE;
|
||||||
|
|
||||||
|
-- Update submission_item to rejected status
|
||||||
|
UPDATE submission_items
|
||||||
|
SET
|
||||||
|
status = 'rejected',
|
||||||
|
rejection_reason = SQLERRM,
|
||||||
|
updated_at = NOW()
|
||||||
|
WHERE id = v_item.id;
|
||||||
|
|
||||||
|
-- Track failure
|
||||||
|
v_approval_results := array_append(
|
||||||
|
v_approval_results,
|
||||||
|
jsonb_build_object(
|
||||||
|
'itemId', v_item.id,
|
||||||
|
'itemType', v_item.item_type,
|
||||||
|
'actionType', v_item.action_type,
|
||||||
|
'success', false,
|
||||||
|
'error', SQLERRM
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
v_all_approved := FALSE;
|
||||||
|
END;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 4: Determine final submission status
|
||||||
|
-- ========================================================================
|
||||||
|
v_final_status := CASE
|
||||||
|
WHEN v_all_approved THEN 'approved'
|
||||||
|
WHEN v_some_approved THEN 'partially_approved'
|
||||||
|
ELSE 'rejected'
|
||||||
|
END;
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 5: Update submission status
|
||||||
|
-- ========================================================================
|
||||||
|
UPDATE content_submissions
|
||||||
|
SET
|
||||||
|
status = v_final_status,
|
||||||
|
reviewer_id = p_moderator_id,
|
||||||
|
reviewed_at = NOW(),
|
||||||
|
assigned_to = NULL,
|
||||||
|
locked_until = NULL
|
||||||
|
WHERE id = p_submission_id;
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 6: Log metrics
|
||||||
|
-- ========================================================================
|
||||||
|
INSERT INTO approval_transaction_metrics (
|
||||||
|
submission_id,
|
||||||
|
moderator_id,
|
||||||
|
submitter_id,
|
||||||
|
items_count,
|
||||||
|
duration_ms,
|
||||||
|
success,
|
||||||
|
request_id
|
||||||
|
) VALUES (
|
||||||
|
p_submission_id,
|
||||||
|
p_moderator_id,
|
||||||
|
p_submitter_id,
|
||||||
|
array_length(p_item_ids, 1),
|
||||||
|
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000,
|
||||||
|
v_all_approved,
|
||||||
|
p_request_id
|
||||||
|
);
|
||||||
|
|
||||||
|
-- ========================================================================
|
||||||
|
-- STEP 7: Build result
|
||||||
|
-- ========================================================================
|
||||||
|
v_result := jsonb_build_object(
|
||||||
|
'success', TRUE,
|
||||||
|
'results', to_jsonb(v_approval_results),
|
||||||
|
'submissionStatus', v_final_status,
|
||||||
|
'itemsProcessed', v_items_processed,
|
||||||
|
'allApproved', v_all_approved,
|
||||||
|
'someApproved', v_some_approved
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Clear session variables (defense-in-depth)
|
||||||
|
PERFORM set_config('app.current_user_id', '', true);
|
||||||
|
PERFORM set_config('app.submission_id', '', true);
|
||||||
|
PERFORM set_config('app.moderator_id', '', true);
|
||||||
|
|
||||||
|
RAISE NOTICE '[%] Transaction completed successfully in %ms',
|
||||||
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
||||||
|
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000;
|
||||||
|
|
||||||
|
RETURN v_result;
|
||||||
|
|
||||||
|
EXCEPTION WHEN OTHERS THEN
|
||||||
|
-- ANY unhandled error triggers automatic ROLLBACK
|
||||||
|
RAISE WARNING '[%] Transaction failed, rolling back: % (SQLSTATE: %)',
|
||||||
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
||||||
|
SQLERRM,
|
||||||
|
SQLSTATE;
|
||||||
|
|
||||||
|
-- Log failed transaction metrics
|
||||||
|
INSERT INTO approval_transaction_metrics (
|
||||||
|
submission_id,
|
||||||
|
moderator_id,
|
||||||
|
submitter_id,
|
||||||
|
items_count,
|
||||||
|
duration_ms,
|
||||||
|
success,
|
||||||
|
rollback_triggered,
|
||||||
|
error_message,
|
||||||
|
request_id
|
||||||
|
) VALUES (
|
||||||
|
p_submission_id,
|
||||||
|
p_moderator_id,
|
||||||
|
p_submitter_id,
|
||||||
|
array_length(p_item_ids, 1),
|
||||||
|
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000,
|
||||||
|
FALSE,
|
||||||
|
TRUE,
|
||||||
|
SQLERRM,
|
||||||
|
p_request_id
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Clear session variables before re-raising
|
||||||
|
PERFORM set_config('app.current_user_id', '', true);
|
||||||
|
PERFORM set_config('app.submission_id', '', true);
|
||||||
|
PERFORM set_config('app.moderator_id', '', true);
|
||||||
|
|
||||||
|
-- Re-raise the exception to trigger ROLLBACK
|
||||||
|
RAISE;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Grant execute permissions
|
||||||
|
GRANT EXECUTE ON FUNCTION process_approval_transaction TO authenticated;
|
||||||
|
GRANT EXECUTE ON FUNCTION create_entity_from_submission TO authenticated;
|
||||||
|
GRANT EXECUTE ON FUNCTION update_entity_from_submission TO authenticated;
|
||||||
|
GRANT EXECUTE ON FUNCTION delete_entity_from_submission TO authenticated;
|
||||||
Reference in New Issue
Block a user