-- Create a SQL function to mark sessions for calendar cleanup -- This works with psql (which is available in the database container) CREATE OR REPLACE FUNCTION mark_calendar_cleanup_sql() RETURNS jsonb LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE cancelled_session RECORD; marked_count INTEGER := 0; BEGIN RAISE NOTICE '[CALENDAR-CLEANUP] Marking cancelled sessions for calendar cleanup'; -- Create a table to track sessions that need calendar cleanup CREATE TABLE IF NOT EXISTS calendar_cleanup_queue ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), session_id UUID NOT NULL, calendar_event_id TEXT NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), processed BOOLEAN DEFAULT FALSE ); -- Find cancelled sessions with calendar events that haven't been marked yet FOR cancelled_session IN SELECT id, calendar_event_id FROM consulting_sessions WHERE status = 'cancelled' AND calendar_event_id IS NOT NULL AND id NOT IN (SELECT session_id FROM calendar_cleanup_queue WHERE processed = TRUE) LOOP -- Mark for cleanup INSERT INTO calendar_cleanup_queue (session_id, calendar_event_id) VALUES (cancelled_session.id, cancelled_session.calendar_event_id); -- Clear the calendar_event_id from the session (we've saved it in the queue) UPDATE consulting_sessions SET calendar_event_id = NULL WHERE id = cancelled_session.id; marked_count := marked_count + 1; RAISE NOTICE '[CALENDAR-CLEANUP] Marked session for cleanup: %', cancelled_session.id; END LOOP; RAISE NOTICE '[CALENDAR-CLEANUP] Marked % sessions for calendar cleanup', marked_count; RETURN jsonb_build_object( 'success', true, 'processed', marked_count, 'message', format('Marked %s sessions for calendar cleanup', marked_count) ); END; $$; -- Grant permissions GRANT EXECUTE ON FUNCTION mark_calendar_cleanup_sql() TO postgres; GRANT ALL ON TABLE calendar_cleanup_queue TO postgres;