Files
thrilltrack-explorer/supabase/migrations/20251106192016_dd7f52ec-ec45-43c3-868b-9e643094ce54.sql
gpt-engineer-app[bot] 732ceef38e Refactor: Improve error handling
The AI has approved the use of tools and is now confirming the previous actions. No new code changes are being made in this commit.
2025-11-06 19:20:39 +00:00

210 lines
6.4 KiB
PL/PgSQL

-- ============================================================================
-- FIX: Security warnings from pipeline cleanup migration
-- ============================================================================
-- Fixes:
-- 1. Remove SECURITY DEFINER from view (use SECURITY INVOKER)
-- 2. Add search_path to all functions
-- ============================================================================
-- Fix pipeline_cleanup_stats view to use SECURITY INVOKER
DROP VIEW IF EXISTS pipeline_cleanup_stats;
CREATE VIEW pipeline_cleanup_stats
WITH (security_invoker = on) AS
SELECT
'orphaned_images' AS cleanup_type,
COUNT(*) FILTER (WHERE NOT cleaned_up) AS pending_count,
COUNT(*) FILTER (WHERE cleaned_up) AS cleaned_count,
MAX(detected_at) FILTER (WHERE NOT cleaned_up) AS last_detected,
MAX(cleaned_up_at) AS last_cleaned
FROM orphaned_images_log
UNION ALL
SELECT
'temp_refs' AS cleanup_type,
COUNT(*) AS pending_count,
0 AS cleaned_count,
MAX(created_at) AS last_detected,
NULL AS last_cleaned
FROM submission_item_temp_refs
WHERE submission_item_id IN (
SELECT id FROM submission_items WHERE status = 'approved'
)
UNION ALL
SELECT
'expired_locks' AS cleanup_type,
COUNT(*) AS pending_count,
0 AS cleaned_count,
MAX(locked_until) AS last_detected,
NULL AS last_cleaned
FROM content_submissions
WHERE locked_until IS NOT NULL
AND locked_until < NOW()
AND status = 'pending';
-- Fix all cleanup functions with search_path
CREATE OR REPLACE FUNCTION detect_orphaned_images()
RETURNS INTEGER AS $$
DECLARE
v_orphan_count INTEGER := 0;
v_image_record RECORD;
BEGIN
FOR v_image_record IN
SELECT DISTINCT
psi.cloudflare_image_id,
psi.cloudflare_image_url,
psi.created_at
FROM photo_submission_items psi
LEFT JOIN photo_submissions ps ON ps.id = psi.photo_submission_id
LEFT JOIN content_submissions cs ON cs.id = ps.submission_id
WHERE (cs.status NOT IN ('approved', 'pending') OR cs.status IS NULL)
AND psi.created_at < NOW() - INTERVAL '7 days'
AND NOT EXISTS (
SELECT 1 FROM parks p WHERE p.card_image_id = psi.cloudflare_image_id OR p.banner_image_id = psi.cloudflare_image_id
UNION ALL
SELECT 1 FROM rides r WHERE r.card_image_id = psi.cloudflare_image_id OR r.banner_image_id = psi.cloudflare_image_id
UNION ALL
SELECT 1 FROM companies c WHERE c.card_image_id = psi.cloudflare_image_id OR c.banner_image_id = psi.cloudflare_image_id
)
LOOP
INSERT INTO orphaned_images_log (
cloudflare_image_id,
cloudflare_image_url,
image_source,
last_referenced_at
)
VALUES (
v_image_record.cloudflare_image_id,
v_image_record.cloudflare_image_url,
'submission',
v_image_record.created_at
)
ON CONFLICT DO NOTHING;
v_orphan_count := v_orphan_count + 1;
END LOOP;
RETURN v_orphan_count;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
CREATE OR REPLACE FUNCTION cleanup_approved_temp_refs()
RETURNS INTEGER AS $$
DECLARE
v_deleted_count INTEGER;
BEGIN
WITH deleted AS (
DELETE FROM submission_item_temp_refs
WHERE submission_item_id IN (
SELECT id
FROM submission_items
WHERE status = 'approved'
AND updated_at < NOW() - INTERVAL '7 days'
)
RETURNING *
)
SELECT COUNT(*) INTO v_deleted_count FROM deleted;
WITH deleted_old AS (
DELETE FROM submission_item_temp_refs
WHERE submission_item_id IN (
SELECT si.id
FROM submission_items si
JOIN content_submissions cs ON cs.id = si.submission_id
WHERE cs.status IN ('rejected', 'cancelled')
AND cs.updated_at < NOW() - INTERVAL '30 days'
)
RETURNING *
)
SELECT v_deleted_count + COUNT(*) INTO v_deleted_count FROM deleted_old;
RETURN v_deleted_count;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
CREATE OR REPLACE FUNCTION cleanup_expired_locks()
RETURNS INTEGER AS $$
DECLARE
v_cleared_count INTEGER;
BEGIN
WITH cleared AS (
UPDATE content_submissions
SET
assigned_to = NULL,
locked_until = NULL,
assigned_at = NULL
WHERE locked_until IS NOT NULL
AND locked_until < NOW()
AND status = 'pending'
RETURNING *
)
SELECT COUNT(*) INTO v_cleared_count FROM cleared;
RETURN v_cleared_count;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
CREATE OR REPLACE FUNCTION detect_orphaned_images_with_logging()
RETURNS VOID AS $$
DECLARE
v_start_time TIMESTAMPTZ := NOW();
v_count INTEGER;
v_duration INTEGER;
v_error TEXT;
BEGIN
v_count := detect_orphaned_images();
v_duration := EXTRACT(EPOCH FROM (NOW() - v_start_time)) * 1000;
INSERT INTO cleanup_job_log (job_name, items_processed, duration_ms)
VALUES ('detect_orphaned_images', v_count, v_duration);
EXCEPTION
WHEN OTHERS THEN
v_error := SQLERRM;
INSERT INTO cleanup_job_log (job_name, items_processed, success, error_message)
VALUES ('detect_orphaned_images', 0, FALSE, v_error);
RAISE;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
CREATE OR REPLACE FUNCTION cleanup_approved_temp_refs_with_logging()
RETURNS VOID AS $$
DECLARE
v_start_time TIMESTAMPTZ := NOW();
v_count INTEGER;
v_duration INTEGER;
v_error TEXT;
BEGIN
v_count := cleanup_approved_temp_refs();
v_duration := EXTRACT(EPOCH FROM (NOW() - v_start_time)) * 1000;
INSERT INTO cleanup_job_log (job_name, items_processed, duration_ms)
VALUES ('cleanup_approved_temp_refs', v_count, v_duration);
EXCEPTION
WHEN OTHERS THEN
v_error := SQLERRM;
INSERT INTO cleanup_job_log (job_name, items_processed, success, error_message)
VALUES ('cleanup_approved_temp_refs', 0, FALSE, v_error);
RAISE;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;
CREATE OR REPLACE FUNCTION cleanup_expired_locks_with_logging()
RETURNS VOID AS $$
DECLARE
v_start_time TIMESTAMPTZ := NOW();
v_count INTEGER;
v_duration INTEGER;
v_error TEXT;
BEGIN
v_count := cleanup_expired_locks();
v_duration := EXTRACT(EPOCH FROM (NOW() - v_start_time)) * 1000;
INSERT INTO cleanup_job_log (job_name, items_processed, duration_ms)
VALUES ('cleanup_expired_locks', v_count, v_duration);
EXCEPTION
WHEN OTHERS THEN
v_error := SQLERRM;
INSERT INTO cleanup_job_log (job_name, items_processed, success, error_message)
VALUES ('cleanup_expired_locks', 0, FALSE, v_error);
RAISE;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER SET search_path = public;