From a7945999a2ac36cb2849f292092011b03e36c61d Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 27 Aug 2025 22:41:39 -0400 Subject: [PATCH] initial rework of last price so it is clearer to review --- procs/approval_logic.ms.sql | 91 +++++++++++++++++++++ procs/guidance_logic.ms.sql | 152 ++++++++++++++++++------------------ 2 files changed, 168 insertions(+), 75 deletions(-) create mode 100644 procs/approval_logic.ms.sql diff --git a/procs/approval_logic.ms.sql b/procs/approval_logic.ms.sql new file mode 100644 index 0000000..272a0b4 --- /dev/null +++ b/procs/approval_logic.ms.sql @@ -0,0 +1,91 @@ +CREATE OR ALTER FUNCTION pricing.approval_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, + @cap_last_pct numeric(10,5) = 1.00, + @cap_list_pct numeric(10,5) = 1.00 +) +RETURNS @ret TABLE ( + guidance_price numeric(20,5), + guidance_reason nvarchar(4000) +) +AS +BEGIN + DECLARE + @base_price numeric(20,5), + @after_floor numeric(20,5), + @after_cap_last numeric(20,5), + @final_price numeric(20,5), + @reason nvarchar(4000) = N''; + + -- no target → early return + IF @target IS NULL + BEGIN + INSERT INTO @ret VALUES (NULL, N'No target price available'); + RETURN; + END; + + -- start from target + SET @base_price = @target; + + -- Step 1: floor vs last_norm (only if it raises price) + SET @after_floor = @base_price; + IF @last_norm IS NOT NULL AND @floor_pct > 0 + SET @after_floor = ROUND( + CASE WHEN @base_price >= @last_norm*(1-@floor_pct) + THEN @base_price + ELSE @last_norm*(1-@floor_pct) + END, 5); + + -- Step 2: cap vs last_norm (only if it lowers price) + SET @after_cap_last = @after_floor; + IF @last_norm IS NOT NULL + SET @after_cap_last = ROUND( + CASE WHEN @after_floor <= @last_norm*@cap_last_pct + THEN @after_floor + ELSE @last_norm*@cap_last_pct + END, 5); + + -- Step 3: cap vs list_eff (only if it lowers price) + SET @final_price = @after_cap_last; + IF @list_eff IS NOT NULL + SET @final_price = ROUND( + CASE WHEN @after_cap_last <= @list_eff*@cap_list_pct + THEN @after_cap_last + ELSE @list_eff*@cap_list_pct + END, 5); + + -- Build explanation + IF @last_norm IS NULL AND @list_eff IS NULL + BEGIN + SET @reason = N'No prior sale or list; using target price'; + END + ELSE + BEGIN + SET @reason = N'Using target price'; + + -- mention floor only if it raised the price + IF @last_norm IS NOT NULL AND @floor_pct > 0 AND @after_floor > @base_price + SET @reason += N', floored to ' + FORMAT(@floor_pct*100, '0.##') + N'% below last price'; + + -- mention last cap only if it lowered the price + IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor + SET @reason += CASE WHEN @cap_last_pct = 1 + THEN N', capped to not exceed last price' + ELSE N', capped to ' + FORMAT(@cap_last_pct*100,'0.##') + N'% of last price' + END; + + -- mention list cap only if it lowered the price + IF @list_eff IS NOT NULL AND @final_price < @after_cap_last + SET @reason += CASE WHEN @cap_list_pct = 1 + THEN N', capped to not exceed list price' + ELSE N', capped to ' + FORMAT(@cap_list_pct*100,'0.##') + N'% of list price' + END; + END; + + INSERT INTO @ret VALUES (@final_price, @reason); + RETURN; +END; + diff --git a/procs/guidance_logic.ms.sql b/procs/guidance_logic.ms.sql index e21cf44..8e860c7 100644 --- a/procs/guidance_logic.ms.sql +++ b/procs/guidance_logic.ms.sql @@ -3,81 +3,83 @@ CREATE OR ALTER FUNCTION pricing.guidance_logic( @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% + @floor_pct numeric(10,5) = 0.05, + @cap_last_pct numeric(10,5) = 1.00, @cap_list_pct numeric(10,5) = 1.00 ) -RETURNS TABLE -AS -RETURN -WITH params AS ( - SELECT - @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 - 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 - 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 - 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 +RETURNS @ret TABLE ( + guidance_price numeric(20,5), + guidance_reason nvarchar(4000) ) -SELECT - 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 prior sale or list; using target price' - ELSE - CONCAT( - 'Using target price', - -- 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, - -- 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, - -- 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 -FROM step_cap_list; \ No newline at end of file +AS +BEGIN + DECLARE + @base_price numeric(20,5), -- starting point (target if available, else last_norm, else list_eff) + @after_floor numeric(20,5), -- after applying floor: raised if below (1 - floor_pct) * last_norm + @after_cap_last numeric(20,5), -- after applying last cap: lowered if above cap_last_pct * last_norm + @final_price numeric(20,5), -- after applying list cap: lowered if above cap_list_pct * list_eff + @reason nvarchar(4000) = N''; -- explanation text for what rules applied + + -- Early exit if nothing to work with + IF @target IS NULL AND @last_norm IS NULL AND @list_eff IS NULL + BEGIN + INSERT INTO @ret VALUES (NULL, N'No target, last, or list available'); + RETURN; + END; + + -- Pick starting base price + SET @base_price = COALESCE(@target, @last_norm, @list_eff); + + -- Step 1: use base price unless it's more than x% below last price + SET @after_floor = @base_price; + IF @last_norm IS NOT NULL + SET @after_floor = ROUND( + CASE WHEN @base_price >= @last_norm*(1-@floor_pct) + THEN @base_price + ELSE @last_norm*(1-@floor_pct) + END, 5); + + -- Step 2: cap vs last_norm + SET @after_cap_last = @after_floor; + IF @last_norm IS NOT NULL + SET @after_cap_last = ROUND( + CASE WHEN @after_floor <= @last_norm*@cap_last_pct + THEN @after_floor + ELSE @last_norm*@cap_last_pct + END, 5); + + -- Step 3: cap vs list_eff + SET @final_price = @after_cap_last; + IF @list_eff IS NOT NULL + SET @final_price = ROUND( + CASE WHEN @after_cap_last <= @list_eff*@cap_list_pct + THEN @after_cap_last + ELSE @list_eff*@cap_list_pct + END, 5); + + -- Reason text + SET @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 @floor_pct > 0 AND @after_floor > @base_price + SET @reason += N', floored to ' + FORMAT(@floor_pct*100,'0.##') + N'% below last price'; + + IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor + SET @reason += CASE WHEN @cap_last_pct = 1 + THEN N', capped to not exceed last price' + ELSE N', capped to ' + FORMAT(@cap_last_pct*100,'0.##') + N'% of last price' + END; + + IF @list_eff IS NOT NULL AND @final_price < @after_cap_last + SET @reason += CASE WHEN @cap_list_pct = 1 + THEN N', capped to not exceed list price' + ELSE N', capped to ' + FORMAT(@cap_list_pct*100,'0.##') + N'% of list price' + END; + + INSERT INTO @ret VALUES (@final_price, @reason); + RETURN; +END;