CREATE OR REPLACE FUNCTION pricequote.approval_logic( _target numeric(20,5), _last_norm numeric(20,5), _list_eff numeric(20,5), _last_date date, _floor_pct numeric(10,5) DEFAULT 0.95, _cap_last_pct numeric(10,5) DEFAULT 1.00, _cap_list_pct numeric(10,5) DEFAULT 1.00 ) RETURNS TABLE ( approval_price numeric(20,5), approval_reason text ) LANGUAGE plpgsql AS $$ DECLARE base_price numeric(20,5); after_floor numeric(20,5); after_cap_last numeric(20,5); final_price numeric(20,5); reason text := ''; BEGIN -- Early exit if nothing to work with IF _target IS NULL AND _last_norm IS NULL AND _list_eff IS NULL THEN RETURN QUERY SELECT NULL::numeric, 'No target, last, or list available'; RETURN; END IF; -- Pick starting base price base_price := COALESCE(_target, _last_norm, _list_eff); -- Step 1: use base price unless it's more than x% below last price after_floor := base_price; IF _last_norm IS NOT NULL THEN after_floor := GREATEST(base_price, ROUND(_last_norm*_floor_pct,5)); END IF; -- Step 2: use price from previous step but don't allow it to be x% above last price after_cap_last := after_floor; IF _last_norm IS NOT NULL THEN after_cap_last := LEAST(after_floor, ROUND(_last_norm*_cap_last_pct,5)); END IF; -- cap to list (binds if it lowers price) final_price := after_cap_last; IF _list_eff IS NOT NULL THEN final_price := LEAST(after_cap_last, ROUND(_list_eff*_cap_list_pct,5)); END IF; -- Reason text reason := CASE WHEN _target IS NOT NULL THEN 'Using target price' WHEN _last_norm IS NOT NULL THEN 'Using last price as base' WHEN _list_eff IS NOT NULL THEN 'Using list price as base' END; IF _last_norm IS NOT NULL AND after_floor > base_price THEN reason := 'Last price drop limit'; END IF; IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN reason := 'Last price increase limit'; END IF; IF _list_eff IS NOT NULL AND final_price < after_cap_last THEN reason := 'List price ceiling'; END IF; RETURN QUERY SELECT final_price, reason; END $$;