feat: Create stale temp refs cleanup function

This commit is contained in:
gpt-engineer-app[bot]
2025-11-05 18:33:58 +00:00
parent b0ff952318
commit 18d28a1fc8
2 changed files with 55 additions and 0 deletions

View File

@@ -5602,6 +5602,13 @@ export type Database = {
}
cleanup_orphaned_submissions: { Args: never; Returns: number }
cleanup_rate_limits: { Args: never; Returns: undefined }
cleanup_stale_temp_refs: {
Args: { p_age_days?: number }
Returns: {
deleted_count: number
oldest_deleted_date: string
}[]
}
create_submission_with_items: {
Args: {
p_content: Json

View File

@@ -0,0 +1,48 @@
-- Create function to clean up stale temporary submission references
-- These are temp refs that should have been deleted during submission approval/rejection
-- but weren't due to errors, crashes, or edge cases
CREATE OR REPLACE FUNCTION public.cleanup_stale_temp_refs(
p_age_days INTEGER DEFAULT 30
)
RETURNS TABLE (
deleted_count INTEGER,
oldest_deleted_date TIMESTAMPTZ
)
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public'
AS $$
DECLARE
v_deleted_count INTEGER;
v_oldest_date TIMESTAMPTZ;
BEGIN
-- Capture oldest ref before deletion for logging
SELECT MIN(created_at) INTO v_oldest_date
FROM submission_item_temp_refs
WHERE created_at < NOW() - (p_age_days || ' days')::INTERVAL;
-- Delete stale temp refs older than p_age_days
DELETE FROM submission_item_temp_refs
WHERE created_at < NOW() - (p_age_days || ' days')::INTERVAL;
GET DIAGNOSTICS v_deleted_count = ROW_COUNT;
-- Return results for logging/monitoring
RETURN QUERY SELECT v_deleted_count, v_oldest_date;
-- Log the cleanup operation
RAISE NOTICE 'Cleaned up % stale temp refs older than % days (oldest: %)',
v_deleted_count, p_age_days, v_oldest_date;
END;
$$;
COMMENT ON FUNCTION public.cleanup_stale_temp_refs IS
'Deletes temporary submission references older than specified days (default 30). Returns deleted count and oldest deletion date. Should be run via pg_cron or manually for maintenance.';
-- Grant execute permission to authenticated users (moderators will use this)
GRANT EXECUTE ON FUNCTION public.cleanup_stale_temp_refs TO authenticated;
-- Example usage:
-- SELECT * FROM cleanup_stale_temp_refs(); -- Default 30 days
-- SELECT * FROM cleanup_stale_temp_refs(7); -- Aggressive 7 day cleanup