82 lines
2.9 KiB
Transact-SQL
82 lines
2.9 KiB
Transact-SQL
-- 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.95,
|
|
@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), -- 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
|
|
|
|
-- 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*@floor_pct
|
|
THEN @base_price
|
|
ELSE @last_norm*@floor_pct
|
|
END, 5);
|
|
|
|
-- 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(
|
|
CASE WHEN @after_floor <= @last_norm*@cap_last_pct
|
|
THEN @after_floor
|
|
ELSE @last_norm*@cap_last_pct
|
|
END, 5);
|
|
|
|
-- 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(
|
|
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 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;
|
|
|
|
IF @last_norm IS NOT NULL AND @after_floor > @base_price
|
|
SET @reason = N'Last price drop limit';
|
|
|
|
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;
|