@@ -37,11 +37,55 @@ WHERE dependency.dep_slug = complete_task.step_slug -- parent is the completing
3737LIMIT 1 ;
3838
3939IF v_dependent_map_slug IS NOT NULL THEN
40- RAISE EXCEPTION ' Map step % expects array input but dependency % produced % (output: %)' ,
41- v_dependent_map_slug,
42- complete_task .step_slug ,
43- CASE WHEN complete_task .output IS NULL THEN ' null' ELSE jsonb_typeof(complete_task .output ) END,
44- complete_task .output ;
40+ -- Mark run as failed immediately
41+ UPDATE pgflow .runs
42+ SET status = ' failed' ,
43+ failed_at = now()
44+ WHERE pgflow .runs .run_id = complete_task .run_id ;
45+
46+ -- Archive all queued messages
47+ PERFORM pgmq .archive (r .flow_slug , st .message_id )
48+ FROM pgflow .step_tasks st
49+ JOIN pgflow .runs r ON st .run_id = r .run_id
50+ WHERE st .run_id = complete_task .run_id
51+ AND st .status = ' queued'
52+ AND st .message_id IS NOT NULL ;
53+
54+ -- Mark current task as failed
55+ UPDATE pgflow .step_tasks
56+ SET status = ' failed' ,
57+ failed_at = now(),
58+ error_message = ' [TYPE_VIOLATION] Produced ' ||
59+ CASE WHEN complete_task .output IS NULL THEN ' null'
60+ ELSE jsonb_typeof(complete_task .output ) END ||
61+ ' instead of array'
62+ WHERE pgflow .step_tasks .run_id = complete_task .run_id
63+ AND pgflow .step_tasks .step_slug = complete_task .step_slug
64+ AND pgflow .step_tasks .task_index = complete_task .task_index ;
65+
66+ -- Mark step state as failed
67+ UPDATE pgflow .step_states
68+ SET status = ' failed' ,
69+ failed_at = now(),
70+ error_message = ' [TYPE_VIOLATION] Map step ' || v_dependent_map_slug ||
71+ ' expects array input but dependency ' || complete_task .step_slug ||
72+ ' produced ' || CASE WHEN complete_task .output IS NULL THEN ' null'
73+ ELSE jsonb_typeof(complete_task .output ) END
74+ WHERE pgflow .step_states .run_id = complete_task .run_id
75+ AND pgflow .step_states .step_slug = complete_task .step_slug ;
76+
77+ -- Archive the current task's message (it was started, now failed)
78+ PERFORM pgmq .archive (r .flow_slug , st .message_id )
79+ FROM pgflow .step_tasks st
80+ JOIN pgflow .runs r ON st .run_id = r .run_id
81+ WHERE st .run_id = complete_task .run_id
82+ AND st .step_slug = complete_task .step_slug
83+ AND st .task_index = complete_task .task_index
84+ AND st .message_id IS NOT NULL ;
85+
86+ -- Return empty result
87+ RETURN QUERY SELECT * FROM pgflow .step_tasks WHERE false;
88+ RETURN;
4589END IF;
4690
4791-- ==========================================
0 commit comments