Due to Docker networking limitations between supabase-db and supabase-edge-functions containers, automatic HTTP triggering of the edge function is not possible. Changes: - Updated cancel_expired_consulting_orders_sql() to also clear calendar_event_id - This prevents stale references in the database - Removed Task 2 dependency documentation (not workable without HTTP access) - Edge function trigger-calendar-cleanup still available for manual triggering To manually clean up Google Calendar events: curl -X POST https://your-project.supabase.co/functions/v1/trigger-calendar-cleanup Coolify Tasks: - Task 1: Keep (works fine with psql) - Task 2: DELETE (HTTP between containers doesn't work) - Task 3: DELETE (deprecated duplicate) 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Sonnet 4.5 <noreply@anthropic.com>
119 lines
4.5 KiB
PL/PgSQL
119 lines
4.5 KiB
PL/PgSQL
-- ============================================
|
|
-- SQL Function for Expired Consulting Orders Cleanup
|
|
-- ============================================
|
|
-- This creates a reusable SQL function that can be called from
|
|
-- Coolify Scheduled Tasks to cancel expired consulting orders
|
|
--
|
|
-- NOTE: We use Coolify for ALL cron jobs (single source of truth)
|
|
-- instead of mixing pg_cron and Coolify scheduled tasks
|
|
|
|
-- Drop existing function if exists (to handle return type change)
|
|
DROP FUNCTION IF EXISTS cancel_expired_consulting_orders_sql();
|
|
|
|
-- Create SQL function to cancel expired orders
|
|
CREATE OR REPLACE FUNCTION cancel_expired_consulting_orders_sql()
|
|
RETURNS jsonb
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
AS $$
|
|
DECLARE
|
|
expired_order RECORD;
|
|
expired_session RECORD;
|
|
processed_count INTEGER := 0;
|
|
calendar_cleanup_count INTEGER := 0;
|
|
BEGIN
|
|
-- Log start
|
|
RAISE NOTICE '[CANCEL-EXPIRED] Starting check for expired consulting orders';
|
|
|
|
-- Loop through expired consulting orders
|
|
FOR expired_order IN
|
|
SELECT o.id, o.payment_status, o.qr_expires_at
|
|
FROM orders o
|
|
INNER JOIN consulting_sessions cs ON cs.order_id = o.id
|
|
WHERE o.payment_status = 'pending'
|
|
AND o.qr_expires_at < NOW()
|
|
AND o.status != 'cancelled'
|
|
LOOP
|
|
RAISE NOTICE '[CANCEL-EXPIRED] Processing order: %', expired_order.id;
|
|
|
|
-- Update order status to cancelled AND payment status to failed
|
|
UPDATE orders
|
|
SET status = 'cancelled',
|
|
payment_status = 'failed'
|
|
WHERE id = expired_order.id;
|
|
|
|
-- Cancel all consulting sessions for this order
|
|
FOR expired_session IN
|
|
SELECT id, calendar_event_id
|
|
FROM consulting_sessions
|
|
WHERE order_id = expired_order.id
|
|
AND status != 'cancelled'
|
|
LOOP
|
|
-- Update session status to cancelled
|
|
UPDATE consulting_sessions
|
|
SET status = 'cancelled'
|
|
WHERE id = expired_session.id;
|
|
|
|
-- Delete time slots to release them for re-booking
|
|
DELETE FROM consulting_time_slots
|
|
WHERE session_id = expired_session.id;
|
|
|
|
-- Clear calendar_event_id to mark for cleanup
|
|
-- Note: The actual Google Calendar event deletion is handled separately
|
|
-- via the trigger-calendar-cleanup edge function (if HTTP access is available)
|
|
IF expired_session.calendar_event_id IS NOT NULL THEN
|
|
UPDATE consulting_sessions
|
|
SET calendar_event_id = NULL
|
|
WHERE id = expired_session.id;
|
|
calendar_cleanup_count := calendar_cleanup_count + 1;
|
|
END IF;
|
|
|
|
RAISE NOTICE '[CANCEL-EXPIRED] Cancelled session: %', expired_session.id;
|
|
END LOOP;
|
|
|
|
processed_count := processed_count + 1;
|
|
END LOOP;
|
|
|
|
RAISE NOTICE '[CANCEL-EXPIRED] Successfully processed % expired orders', processed_count;
|
|
|
|
RETURN jsonb_build_object(
|
|
'success', true,
|
|
'processed', processed_count,
|
|
'calendar_references_cleared', calendar_cleanup_count,
|
|
'message', format('Successfully cancelled %s expired consulting orders (cleared %s calendar references)', processed_count, calendar_cleanup_count)
|
|
);
|
|
END;
|
|
$$;
|
|
|
|
-- ============================================
|
|
-- Coolify Scheduled Tasks Configuration
|
|
-- ============================================
|
|
-- Instead of using pg_cron, configure these in Coolify:
|
|
--
|
|
-- Task 1: Database Cleanup (every 10 minutes)
|
|
-- -------------------------------------------
|
|
-- Name: cancel-expired-consulting-orders-db
|
|
-- Command: psql -h supabase-db -U postgres -d postgres -c "SELECT cancel_expired_consulting_orders_sql();"
|
|
-- Frequency: */10 * * * *
|
|
-- Timeout: 30 seconds
|
|
-- Container: supabase-db (or supabase-rest if it has psql client)
|
|
--
|
|
-- NOTE: Calendar cleanup is now included in the SQL function above.
|
|
-- The function clears calendar_event_id references to prevent stale data.
|
|
-- Actual Google Calendar event deletion can be triggered manually via:
|
|
-- curl -X POST http://your-domain/functions/v1/trigger-calendar-cleanup
|
|
--
|
|
-- Task 2 (DEPRECATED): Calendar cleanup edge function
|
|
-- -------------------------------------------
|
|
-- Due to Docker networking limitations between containers, we cannot
|
|
-- automatically trigger the edge function from the scheduled task.
|
|
-- The SQL function now handles cleanup of database references.
|
|
-- To manually clean up Google Calendar events, trigger the edge function:
|
|
-- POST http://your-supabase-project.supabase.co/functions/v1/trigger-calendar-cleanup
|
|
|
|
-- ============================================
|
|
-- Manual Testing
|
|
-- ============================================
|
|
-- Test the function directly:
|
|
-- SELECT cancel_expired_consulting_orders_sql();
|