cap at ceiling not working becuase _eff list was being set to null
This commit is contained in:
parent
ccf50036ca
commit
f1d4d8a60b
@ -10,50 +10,74 @@ CREATE OR ALTER FUNCTION pricing.guidance_logic(
|
|||||||
RETURNS TABLE
|
RETURNS TABLE
|
||||||
AS
|
AS
|
||||||
RETURN
|
RETURN
|
||||||
WITH base AS (
|
WITH params AS (
|
||||||
SELECT
|
SELECT
|
||||||
CAST(CASE WHEN @target IS NULL THEN NULL ELSE @target END AS numeric(20,5)) AS price
|
@target AS base_price,
|
||||||
), floored AS (
|
@last_norm AS last_norm,
|
||||||
|
@list_eff AS list_eff,
|
||||||
|
@floor_pct AS floor_pct,
|
||||||
|
@cap_last_pct AS cap_last_pct,
|
||||||
|
-- HARD CEILING at list: clamp to <= 1.00 regardless of input
|
||||||
|
CASE WHEN @cap_list_pct IS NULL OR @cap_list_pct > 1 THEN 1.00 ELSE @cap_list_pct END AS eff_list_cap
|
||||||
|
),
|
||||||
|
step_floor AS (
|
||||||
SELECT
|
SELECT
|
||||||
CASE WHEN price IS NULL OR @last_norm IS NULL OR @floor_pct<=0
|
base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap,
|
||||||
THEN price
|
CAST(
|
||||||
ELSE CAST(ROUND(IIF(price>@last_norm*(1-@floor_pct),price,@last_norm*(1-@floor_pct)),5) AS numeric(20,5))
|
CASE
|
||||||
END AS price
|
WHEN base_price IS NULL OR last_norm IS NULL OR floor_pct <= 0
|
||||||
FROM base
|
THEN base_price
|
||||||
), cap_last AS (
|
ELSE ROUND(IIF(base_price >= last_norm*(1-floor_pct), base_price, last_norm*(1-floor_pct)), 5)
|
||||||
|
END
|
||||||
|
AS numeric(20,5)) AS after_floor
|
||||||
|
FROM params
|
||||||
|
),
|
||||||
|
step_cap_last AS (
|
||||||
SELECT
|
SELECT
|
||||||
CASE WHEN price IS NULL OR @last_norm IS NULL
|
base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, after_floor,
|
||||||
THEN price
|
CAST(
|
||||||
ELSE CAST(ROUND(IIF(price<@last_norm*@cap_last_pct,price,@last_norm*@cap_last_pct),5) AS numeric(20,5))
|
CASE
|
||||||
END AS price
|
WHEN after_floor IS NULL OR last_norm IS NULL
|
||||||
FROM floored
|
THEN after_floor
|
||||||
), cap_list AS (
|
ELSE ROUND(IIF(after_floor <= last_norm*cap_last_pct, after_floor, last_norm*cap_last_pct), 5)
|
||||||
|
END
|
||||||
|
AS numeric(20,5)) AS after_cap_last
|
||||||
|
FROM step_floor
|
||||||
|
),
|
||||||
|
step_cap_list AS (
|
||||||
SELECT
|
SELECT
|
||||||
CASE WHEN price IS NULL OR @list_eff IS NULL
|
base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, after_floor, after_cap_last,
|
||||||
THEN price
|
CAST(
|
||||||
ELSE CAST(ROUND(IIF(price<@list_eff*@cap_list_pct,price,@list_eff*@cap_list_pct),5) AS numeric(20,5))
|
CASE
|
||||||
END AS price
|
WHEN after_cap_last IS NULL OR list_eff IS NULL
|
||||||
FROM cap_last
|
THEN after_cap_last
|
||||||
|
ELSE ROUND(IIF(after_cap_last <= list_eff*eff_list_cap, after_cap_last, list_eff*eff_list_cap), 5)
|
||||||
|
END
|
||||||
|
AS numeric(20,5)) AS final_price
|
||||||
|
FROM step_cap_last
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
price AS guidance_price,
|
final_price AS guidance_price,
|
||||||
CASE
|
CASE
|
||||||
WHEN @target IS NULL THEN 'No target price available'
|
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'
|
WHEN @last_norm IS NULL AND @list_eff IS NULL THEN 'No prior sale or list; using target price'
|
||||||
ELSE
|
ELSE
|
||||||
CONCAT(
|
CONCAT(
|
||||||
'Using target price',
|
'Using target price',
|
||||||
CASE WHEN @last_norm IS NOT NULL AND @floor_pct>0
|
-- show floor only if it raised price
|
||||||
|
CASE WHEN last_norm IS NOT NULL AND @floor_pct > 0 AND after_floor > base_price
|
||||||
THEN CONCAT(', floored to ', FORMAT(@floor_pct*100,'0.##'), '% below last price') ELSE '' END,
|
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
|
-- show last cap only if it lowered price
|
||||||
THEN CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price')
|
CASE WHEN last_norm IS NOT NULL AND after_cap_last < after_floor
|
||||||
WHEN @last_norm IS NOT NULL AND @cap_last_pct=1
|
THEN CASE WHEN @cap_last_pct = 1
|
||||||
THEN ', capped to not exceed last price'
|
THEN ', capped to not exceed last price'
|
||||||
|
ELSE CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price')
|
||||||
|
END
|
||||||
ELSE '' END,
|
ELSE '' END,
|
||||||
CASE WHEN @list_eff IS NOT NULL AND @cap_list_pct<1
|
-- show list cap only if it lowered price (always “not exceed” because eff_list_cap<=1)
|
||||||
THEN CONCAT(', capped to ', FORMAT(@cap_list_pct*100,'0.##'), '% of list price')
|
CASE WHEN list_eff IS NOT NULL AND final_price < after_cap_last
|
||||||
WHEN @list_eff IS NOT NULL AND @cap_list_pct=1
|
|
||||||
THEN ', capped to not exceed list price'
|
THEN ', capped to not exceed list price'
|
||||||
ELSE '' END
|
ELSE '' END
|
||||||
)
|
)
|
||||||
END AS guidance_reason;
|
END AS guidance_reason
|
||||||
|
FROM step_cap_list;
|
@ -356,7 +356,7 @@ BEGIN
|
|||||||
SET
|
SET
|
||||||
listcode = rp.jcplcd
|
listcode = rp.jcplcd
|
||||||
,listprice = rp.price
|
,listprice = rp.price
|
||||||
,listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END
|
,listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE rp.price END
|
||||||
,list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END
|
,list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END
|
||||||
,list_from = vb_from
|
,list_from = vb_from
|
||||||
FROM @queue q
|
FROM @queue q
|
||||||
|
Loading…
Reference in New Issue
Block a user