convert to factor and clarify the logical steps

This commit is contained in:
Paul Trowbridge 2025-08-27 23:06:08 -04:00
parent a7945999a2
commit c5532cd2dd
2 changed files with 22 additions and 24 deletions

View File

@ -1,9 +1,11 @@
-- CREATE OR ALTER FUNCTION pricing.guidance_logic;
CREATE OR ALTER FUNCTION pricing.guidance_logic( CREATE OR ALTER FUNCTION pricing.guidance_logic(
@target numeric(20,5), @target numeric(20,5),
@last_norm numeric(20,5), @last_norm numeric(20,5),
@list_eff numeric(20,5), @list_eff numeric(20,5),
@last_date date, @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_last_pct numeric(10,5) = 1.00,
@cap_list_pct numeric(10,5) = 1.00 @cap_list_pct numeric(10,5) = 1.00
) )
@ -15,10 +17,10 @@ AS
BEGIN BEGIN
DECLARE DECLARE
@base_price numeric(20,5), -- starting point (target if available, else last_norm, else list_eff) @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_floor numeric(20,5), -- base but limited to x% lower than last price
@after_cap_last numeric(20,5), -- after applying last cap: lowered if above cap_last_pct * last_norm @after_cap_last numeric(20,5), -- previous step but limited to x% higher than last price
@final_price numeric(20,5), -- after applying list cap: lowered if above cap_list_pct * list_eff @final_price numeric(20,5), -- previous step but limited to x% higher than list price
@reason nvarchar(4000) = N''; -- explanation text for what rules applied @reason nvarchar(4000) = N''; -- logic source of price
-- Early exit if nothing to work with -- Early exit if nothing to work with
IF @target IS NULL AND @last_norm IS NULL AND @list_eff IS NULL IF @target IS NULL AND @last_norm IS NULL AND @list_eff IS NULL
@ -34,12 +36,12 @@ BEGIN
SET @after_floor = @base_price; SET @after_floor = @base_price;
IF @last_norm IS NOT NULL IF @last_norm IS NOT NULL
SET @after_floor = ROUND( SET @after_floor = ROUND(
CASE WHEN @base_price >= @last_norm*(1-@floor_pct) CASE WHEN @base_price >= @last_norm*@floor_pct
THEN @base_price THEN @base_price
ELSE @last_norm*(1-@floor_pct) ELSE @last_norm*@floor_pct
END, 5); END, 5);
-- Step 2: cap vs last_norm -- Step 2: use price from previous step but don't allow it to be x% above last price
SET @after_cap_last = @after_floor; SET @after_cap_last = @after_floor;
IF @last_norm IS NOT NULL IF @last_norm IS NOT NULL
SET @after_cap_last = ROUND( SET @after_cap_last = ROUND(
@ -48,7 +50,7 @@ BEGIN
ELSE @last_norm*@cap_last_pct ELSE @last_norm*@cap_last_pct
END, 5); END, 5);
-- Step 3: cap vs list_eff -- 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; SET @final_price = @after_cap_last;
IF @list_eff IS NOT NULL IF @list_eff IS NOT NULL
SET @final_price = ROUND( SET @final_price = ROUND(
@ -60,26 +62,20 @@ BEGIN
-- Reason text -- Reason text
SET @reason = SET @reason =
CASE CASE
WHEN @target IS NOT NULL THEN 'Using target price' WHEN @target IS NOT NULL THEN N'Using target price'
WHEN @last_norm IS NOT NULL THEN 'Using last price as base' WHEN @last_norm IS NOT NULL THEN N'Using last price as base'
WHEN @list_eff IS NOT NULL THEN 'Using list price as base' WHEN @list_eff IS NOT NULL THEN N'Using list price as base'
END; END;
IF @last_norm IS NOT NULL AND @floor_pct > 0 AND @after_floor > @base_price IF @last_norm IS NOT NULL AND @after_floor > @base_price
SET @reason += N', floored to ' + FORMAT(@floor_pct*100,'0.##') + N'% below last price'; SET @reason = N'Last price drop limit';
IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor IF @last_norm IS NOT NULL AND @after_cap_last < @after_floor
SET @reason += CASE WHEN @cap_last_pct = 1 SET @reason = N'Last price increase limit';
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 IF @list_eff IS NOT NULL AND @final_price < @after_cap_last
SET @reason += CASE WHEN @cap_list_pct = 1 SET @reason = N'List price ceiling';
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); INSERT INTO @ret VALUES (@final_price, @reason);
RETURN; RETURN;
END; END;

View File

@ -136,6 +136,8 @@ BEGIN
------------step 6 compute guidance------------ ------------step 6 compute guidance------------
guidance_price NUMERIC(20,5), guidance_price NUMERIC(20,5),
guidance_reason NVARCHAR(MAX), guidance_reason NVARCHAR(MAX),
shown_price NUMERIC(20,5),
shown_logic NVARCHAR(MAX),
------------step 7 build json------------------ ------------step 7 build json------------------
expl NVARCHAR(MAX), expl NVARCHAR(MAX),
ui_json NVARCHAR(MAX) ui_json NVARCHAR(MAX)
@ -384,7 +386,7 @@ BEGIN
TRY_CAST(q.listprice_eff AS NUMERIC(20,5)), TRY_CAST(q.listprice_eff AS NUMERIC(20,5)),
TRY_CAST(q.last_date AS DATE), TRY_CAST(q.last_date AS DATE),
--allowable price drop percent --allowable price drop percent
.05, .95,
--cap on last price --cap on last price
1.0, 1.0,
--cap on list percent --cap on list percent