CREATE OR REPLACE FUNCTION pricequote.guidance_logic( _target_price NUMERIC(20,5), _last_price NUMERIC(20,5), _list_price NUMERIC(20,5), _last_date DATE ) RETURNS TABLE ( guidance_price NUMERIC(20,5), guidance_reason TEXT ) AS $$ DECLARE _price NUMERIC(20,5); _reason TEXT := ''; _floored NUMERIC(20,5); _capped NUMERIC(20,5); _is_last_recent BOOLEAN := _last_date IS NOT NULL AND _last_date > CURRENT_DATE - INTERVAL '2 years'; BEGIN IF _target_price IS NOT NULL AND _last_price IS NOT NULL AND _is_last_recent THEN _floored := GREATEST(_target_price, _last_price * 0.95); _capped := LEAST(_floored, _last_price); _price := LEAST(COALESCE(_list_price, 1e9), _capped); IF _price = _last_price THEN _reason := 'Cap at last price'; ELSE _reason := 'Using target price'; IF _target_price < _last_price * 0.95 THEN _reason := _reason || ', floored to 5% below last price'; END IF; IF _target_price > _last_price THEN _reason := _reason || ', capped to not exceed last price'; END IF; IF _list_price IS NOT NULL AND _price = _list_price AND _target_price > _list_price THEN _reason := _reason || ', capped to not exceed list price'; END IF; END IF; ELSIF _last_price IS NOT NULL AND _is_last_recent THEN _price := _last_price; _reason := 'Last price - no target'; ELSIF _target_price IS NOT NULL THEN _price := _target_price; _reason := 'Target price - no prior sale'; ELSE _price := NULL; _reason := 'No pricing available'; END IF; RETURN QUERY SELECT _price, _reason; END; $$ LANGUAGE plpgsql;