mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-22 12:31:12 -05:00
326 lines
11 KiB
PL/PgSQL
326 lines
11 KiB
PL/PgSQL
-- ============================================================================
|
|
-- PHASE 2: AUTOMATED CLEANUP JOBS - Sacred Pipeline Maintenance
|
|
-- ============================================================================
|
|
-- 1. Create cleanup_abandoned_locks function
|
|
-- 2. Create cleanup_old_submissions function
|
|
-- 3. Create wrapper function to run all cleanup jobs
|
|
-- ============================================================================
|
|
|
|
-- ============================================================================
|
|
-- 1. CLEANUP ABANDONED LOCKS
|
|
-- ============================================================================
|
|
|
|
CREATE OR REPLACE FUNCTION cleanup_abandoned_locks()
|
|
RETURNS TABLE (
|
|
released_count INTEGER,
|
|
lock_details JSONB
|
|
)
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_released_count INTEGER;
|
|
v_lock_details JSONB;
|
|
v_deleted_user_locks INTEGER := 0;
|
|
v_banned_user_locks INTEGER := 0;
|
|
v_expired_locks INTEGER := 0;
|
|
BEGIN
|
|
-- Capture locks from deleted users (users no longer in auth.users)
|
|
WITH deleted_user_locks AS (
|
|
SELECT
|
|
cs.id as submission_id,
|
|
cs.assigned_to as moderator_id,
|
|
cs.locked_until,
|
|
'deleted_user' as reason
|
|
FROM content_submissions cs
|
|
WHERE cs.assigned_to IS NOT NULL
|
|
AND NOT EXISTS (
|
|
SELECT 1 FROM auth.users au WHERE au.id = cs.assigned_to
|
|
)
|
|
),
|
|
-- Capture locks from banned users
|
|
banned_user_locks AS (
|
|
SELECT
|
|
cs.id as submission_id,
|
|
cs.assigned_to as moderator_id,
|
|
cs.locked_until,
|
|
'banned_user' as reason
|
|
FROM content_submissions cs
|
|
JOIN profiles p ON p.user_id = cs.assigned_to
|
|
WHERE cs.assigned_to IS NOT NULL
|
|
AND p.banned = true
|
|
),
|
|
-- Release locks from deleted users
|
|
release_deleted AS (
|
|
UPDATE content_submissions cs
|
|
SET
|
|
assigned_to = NULL,
|
|
assigned_at = NULL,
|
|
locked_until = NULL
|
|
WHERE cs.assigned_to IS NOT NULL
|
|
AND NOT EXISTS (
|
|
SELECT 1 FROM auth.users au WHERE au.id = cs.assigned_to
|
|
)
|
|
RETURNING cs.id
|
|
),
|
|
-- Release locks from banned users
|
|
release_banned AS (
|
|
UPDATE content_submissions cs
|
|
SET
|
|
assigned_to = NULL,
|
|
assigned_at = NULL,
|
|
locked_until = NULL
|
|
FROM profiles p
|
|
WHERE cs.assigned_to = p.user_id
|
|
AND cs.assigned_to IS NOT NULL
|
|
AND p.banned = true
|
|
RETURNING cs.id
|
|
),
|
|
-- Release expired locks (locked_until in past)
|
|
release_expired AS (
|
|
UPDATE content_submissions
|
|
SET
|
|
assigned_to = NULL,
|
|
assigned_at = NULL,
|
|
locked_until = NULL
|
|
WHERE assigned_to IS NOT NULL
|
|
AND locked_until < NOW()
|
|
AND status IN ('pending', 'partially_approved')
|
|
RETURNING id
|
|
)
|
|
SELECT
|
|
(SELECT COUNT(*) FROM release_deleted) +
|
|
(SELECT COUNT(*) FROM release_banned) +
|
|
(SELECT COUNT(*) FROM release_expired),
|
|
jsonb_build_object(
|
|
'deleted_user_locks', (SELECT COUNT(*) FROM release_deleted),
|
|
'banned_user_locks', (SELECT COUNT(*) FROM release_banned),
|
|
'expired_locks', (SELECT COUNT(*) FROM release_expired)
|
|
)
|
|
INTO v_released_count, v_lock_details;
|
|
|
|
RAISE NOTICE 'Released % abandoned locks: %', v_released_count, v_lock_details;
|
|
|
|
RETURN QUERY SELECT v_released_count, v_lock_details;
|
|
END;
|
|
$$;
|
|
|
|
GRANT EXECUTE ON FUNCTION cleanup_abandoned_locks TO authenticated;
|
|
|
|
COMMENT ON FUNCTION cleanup_abandoned_locks IS
|
|
'Releases locks from deleted users, banned users, and expired lock times. Returns count and breakdown of released locks. Run via pg_cron or scheduled job.';
|
|
|
|
-- ============================================================================
|
|
-- 2. CLEANUP OLD SUBMISSIONS
|
|
-- ============================================================================
|
|
|
|
CREATE OR REPLACE FUNCTION cleanup_old_submissions(
|
|
p_retention_days INTEGER DEFAULT 90
|
|
)
|
|
RETURNS TABLE (
|
|
deleted_count INTEGER,
|
|
deleted_by_status JSONB,
|
|
oldest_deleted_date TIMESTAMPTZ
|
|
)
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_deleted_count INTEGER;
|
|
v_status_breakdown JSONB;
|
|
v_oldest_date TIMESTAMPTZ;
|
|
BEGIN
|
|
-- Capture oldest submission before deletion
|
|
SELECT MIN(created_at) INTO v_oldest_date
|
|
FROM content_submissions
|
|
WHERE created_at < NOW() - (p_retention_days || ' days')::INTERVAL
|
|
AND status IN ('approved', 'rejected')
|
|
AND is_test_data = false;
|
|
|
|
-- Count by status before deletion
|
|
WITH status_counts AS (
|
|
SELECT
|
|
status,
|
|
COUNT(*) as count
|
|
FROM content_submissions
|
|
WHERE created_at < NOW() - (p_retention_days || ' days')::INTERVAL
|
|
AND status IN ('approved', 'rejected')
|
|
AND is_test_data = false
|
|
GROUP BY status
|
|
)
|
|
SELECT jsonb_object_agg(status, count)
|
|
INTO v_status_breakdown
|
|
FROM status_counts;
|
|
|
|
-- Delete old approved/rejected submissions (CASCADE will delete related records)
|
|
DELETE FROM content_submissions
|
|
WHERE created_at < NOW() - (p_retention_days || ' days')::INTERVAL
|
|
AND status IN ('approved', 'rejected')
|
|
AND is_test_data = false;
|
|
|
|
GET DIAGNOSTICS v_deleted_count = ROW_COUNT;
|
|
|
|
-- Log the cleanup
|
|
RAISE NOTICE 'Deleted % old submissions (older than % days): %',
|
|
v_deleted_count, p_retention_days, v_status_breakdown;
|
|
|
|
RETURN QUERY SELECT
|
|
v_deleted_count,
|
|
COALESCE(v_status_breakdown, '{}'::jsonb),
|
|
v_oldest_date;
|
|
END;
|
|
$$;
|
|
|
|
GRANT EXECUTE ON FUNCTION cleanup_old_submissions TO authenticated;
|
|
|
|
COMMENT ON FUNCTION cleanup_old_submissions IS
|
|
'Deletes approved and rejected submissions older than retention period (default 90 days). Preserves pending submissions and test data. Returns count, status breakdown, and oldest deletion date.';
|
|
|
|
-- ============================================================================
|
|
-- 3. MASTER CLEANUP FUNCTION (Runs all cleanup tasks)
|
|
-- ============================================================================
|
|
|
|
CREATE OR REPLACE FUNCTION run_all_cleanup_jobs()
|
|
RETURNS JSONB
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $$
|
|
DECLARE
|
|
v_start_time TIMESTAMPTZ;
|
|
v_results JSONB := '{}'::jsonb;
|
|
v_idempotency_deleted INTEGER;
|
|
v_temp_refs_result RECORD;
|
|
v_locks_result RECORD;
|
|
v_submissions_result RECORD;
|
|
BEGIN
|
|
v_start_time := clock_timestamp();
|
|
|
|
RAISE NOTICE 'Starting automated cleanup jobs at %', v_start_time;
|
|
|
|
-- 1. Cleanup expired idempotency keys
|
|
BEGIN
|
|
SELECT cleanup_expired_idempotency_keys() INTO v_idempotency_deleted;
|
|
v_results := v_results || jsonb_build_object(
|
|
'idempotency_keys', jsonb_build_object(
|
|
'deleted', v_idempotency_deleted,
|
|
'success', true
|
|
)
|
|
);
|
|
RAISE NOTICE '✓ Cleaned up % expired idempotency keys', v_idempotency_deleted;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_results := v_results || jsonb_build_object(
|
|
'idempotency_keys', jsonb_build_object(
|
|
'success', false,
|
|
'error', SQLERRM
|
|
)
|
|
);
|
|
RAISE WARNING '✗ Failed to cleanup idempotency keys: %', SQLERRM;
|
|
END;
|
|
|
|
-- 2. Cleanup stale temp refs (30 days old)
|
|
BEGIN
|
|
SELECT * INTO v_temp_refs_result FROM cleanup_stale_temp_refs(30);
|
|
v_results := v_results || jsonb_build_object(
|
|
'temp_refs', jsonb_build_object(
|
|
'deleted', v_temp_refs_result.deleted_count,
|
|
'oldest_date', v_temp_refs_result.oldest_deleted_date,
|
|
'success', true
|
|
)
|
|
);
|
|
RAISE NOTICE '✓ Cleaned up % stale temp refs', v_temp_refs_result.deleted_count;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_results := v_results || jsonb_build_object(
|
|
'temp_refs', jsonb_build_object(
|
|
'success', false,
|
|
'error', SQLERRM
|
|
)
|
|
);
|
|
RAISE WARNING '✗ Failed to cleanup temp refs: %', SQLERRM;
|
|
END;
|
|
|
|
-- 3. Cleanup abandoned locks
|
|
BEGIN
|
|
SELECT * INTO v_locks_result FROM cleanup_abandoned_locks();
|
|
v_results := v_results || jsonb_build_object(
|
|
'locks', jsonb_build_object(
|
|
'released', v_locks_result.released_count,
|
|
'details', v_locks_result.lock_details,
|
|
'success', true
|
|
)
|
|
);
|
|
RAISE NOTICE '✓ Released % abandoned locks', v_locks_result.released_count;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_results := v_results || jsonb_build_object(
|
|
'locks', jsonb_build_object(
|
|
'success', false,
|
|
'error', SQLERRM
|
|
)
|
|
);
|
|
RAISE WARNING '✗ Failed to cleanup locks: %', SQLERRM;
|
|
END;
|
|
|
|
-- 4. Cleanup old submissions (90 days retention)
|
|
BEGIN
|
|
SELECT * INTO v_submissions_result FROM cleanup_old_submissions(90);
|
|
v_results := v_results || jsonb_build_object(
|
|
'old_submissions', jsonb_build_object(
|
|
'deleted', v_submissions_result.deleted_count,
|
|
'by_status', v_submissions_result.deleted_by_status,
|
|
'oldest_date', v_submissions_result.oldest_deleted_date,
|
|
'success', true
|
|
)
|
|
);
|
|
RAISE NOTICE '✓ Deleted % old submissions', v_submissions_result.deleted_count;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_results := v_results || jsonb_build_object(
|
|
'old_submissions', jsonb_build_object(
|
|
'success', false,
|
|
'error', SQLERRM
|
|
)
|
|
);
|
|
RAISE WARNING '✗ Failed to cleanup old submissions: %', SQLERRM;
|
|
END;
|
|
|
|
-- Add execution summary
|
|
v_results := v_results || jsonb_build_object(
|
|
'execution', jsonb_build_object(
|
|
'started_at', v_start_time,
|
|
'completed_at', clock_timestamp(),
|
|
'duration_ms', EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000
|
|
)
|
|
);
|
|
|
|
RAISE NOTICE 'Completed all cleanup jobs in % ms',
|
|
EXTRACT(EPOCH FROM (clock_timestamp() - v_start_time)) * 1000;
|
|
|
|
RETURN v_results;
|
|
END;
|
|
$$;
|
|
|
|
GRANT EXECUTE ON FUNCTION run_all_cleanup_jobs TO authenticated;
|
|
|
|
COMMENT ON FUNCTION run_all_cleanup_jobs IS
|
|
'Master cleanup function that runs all maintenance tasks: idempotency keys, temp refs, abandoned locks, and old submissions. Returns detailed execution results. Should be called daily via pg_cron.';
|
|
|
|
-- ============================================================================
|
|
-- COMPLETION SUMMARY
|
|
-- ============================================================================
|
|
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE '============================================================';
|
|
RAISE NOTICE '✅ PHASE 2: AUTOMATED CLEANUP JOBS COMPLETE';
|
|
RAISE NOTICE '============================================================';
|
|
RAISE NOTICE '1. ✅ cleanup_expired_idempotency_keys (already existed)';
|
|
RAISE NOTICE '2. ✅ cleanup_stale_temp_refs (already existed)';
|
|
RAISE NOTICE '3. ✅ cleanup_abandoned_locks (NEW)';
|
|
RAISE NOTICE '4. ✅ cleanup_old_submissions (NEW)';
|
|
RAISE NOTICE '5. ✅ run_all_cleanup_jobs (NEW - master function)';
|
|
RAISE NOTICE '============================================================';
|
|
RAISE NOTICE '📋 NEXT STEP: Schedule via pg_cron';
|
|
RAISE NOTICE ' Run: SELECT * FROM run_all_cleanup_jobs();';
|
|
RAISE NOTICE '============================================================';
|
|
END $$; |