remove stlc as an input, integrate last date to assess age of last price
This commit is contained in:
parent
42dd68b611
commit
a1e623b06a
@ -1,7 +1,8 @@
|
||||
CREATE OR ALTER FUNCTION pricing.guidance_logic (
|
||||
@target_price NUMERIC(20,5),
|
||||
@last_price NUMERIC(20,5),
|
||||
@list_price NUMERIC(20,5)
|
||||
@list_price NUMERIC(20,5),
|
||||
@last_date DATE
|
||||
)
|
||||
RETURNS @result TABLE (
|
||||
guidance_price NUMERIC(20,5),
|
||||
@ -13,16 +14,17 @@ BEGIN
|
||||
DECLARE @reason NVARCHAR(MAX) = '';
|
||||
DECLARE @floored NUMERIC(20,5);
|
||||
DECLARE @capped NUMERIC(20,5);
|
||||
DECLARE @effective_price NUMERIC(20,5);
|
||||
DECLARE @use_last_price BIT = 0;
|
||||
|
||||
IF @target_price IS NOT NULL AND @last_price IS NOT NULL
|
||||
-- Determine if last price is recent (within last 2 years)
|
||||
IF @last_price IS NOT NULL AND @last_date IS NOT NULL AND @last_date > DATEADD(YEAR, -2, CAST(GETDATE() AS DATE))
|
||||
SET @use_last_price = 1;
|
||||
|
||||
IF @target_price IS NOT NULL AND @use_last_price = 1
|
||||
BEGIN
|
||||
SET @floored = dbo.GREATEST_NUMERIC205(@target_price, @last_price * 0.95);
|
||||
SET @capped = dbo.LEAST_NUMERIC205(@floored, @last_price);
|
||||
SET @price = dbo.LEAST_NUMERIC205(
|
||||
ISNULL(@list_price, 1e9),
|
||||
@capped
|
||||
);
|
||||
SET @price = dbo.LEAST_NUMERIC205(ISNULL(@list_price, 1e9), @capped);
|
||||
|
||||
IF @price = @last_price
|
||||
BEGIN
|
||||
@ -39,15 +41,42 @@ BEGIN
|
||||
SET @reason += ', capped to not exceed list price';
|
||||
END
|
||||
END
|
||||
ELSE IF @last_price IS NOT NULL
|
||||
ELSE IF @use_last_price = 1
|
||||
BEGIN
|
||||
SET @price = @last_price;
|
||||
SET @reason = 'Last price - no target';
|
||||
END
|
||||
ELSE
|
||||
ELSE IF @target_price IS NOT NULL
|
||||
BEGIN
|
||||
SET @price = @target_price;
|
||||
SET @reason = 'Target price - no prior sale';
|
||||
IF @last_price IS NOT NULL AND @last_date IS NOT NULL
|
||||
BEGIN
|
||||
SET @reason = CONCAT(
|
||||
'Last price ignored (too old: ',
|
||||
CONVERT(NVARCHAR(10), @last_date, 120),
|
||||
'), using target price'
|
||||
);
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @reason = 'Target price - no prior sale';
|
||||
END
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @price = NULL;
|
||||
IF @last_price IS NOT NULL AND @last_date IS NOT NULL
|
||||
BEGIN
|
||||
SET @reason = CONCAT(
|
||||
'Last price ignored (too old: ',
|
||||
CONVERT(NVARCHAR(10), @last_date, 120),
|
||||
'), no pricing available'
|
||||
);
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SET @reason = 'No pricing available';
|
||||
END
|
||||
END
|
||||
|
||||
INSERT INTO @result VALUES (@price, @reason);
|
||||
|
@ -2,7 +2,6 @@ CREATE OR ALTER PROCEDURE pricing.single_price_call
|
||||
@bill VARCHAR(100),
|
||||
@ship VARCHAR(100),
|
||||
@part VARCHAR(100),
|
||||
@stlc VARCHAR(100),
|
||||
@v1ds VARCHAR(100),
|
||||
@vol NUMERIC(18,6)
|
||||
AS
|
||||
@ -36,8 +35,8 @@ BEGIN
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 1: Seed the queue with input row
|
||||
--------------------------------------------------------------------------------
|
||||
INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol, expl)
|
||||
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol, '{}');
|
||||
INSERT INTO @queue (bill, ship, part, v1ds, vol, expl)
|
||||
VALUES (@bill, @ship, @part, @v1ds, @vol, '{}');
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Step 2: Enrich with channel, tier, customer, pack quantity, and price level
|
||||
@ -76,7 +75,8 @@ BEGIN
|
||||
ELSE bc.plevel
|
||||
END
|
||||
ELSE bc.plevel
|
||||
END
|
||||
END,
|
||||
stlc = substring(q.part,1,8)
|
||||
FROM @queue q
|
||||
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
|
||||
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
|
||||
@ -214,7 +214,8 @@ BEGIN
|
||||
CROSS APPLY pricing.guidance_logic(
|
||||
CAST(JSON_VALUE(q.expl, '$.target_price') AS NUMERIC(20,5)),
|
||||
CAST(JSON_VALUE(q.expl, '$.last_price') AS NUMERIC(20,5)),
|
||||
CAST(JSON_VALUE(q.expl, '$.list_price') AS NUMERIC(20,5))
|
||||
CAST(JSON_VALUE(q.expl, '$.list_price') AS NUMERIC(20,5)),
|
||||
CAST(JSON_VALUE(q.expl, '$.last_date') AS DATE)
|
||||
) g;
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
|
Loading…
Reference in New Issue
Block a user