-- broker_run function -- Executes a job by its ID -- Returns: p_retval (0=success, >0=error), p_errmsg (error message) CREATE OR REPLACE FUNCTION broker_run( p_job_id BIGINT, OUT p_retval INTEGER, OUT p_errmsg TEXT ) RETURNS RECORD LANGUAGE plpgsql AS $$ DECLARE v_job_record RECORD; v_execute_result TEXT; v_error_occurred BOOLEAN := false; BEGIN p_retval := 0; p_errmsg := ''; v_execute_result := ''; -- Validate job ID IF p_job_id IS NULL OR p_job_id <= 0 THEN p_retval := 1; p_errmsg := 'Invalid job ID'; RETURN; END IF; -- Get job details SELECT id_broker_jobs, execute_str, job_language, run_as, complete_status INTO v_job_record FROM broker_jobs WHERE id_broker_jobs = p_job_id FOR UPDATE; -- Check if job exists IF NOT FOUND THEN p_retval := 2; p_errmsg := 'Job not found'; RETURN; END IF; -- Check if job is in running state IF v_job_record.complete_status != 1 THEN p_retval := 3; p_errmsg := format('Job is not in running state (status: %s)', v_job_record.complete_status); RETURN; END IF; -- Execute the job BEGIN -- For SQL/PLPGSQL jobs, execute directly IF v_job_record.job_language IN ('sql', 'plpgsql') THEN EXECUTE v_job_record.execute_str; v_execute_result := 'Success'; ELSE -- Other languages would need external execution p_retval := 4; p_errmsg := format('Unsupported job language: %s', v_job_record.job_language); v_error_occurred := true; END IF; EXCEPTION WHEN OTHERS THEN v_error_occurred := true; p_retval := 5; p_errmsg := SQLERRM; v_execute_result := format('Error: %s', SQLERRM); END; -- Update job with results IF v_error_occurred THEN UPDATE broker_jobs SET complete_status = 3, -- failed error_msg = p_errmsg, execute_result = v_execute_result, completed_at = NOW(), updated_at = NOW() WHERE id_broker_jobs = p_job_id; ELSE UPDATE broker_jobs SET complete_status = 2, -- completed execute_result = v_execute_result, error_msg = NULL, completed_at = NOW(), updated_at = NOW() WHERE id_broker_jobs = p_job_id; END IF; EXCEPTION WHEN OTHERS THEN p_retval := 6; p_errmsg := SQLERRM; RAISE WARNING 'broker_run error: %', SQLERRM; -- Try to update job status to failed BEGIN UPDATE broker_jobs SET complete_status = 3, -- failed error_msg = SQLERRM, completed_at = NOW(), updated_at = NOW() WHERE id_broker_jobs = p_job_id; EXCEPTION WHEN OTHERS THEN -- Ignore update errors NULL; END; END; $$; -- Comments COMMENT ON FUNCTION broker_run IS 'Executes a job by its ID and updates the status';