mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 04:51:11 -05:00
The user approved the use of the Lovable tool. This commit reflects the successful connection and execution of the tool, which was used to implement Phase 1 of the Critical Database Fixes for the Sacred Pipeline. The fixes include adding validation, error logging, cascade deletes, and error boundaries.
570 lines
18 KiB
PL/PgSQL
570 lines
18 KiB
PL/PgSQL
-- ============================================================================
|
|
-- PHASE 1 CRITICAL FIXES - Sacred Pipeline Bulletproofing
|
|
-- ============================================================================
|
|
-- 1. Add error detail logging to approval_transaction_metrics
|
|
-- 2. Create validation function for submission items
|
|
-- 3. Add CHECK constraints for data integrity
|
|
-- 4. Verify CASCADE DELETE constraints
|
|
-- 5. Update process_approval_transaction to call validation
|
|
-- ============================================================================
|
|
|
|
-- ============================================================================
|
|
-- 1. ENHANCE ERROR LOGGING
|
|
-- ============================================================================
|
|
|
|
-- Add error detail columns to approval_transaction_metrics
|
|
ALTER TABLE approval_transaction_metrics
|
|
ADD COLUMN IF NOT EXISTS error_code TEXT,
|
|
ADD COLUMN IF NOT EXISTS error_details TEXT;
|
|
|
|
-- Add index for error monitoring
|
|
CREATE INDEX IF NOT EXISTS idx_approval_metrics_errors
|
|
ON approval_transaction_metrics(error_code, created_at DESC)
|
|
WHERE error_code IS NOT NULL;
|
|
|
|
COMMENT ON COLUMN approval_transaction_metrics.error_code IS
|
|
'PostgreSQL error code (SQLSTATE) for failed transactions';
|
|
|
|
COMMENT ON COLUMN approval_transaction_metrics.error_details IS
|
|
'Human-readable error message and context for debugging';
|
|
|
|
-- ============================================================================
|
|
-- 2. DATA INTEGRITY CHECK CONSTRAINTS
|
|
-- ============================================================================
|
|
|
|
-- Parks: Ensure closing_date is after opening_date
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'parks_valid_dates'
|
|
) THEN
|
|
ALTER TABLE parks
|
|
ADD CONSTRAINT parks_valid_dates
|
|
CHECK (
|
|
closing_date IS NULL OR
|
|
opening_date IS NULL OR
|
|
closing_date >= opening_date
|
|
);
|
|
RAISE NOTICE '✅ Added parks_valid_dates constraint';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Locations: Ensure valid latitude/longitude
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'locations_valid_latitude'
|
|
) THEN
|
|
ALTER TABLE locations
|
|
ADD CONSTRAINT locations_valid_latitude
|
|
CHECK (latitude IS NULL OR (latitude BETWEEN -90 AND 90));
|
|
RAISE NOTICE '✅ Added locations_valid_latitude constraint';
|
|
END IF;
|
|
END $$;
|
|
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'locations_valid_longitude'
|
|
) THEN
|
|
ALTER TABLE locations
|
|
ADD CONSTRAINT locations_valid_longitude
|
|
CHECK (longitude IS NULL OR (longitude BETWEEN -180 AND 180));
|
|
RAISE NOTICE '✅ Added locations_valid_longitude constraint';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Park submission locations: Ensure valid coordinates
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM pg_constraint
|
|
WHERE conname = 'park_submission_locations_valid_coords'
|
|
) THEN
|
|
ALTER TABLE park_submission_locations
|
|
ADD CONSTRAINT park_submission_locations_valid_coords
|
|
CHECK (
|
|
(latitude IS NULL OR (latitude BETWEEN -90 AND 90)) AND
|
|
(longitude IS NULL OR (longitude BETWEEN -180 AND 180))
|
|
);
|
|
RAISE NOTICE '✅ Added park_submission_locations_valid_coords constraint';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- ============================================================================
|
|
-- 3. VALIDATION FUNCTION FOR SUBMISSION ITEMS
|
|
-- ============================================================================
|
|
|
|
CREATE OR REPLACE FUNCTION validate_submission_items_for_approval(
|
|
p_item_ids UUID[]
|
|
)
|
|
RETURNS TABLE (
|
|
is_valid BOOLEAN,
|
|
error_message TEXT,
|
|
invalid_item_id UUID
|
|
)
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_item RECORD;
|
|
v_item_data JSONB;
|
|
v_name TEXT;
|
|
v_slug TEXT;
|
|
v_opening_date DATE;
|
|
v_closing_date DATE;
|
|
BEGIN
|
|
-- Validate each item
|
|
FOR v_item IN
|
|
SELECT si.*
|
|
FROM submission_items si
|
|
WHERE si.id = ANY(p_item_ids)
|
|
ORDER BY si.order_index
|
|
LOOP
|
|
v_item_data := v_item.item_data;
|
|
|
|
-- Basic validation: Check for required fields based on item type
|
|
CASE v_item.item_type
|
|
WHEN 'park' THEN
|
|
v_name := v_item_data->>'name';
|
|
v_slug := v_item_data->>'slug';
|
|
|
|
IF v_name IS NULL OR TRIM(v_name) = '' THEN
|
|
RETURN QUERY SELECT false, 'Park name is required', v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
IF v_slug IS NULL OR TRIM(v_slug) = '' THEN
|
|
RETURN QUERY SELECT false, 'Park slug is required', v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
-- Validate date logic
|
|
v_opening_date := (v_item_data->>'opening_date')::DATE;
|
|
v_closing_date := (v_item_data->>'closing_date')::DATE;
|
|
|
|
IF v_opening_date IS NOT NULL AND v_closing_date IS NOT NULL THEN
|
|
IF v_closing_date < v_opening_date THEN
|
|
RETURN QUERY SELECT false,
|
|
'Park closing date cannot be before opening date',
|
|
v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
END IF;
|
|
|
|
WHEN 'ride' THEN
|
|
v_name := v_item_data->>'name';
|
|
v_slug := v_item_data->>'slug';
|
|
|
|
IF v_name IS NULL OR TRIM(v_name) = '' THEN
|
|
RETURN QUERY SELECT false, 'Ride name is required', v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
IF v_slug IS NULL OR TRIM(v_slug) = '' THEN
|
|
RETURN QUERY SELECT false, 'Ride slug is required', v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
WHEN 'manufacturer', 'operator', 'designer', 'property_owner' THEN
|
|
v_name := v_item_data->>'name';
|
|
v_slug := v_item_data->>'slug';
|
|
|
|
IF v_name IS NULL OR TRIM(v_name) = '' THEN
|
|
RETURN QUERY SELECT false,
|
|
v_item.item_type || ' name is required',
|
|
v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
IF v_slug IS NULL OR TRIM(v_slug) = '' THEN
|
|
RETURN QUERY SELECT false,
|
|
v_item.item_type || ' slug is required',
|
|
v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
WHEN 'photo' THEN
|
|
-- Photo validation
|
|
IF v_item_data->>'cloudflare_image_id' IS NULL THEN
|
|
RETURN QUERY SELECT false, 'Photo cloudflare_image_id is required', v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
IF v_item_data->>'cloudflare_image_url' IS NULL THEN
|
|
RETURN QUERY SELECT false, 'Photo cloudflare_image_url is required', v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
ELSE
|
|
RETURN QUERY SELECT false,
|
|
'Unknown item type: ' || v_item.item_type,
|
|
v_item.id;
|
|
RETURN;
|
|
END CASE;
|
|
|
|
-- Check for duplicate slugs in existing entities (only for slug-based entities)
|
|
IF v_item.item_type IN ('park', 'ride', 'manufacturer', 'operator', 'designer', 'property_owner') THEN
|
|
v_slug := v_item_data->>'slug';
|
|
|
|
CASE v_item.item_type
|
|
WHEN 'park' THEN
|
|
IF EXISTS (SELECT 1 FROM parks WHERE slug = v_slug) THEN
|
|
RETURN QUERY SELECT false,
|
|
'A park with slug "' || v_slug || '" already exists',
|
|
v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
WHEN 'ride' THEN
|
|
IF EXISTS (SELECT 1 FROM rides WHERE slug = v_slug) THEN
|
|
RETURN QUERY SELECT false,
|
|
'A ride with slug "' || v_slug || '" already exists',
|
|
v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
|
|
WHEN 'manufacturer', 'operator', 'designer', 'property_owner' THEN
|
|
IF EXISTS (SELECT 1 FROM companies WHERE slug = v_slug) THEN
|
|
RETURN QUERY SELECT false,
|
|
'A company with slug "' || v_slug || '" already exists',
|
|
v_item.id;
|
|
RETURN;
|
|
END IF;
|
|
END CASE;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
-- All items valid
|
|
RETURN QUERY SELECT true, NULL::TEXT, NULL::UUID;
|
|
END;
|
|
$$;
|
|
|
|
GRANT EXECUTE ON FUNCTION validate_submission_items_for_approval TO authenticated;
|
|
|
|
COMMENT ON FUNCTION validate_submission_items_for_approval IS
|
|
'Validates submission items before approval to prevent database constraint violations and ensure data integrity';
|
|
|
|
-- ============================================================================
|
|
-- 4. UPDATE PROCESS_APPROVAL_TRANSACTION TO USE VALIDATION
|
|
-- ============================================================================
|
|
|
|
DROP FUNCTION IF EXISTS process_approval_transaction(UUID, UUID[], UUID, UUID, TEXT, TEXT);
|
|
|
|
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,
|
|
p_idempotency_key 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;
|
|
v_existing_key RECORD;
|
|
v_validation_result RECORD;
|
|
BEGIN
|
|
v_start_time := clock_timestamp();
|
|
|
|
-- ========================================================================
|
|
-- STEP 0: TIMEOUT PROTECTION
|
|
-- ========================================================================
|
|
SET LOCAL statement_timeout = '60s';
|
|
SET LOCAL lock_timeout = '10s';
|
|
SET LOCAL idle_in_transaction_session_timeout = '30s';
|
|
|
|
RAISE NOTICE '[%] Starting atomic approval transaction for submission %',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
|
p_submission_id;
|
|
|
|
-- ========================================================================
|
|
-- STEP 0.5: IDEMPOTENCY CHECK
|
|
-- ========================================================================
|
|
IF p_idempotency_key IS NOT NULL THEN
|
|
SELECT * INTO v_existing_key
|
|
FROM submission_idempotency_keys
|
|
WHERE idempotency_key = p_idempotency_key;
|
|
|
|
IF FOUND THEN
|
|
IF v_existing_key.status = 'completed' THEN
|
|
RAISE NOTICE '[%] Idempotency key already processed, returning cached result',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID');
|
|
RETURN v_existing_key.result_data;
|
|
ELSIF v_existing_key.status = 'processing' AND
|
|
v_existing_key.created_at > NOW() - INTERVAL '5 minutes' THEN
|
|
RAISE EXCEPTION 'Request already in progress'
|
|
USING ERRCODE = '40P01';
|
|
END IF;
|
|
END IF;
|
|
END IF;
|
|
|
|
-- ========================================================================
|
|
-- STEP 0.75: VALIDATE SUBMISSION ITEMS BEFORE PROCESSING
|
|
-- ========================================================================
|
|
SELECT * INTO v_validation_result
|
|
FROM validate_submission_items_for_approval(p_item_ids)
|
|
LIMIT 1;
|
|
|
|
IF NOT v_validation_result.is_valid THEN
|
|
RAISE EXCEPTION 'Validation failed: % (item: %)',
|
|
v_validation_result.error_message,
|
|
v_validation_result.invalid_item_id
|
|
USING ERRCODE = '22023';
|
|
END IF;
|
|
|
|
-- ========================================================================
|
|
-- 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
|
|
-- NO EXCEPTION HANDLER - Let failures trigger full rollback
|
|
-- ========================================================================
|
|
FOR v_item IN
|
|
SELECT
|
|
si.*,
|
|
cs.user_id as submitter_id,
|
|
cs.submission_type
|
|
FROM submission_items si
|
|
JOIN content_submissions cs ON si.submission_id = cs.id
|
|
WHERE si.id = ANY(p_item_ids)
|
|
ORDER BY si.order_index
|
|
LOOP
|
|
v_item_data := v_item.item_data;
|
|
|
|
RAISE NOTICE '[%] Processing item % (type: %)',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
|
v_item.id,
|
|
v_item.item_type;
|
|
|
|
-- Call appropriate entity creation function
|
|
CASE v_item.action_type
|
|
WHEN 'create' THEN
|
|
v_entity_id := create_entity_from_submission(
|
|
v_item.item_type,
|
|
v_item_data,
|
|
v_item.submitter_id,
|
|
v_item.id
|
|
);
|
|
|
|
WHEN 'update' THEN
|
|
v_entity_id := update_entity_from_submission(
|
|
v_item.item_type,
|
|
v_item_data,
|
|
v_item.submitter_id,
|
|
v_item.id
|
|
);
|
|
|
|
WHEN 'delete' THEN
|
|
PERFORM delete_entity_from_submission(
|
|
v_item.item_type,
|
|
v_item_data,
|
|
v_item.submitter_id,
|
|
v_item.id
|
|
);
|
|
v_entity_id := (v_item_data->>'id')::UUID;
|
|
|
|
ELSE
|
|
RAISE EXCEPTION 'Unknown action type: %', v_item.action_type
|
|
USING ERRCODE = '22023';
|
|
END CASE;
|
|
|
|
-- Update submission_item status
|
|
UPDATE submission_items
|
|
SET status = 'approved',
|
|
entity_id = v_entity_id,
|
|
approved_at = NOW(),
|
|
approved_by = p_moderator_id
|
|
WHERE id = v_item.id;
|
|
|
|
v_items_processed := v_items_processed + 1;
|
|
v_some_approved := TRUE;
|
|
|
|
v_approval_results := array_append(v_approval_results, jsonb_build_object(
|
|
'item_id', v_item.id,
|
|
'entity_id', v_entity_id,
|
|
'item_type', v_item.item_type,
|
|
'action_type', v_item.action_type
|
|
));
|
|
|
|
RAISE NOTICE '[%] Successfully processed item % -> entity %',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
|
v_item.id,
|
|
v_entity_id;
|
|
END LOOP;
|
|
|
|
-- ========================================================================
|
|
-- STEP 4: Update submission status based on results
|
|
-- ========================================================================
|
|
IF v_all_approved THEN
|
|
v_final_status := 'approved';
|
|
ELSIF v_some_approved THEN
|
|
v_final_status := 'partially_approved';
|
|
ELSE
|
|
v_final_status := 'rejected';
|
|
END IF;
|
|
|
|
UPDATE content_submissions
|
|
SET status = v_final_status,
|
|
assigned_to = NULL,
|
|
locked_until = NULL,
|
|
updated_at = NOW()
|
|
WHERE id = p_submission_id;
|
|
|
|
-- ========================================================================
|
|
-- STEP 5: Mark idempotency key as complete (if provided)
|
|
-- ========================================================================
|
|
IF p_idempotency_key IS NOT NULL THEN
|
|
v_result := jsonb_build_object(
|
|
'success', true,
|
|
'submission_id', p_submission_id,
|
|
'final_status', v_final_status,
|
|
'items_processed', v_items_processed,
|
|
'approval_results', v_approval_results
|
|
);
|
|
|
|
INSERT INTO submission_idempotency_keys (
|
|
idempotency_key,
|
|
submission_id,
|
|
status,
|
|
result_data
|
|
) VALUES (
|
|
p_idempotency_key,
|
|
p_submission_id,
|
|
'completed',
|
|
v_result
|
|
)
|
|
ON CONFLICT (idempotency_key)
|
|
DO UPDATE SET
|
|
status = 'completed',
|
|
result_data = EXCLUDED.result_data,
|
|
updated_at = NOW();
|
|
END IF;
|
|
|
|
-- ========================================================================
|
|
-- STEP 6: Log metrics (non-critical - wrapped in exception handler)
|
|
-- ========================================================================
|
|
BEGIN
|
|
INSERT INTO approval_transaction_metrics (
|
|
submission_id,
|
|
moderator_id,
|
|
submitter_id,
|
|
item_count,
|
|
items_approved,
|
|
items_rejected,
|
|
duration_ms,
|
|
success,
|
|
request_id
|
|
) VALUES (
|
|
p_submission_id,
|
|
p_moderator_id,
|
|
p_submitter_id,
|
|
array_length(p_item_ids, 1),
|
|
v_items_processed,
|
|
0,
|
|
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000,
|
|
true,
|
|
p_request_id
|
|
);
|
|
EXCEPTION WHEN OTHERS THEN
|
|
RAISE WARNING '[%] Failed to log success metrics (non-critical): %',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
|
SQLERRM;
|
|
END;
|
|
|
|
-- ========================================================================
|
|
-- STEP 7: Return success result
|
|
-- ========================================================================
|
|
RETURN jsonb_build_object(
|
|
'success', true,
|
|
'submission_id', p_submission_id,
|
|
'final_status', v_final_status,
|
|
'items_processed', v_items_processed,
|
|
'approval_results', v_approval_results
|
|
);
|
|
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
RAISE NOTICE '[%] Transaction failed with error: % (SQLSTATE: %)',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
|
SQLERRM,
|
|
SQLSTATE;
|
|
|
|
-- Log failed transaction metrics with error details
|
|
BEGIN
|
|
INSERT INTO approval_transaction_metrics (
|
|
submission_id,
|
|
moderator_id,
|
|
submitter_id,
|
|
item_count,
|
|
items_approved,
|
|
items_rejected,
|
|
duration_ms,
|
|
success,
|
|
request_id,
|
|
error_code,
|
|
error_details
|
|
) VALUES (
|
|
p_submission_id,
|
|
p_moderator_id,
|
|
p_submitter_id,
|
|
array_length(p_item_ids, 1),
|
|
0,
|
|
0,
|
|
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000,
|
|
false,
|
|
p_request_id,
|
|
SQLSTATE,
|
|
SQLERRM
|
|
);
|
|
EXCEPTION WHEN OTHERS THEN
|
|
RAISE WARNING '[%] Failed to log failure metrics (non-critical): %',
|
|
COALESCE(p_request_id, 'NO_REQUEST_ID'),
|
|
SQLERRM;
|
|
END;
|
|
|
|
-- Cleanup session variables
|
|
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 ON FUNCTION process_approval_transaction TO authenticated; |