diff --git a/procs/guidance_logic.ms.sql b/procs/guidance_logic.ms.sql index 2071384..e21cf44 100644 --- a/procs/guidance_logic.ms.sql +++ b/procs/guidance_logic.ms.sql @@ -10,50 +10,74 @@ CREATE OR ALTER FUNCTION pricing.guidance_logic( RETURNS TABLE AS RETURN -WITH base AS ( +WITH params AS ( SELECT - CAST(CASE WHEN @target IS NULL THEN NULL ELSE @target END AS numeric(20,5)) AS price -), floored AS ( + @target AS base_price, + @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 - 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 ( + base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, + CAST( + CASE + WHEN base_price IS NULL OR last_norm IS NULL OR floor_pct <= 0 + THEN base_price + 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 - 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 ( + base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, after_floor, + CAST( + CASE + WHEN after_floor IS NULL OR last_norm IS NULL + THEN after_floor + 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 - 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 + base_price, last_norm, list_eff, floor_pct, cap_last_pct, eff_list_cap, after_floor, after_cap_last, + CAST( + CASE + WHEN after_cap_last IS NULL OR list_eff IS NULL + 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 - price AS guidance_price, + final_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' + WHEN @last_norm IS NULL AND @list_eff IS NULL THEN 'No prior sale or list; using target price' ELSE CONCAT( '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, - 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' + -- show last cap only if it lowered price + CASE WHEN last_norm IS NOT NULL AND after_cap_last < after_floor + THEN CASE WHEN @cap_last_pct = 1 + THEN ', capped to not exceed last price' + ELSE CONCAT(', capped to ', FORMAT(@cap_last_pct*100,'0.##'), '% of last price') + END 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 + -- show list cap only if it lowered price (always “not exceed” because eff_list_cap<=1) + CASE WHEN list_eff IS NOT NULL AND final_price < after_cap_last THEN ', capped to not exceed list price' ELSE '' END ) - END AS guidance_reason; + END AS guidance_reason +FROM step_cap_list; \ No newline at end of file diff --git a/procs/single_price_call.ms.sql b/procs/single_price_call.ms.sql index 3a2b6be..82d03d1 100644 --- a/procs/single_price_call.ms.sql +++ b/procs/single_price_call.ms.sql @@ -356,7 +356,7 @@ BEGIN SET listcode = rp.jcplcd ,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_from = vb_from FROM @queue q