-- Migration: 101_worker_preflight_timezone.sql -- Description: Update update_worker_preflight to extract timezone from fingerprint -- Created: 2024-12-13 CREATE OR REPLACE FUNCTION public.update_worker_preflight( p_worker_id character varying, p_transport character varying, p_status character varying, p_ip character varying DEFAULT NULL, p_response_ms integer DEFAULT NULL, p_error text DEFAULT NULL, p_fingerprint jsonb DEFAULT NULL ) RETURNS void LANGUAGE plpgsql AS $function$ DECLARE v_curl_status VARCHAR(20); v_http_status VARCHAR(20); v_overall_status VARCHAR(20); v_timezone VARCHAR(50); BEGIN IF p_transport = 'curl' THEN UPDATE worker_registry SET preflight_curl_status = p_status, preflight_curl_at = NOW(), preflight_curl_ms = p_response_ms, preflight_curl_error = p_error, curl_ip = p_ip, updated_at = NOW() WHERE worker_id = p_worker_id; ELSIF p_transport = 'http' THEN -- Extract timezone from fingerprint JSON if present v_timezone := p_fingerprint->>'detectedTimezone'; UPDATE worker_registry SET preflight_http_status = p_status, preflight_http_at = NOW(), preflight_http_ms = p_response_ms, preflight_http_error = p_error, http_ip = p_ip, fingerprint_data = COALESCE(p_fingerprint, fingerprint_data), -- Save extracted timezone timezone = COALESCE(v_timezone, timezone), updated_at = NOW() WHERE worker_id = p_worker_id; END IF; -- Update overall preflight status SELECT preflight_curl_status, preflight_http_status INTO v_curl_status, v_http_status FROM worker_registry WHERE worker_id = p_worker_id; -- Compute overall status IF v_curl_status = 'passed' AND v_http_status = 'passed' THEN v_overall_status := 'passed'; ELSIF v_curl_status = 'passed' OR v_http_status = 'passed' THEN v_overall_status := 'partial'; ELSIF v_curl_status = 'failed' OR v_http_status = 'failed' THEN v_overall_status := 'failed'; ELSE v_overall_status := 'pending'; END IF; UPDATE worker_registry SET preflight_status = v_overall_status, preflight_at = NOW() WHERE worker_id = p_worker_id; END; $function$; COMMENT ON FUNCTION update_worker_preflight(varchar, varchar, varchar, varchar, integer, text, jsonb) IS 'Updates worker preflight status and extracts timezone from fingerprint for working hours';