price_api/procs/guidance_logic.pg.sql

70 lines
2.5 KiB
PL/PgSQL

CREATE OR REPLACE FUNCTION pricequote.guidance_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.05,
_cap_last_pct numeric(10,5) DEFAULT 1.00,
_cap_list_pct numeric(10,5) DEFAULT 1.00
)
RETURNS TABLE (guidance_price numeric(20,5), guidance_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
IF _target IS NULL THEN
RETURN QUERY SELECT NULL::numeric, 'No target price available';
RETURN;
END IF;
base_price := _target;
-- floor (binds if it raises price)
after_floor := base_price;
IF _last_norm IS NOT NULL AND _floor_pct > 0 THEN
after_floor := GREATEST(base_price, ROUND(_last_norm*(1-_floor_pct),5));
END IF;
-- cap to last (binds if it lowers 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;
-- build reason
IF _last_norm IS NULL AND _list_eff IS NULL THEN
reason := 'No prior sale or list; using target price';
ELSE
reason := 'Using target price';
IF _last_norm IS NOT NULL AND _floor_pct > 0 AND after_floor > base_price THEN
reason := reason || format(', floored to %s%% below last price', to_char((_floor_pct*100)::numeric,'FM999990.##'));
END IF;
IF _last_norm IS NOT NULL AND after_cap_last < after_floor THEN
IF _cap_last_pct = 1 THEN
reason := reason || ', capped to not exceed last price';
ELSE
reason := reason || format(', capped to %s%% of last price', to_char((_cap_last_pct*100)::numeric,'FM999990.##'));
END IF;
END IF;
IF _list_eff IS NOT NULL AND final_price < after_cap_last THEN
IF _cap_list_pct = 1 THEN
reason := reason || ', capped to not exceed list price';
ELSE
reason := reason || format(', capped to %s%% of list price', to_char((_cap_list_pct*100)::numeric,'FM999990.##'));
END IF;
END IF;
END IF;
RETURN QUERY SELECT final_price, reason;
END $$;