diff --git a/procs/approval_logic.ms.sql b/procs/approval_logic.ms.sql index 272a0b4..cc72db4 100644 --- a/procs/approval_logic.ms.sql +++ b/procs/approval_logic.ms.sql @@ -1,9 +1,11 @@ -CREATE OR ALTER FUNCTION pricing.approval_logic( +-- CREATE OR ALTER FUNCTION pricing.guidance_logic; + +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, + @floor_pct numeric(10,5) = 0.95, @cap_last_pct numeric(10,5) = 1.00, @cap_list_pct numeric(10,5) = 1.00 ) @@ -14,32 +16,32 @@ RETURNS @ret TABLE ( 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''; + @base_price numeric(20,5), -- starting point (target if available, else last_norm, else list_eff) + @after_floor numeric(20,5), -- base but limited to x% lower than last price + @after_cap_last numeric(20,5), -- previous step but limited to x% higher than last price + @final_price numeric(20,5), -- previous step but limited to x% higher than list price + @reason nvarchar(4000) = N''; -- logic source of price - -- no target → early return - IF @target IS NULL + -- 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 price available'); + INSERT INTO @ret VALUES (NULL, N'No target, last, or list available'); RETURN; END; - -- start from target - SET @base_price = @target; + -- Pick starting base price + SET @base_price = COALESCE(@target, @last_norm, @list_eff); - -- Step 1: floor vs last_norm (only if it raises price) + -- 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 AND @floor_pct > 0 + IF @last_norm IS NOT NULL SET @after_floor = ROUND( - CASE WHEN @base_price >= @last_norm*(1-@floor_pct) + CASE WHEN @base_price >= @last_norm*@floor_pct THEN @base_price - ELSE @last_norm*(1-@floor_pct) + ELSE @last_norm*@floor_pct END, 5); - -- Step 2: cap vs last_norm (only if it lowers price) + -- Step 2: use price from previous step but don't allow it to be x% above last price SET @after_cap_last = @after_floor; IF @last_norm IS NOT NULL SET @after_cap_last = ROUND( @@ -48,7 +50,7 @@ BEGIN ELSE @last_norm*@cap_last_pct END, 5); - -- Step 3: cap vs list_eff (only if it lowers price) + -- Step 3: use price from last step, but don't allow it to be more than x% above list price SET @final_price = @after_cap_last; IF @list_eff IS NOT NULL SET @final_price = ROUND( @@ -57,35 +59,23 @@ BEGIN 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'; + -- Reason text + SET @reason = + CASE + WHEN @target IS NOT NULL THEN N'Using target price' + WHEN @last_norm IS NOT NULL THEN N'Using last price as base' + WHEN @list_eff IS NOT NULL THEN N'Using list price as base' + END; - -- 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'; + IF @last_norm IS NOT NULL AND @after_floor > @base_price + SET @reason = N'Last price drop limit'; - -- 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; + IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor + SET @reason = N'Last price increase limit'; + IF @list_eff IS NOT NULL AND @final_price < @after_cap_last + SET @reason = N'List price ceiling'; + INSERT INTO @ret VALUES (@final_price, @reason); RETURN; END; -