price_api/procs/guidance_logic.ms.sql

60 lines
2.2 KiB
SQL

CREATE OR ALTER FUNCTION pricing.guidance_logic(
@target numeric(20,5),
@last_norm numeric(20,5),
@list_eff numeric(20,5),
@last_date date,
@floor_pct numeric(10,5) = 0.05, -- e.g., 5%
@cap_last_pct numeric(10,5) = 1.00, -- e.g., 100%
@cap_list_pct numeric(10,5) = 1.00
)
RETURNS TABLE
AS
RETURN
WITH base AS (
SELECT
CAST(CASE WHEN @target IS NULL THEN NULL ELSE @target END AS numeric(20,5)) AS price
), floored AS (
SELECT
CASE WHEN price IS NULL OR @last_norm IS NULL OR @floor_pct<=0
THEN price
ELSE CAST(ROUND(IIF(price>@last_norm*(1-@floor_pct),price,@last_norm*(1-@floor_pct)),5) AS numeric(20,5))
END AS price
FROM base
), cap_last AS (
SELECT
CASE WHEN price IS NULL OR @last_norm IS NULL
THEN price
ELSE CAST(ROUND(IIF(price<@last_norm*@cap_last_pct,price,@last_norm*@cap_last_pct),5) AS numeric(20,5))
END AS price
FROM floored
), cap_list AS (
SELECT
CASE WHEN price IS NULL OR @list_eff IS NULL
THEN price
ELSE CAST(ROUND(IIF(price<@list_eff*@cap_list_pct,price,@list_eff*@cap_list_pct),5) AS numeric(20,5))
END AS price
FROM cap_last
)
SELECT
price AS guidance_price,
CASE
WHEN @target IS NULL THEN 'No target price available'
WHEN @last_norm IS NULL AND @list_eff IS NULL THEN 'No recent sale or list; using target price'
ELSE
CONCAT(
'Using target price',
CASE WHEN @last_norm IS NOT NULL AND @floor_pct>0
THEN CONCAT(', floored to ', FORMAT(@floor_pct*100,'0.##'), '% below last price') ELSE '' END,
CASE WHEN @last_norm IS NOT NULL AND @cap_last_pct<1
THEN CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price')
WHEN @last_norm IS NOT NULL AND @cap_last_pct=1
THEN ', capped to not exceed last price'
ELSE '' END,
CASE WHEN @list_eff IS NOT NULL AND @cap_list_pct<1
THEN CONCAT(', capped to ', FORMAT(@cap_list_pct*100,'0.##'), '% of list price')
WHEN @list_eff IS NOT NULL AND @cap_list_pct=1
THEN ', capped to not exceed list price'
ELSE '' END
)
END AS guidance_reason;