-- Migration: 102_check_working_hours.sql -- Description: Function to check if worker should be available based on working hours -- Created: 2024-12-13 -- Function to check if a worker should be available for work -- Returns TRUE if worker passes the probability check for current hour -- Returns FALSE if worker should sleep/skip this cycle CREATE OR REPLACE FUNCTION check_working_hours( p_worker_id VARCHAR, p_profile_name VARCHAR DEFAULT 'natural_traffic' ) RETURNS TABLE ( is_available BOOLEAN, current_hour INTEGER, hour_weight INTEGER, worker_timezone VARCHAR, roll INTEGER, reason TEXT ) LANGUAGE plpgsql AS $function$ DECLARE v_timezone VARCHAR(50); v_hour INTEGER; v_weight INTEGER; v_dow INTEGER; v_dow_weight INTEGER; v_final_weight INTEGER; v_roll INTEGER; v_hour_weights JSONB; v_dow_weights JSONB; v_profile_enabled BOOLEAN; BEGIN -- Get worker's timezone (from preflight) SELECT wr.timezone INTO v_timezone FROM worker_registry wr WHERE wr.worker_id = p_worker_id; -- Default to America/Phoenix if no timezone set v_timezone := COALESCE(v_timezone, 'America/Phoenix'); -- Get current hour in worker's timezone v_hour := EXTRACT(HOUR FROM NOW() AT TIME ZONE v_timezone)::INTEGER; -- Get day of week (0=Sunday) v_dow := EXTRACT(DOW FROM NOW() AT TIME ZONE v_timezone)::INTEGER; -- Get working hours profile SELECT wh.hour_weights, wh.dow_weights, wh.enabled INTO v_hour_weights, v_dow_weights, v_profile_enabled FROM working_hours wh WHERE wh.name = p_profile_name AND wh.enabled = true; -- If profile not found or disabled, always available IF v_hour_weights IS NULL THEN RETURN QUERY SELECT TRUE::BOOLEAN, v_hour, 100::INTEGER, v_timezone, 0::INTEGER, 'Profile not found or disabled - defaulting to available'::TEXT; RETURN; END IF; -- Get hour weight (default to 50 if hour not specified) v_weight := COALESCE((v_hour_weights->>v_hour::TEXT)::INTEGER, 50); -- Get day-of-week weight (default to 100) v_dow_weight := COALESCE((v_dow_weights->>v_dow::TEXT)::INTEGER, 100); -- Calculate final weight (hour_weight * dow_weight / 100) v_final_weight := (v_weight * v_dow_weight / 100); -- Roll the dice (0-99) v_roll := floor(random() * 100)::INTEGER; -- Return result RETURN QUERY SELECT (v_roll < v_final_weight)::BOOLEAN AS is_available, v_hour AS current_hour, v_final_weight AS hour_weight, v_timezone AS worker_timezone, v_roll AS roll, CASE WHEN v_roll < v_final_weight THEN format('Available: rolled %s < %s%% threshold', v_roll, v_final_weight) ELSE format('Sleeping: rolled %s >= %s%% threshold', v_roll, v_final_weight) END AS reason; END; $function$; -- Simplified version that just returns boolean CREATE OR REPLACE FUNCTION is_worker_available( p_worker_id VARCHAR, p_profile_name VARCHAR DEFAULT 'natural_traffic' ) RETURNS BOOLEAN LANGUAGE plpgsql AS $function$ DECLARE v_result BOOLEAN; BEGIN SELECT is_available INTO v_result FROM check_working_hours(p_worker_id, p_profile_name); RETURN COALESCE(v_result, TRUE); END; $function$; COMMENT ON FUNCTION check_working_hours(VARCHAR, VARCHAR) IS 'Check if worker should be available based on working hours profile. Returns detailed info.'; COMMENT ON FUNCTION is_worker_available(VARCHAR, VARCHAR) IS 'Simple boolean check if worker passes working hours probability roll.';