create final pricing guidance

This commit is contained in:
Paul Trowbridge 2025-07-28 23:24:34 -04:00
parent 041b0591ba
commit 67fc532804
8 changed files with 238 additions and 244 deletions

View File

@ -1,40 +0,0 @@
SELECT
o.qline,
o.part,
o.touched,
o.qcustomer,
lp.customer,
lp.mold,
p.[key] AS part, -- this is the part number
j.qty,
j.price,
j.odate,
j.ordnum,
j.quoten
FROM
rlarp.live_quotes o
LEFT OUTER JOIN pricing.lastprice lp ON
lp.customer = o.qcustomer
AND lp.mold = substring(o.part,1,8)
OUTER APPLY OPENJSON(lp.part_stats) AS p -- unpacks part keys
OUTER APPLY OPENJSON(p.value)
WITH (
qty FLOAT,
price FLOAT,
odate DATE,
ordnum INT,
quoten INT
) AS j
WHERE
qid = 112859
AND o.part = p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS
SELECT
o.qline,
o.part,
o.touched
FROM
rlarp.live_quotes o
WHERE
o.qid = 112794

View File

@ -1,24 +0,0 @@
SELECT * FROM pricing.lastprice WHERE customer = 'ALTMAN PLANTS' AND mold = 'XPR15CS1'
SELECT
lp.*
,p.*
,j.*
FROM
pricing.lastprice lp
OUTER APPLY OPENJSON(lp.part_stats) AS p -- unpacks part keys
OUTER APPLY OPENJSON(p.value)
WITH (
qty FLOAT,
price FLOAT,
odate DATE,
ordnum INT,
quoten INT
) AS j
WHERE
customer = 'ALTMAN PLANTS'
AND mold = 'XPR15CS1'
SELECT * FROM pricing.price_queue pq

View File

@ -1,29 +0,0 @@
WITH ordered AS (
SELECT
jcpart,
jcpric,
jcunit,
jcvoll,
ROW_NUMBER() OVER (PARTITION BY jcpart ORDER BY jcvoll) AS rn
FROM cmsinterfacein.lgdat.iprcc
WHERE jcplcd = 'FUCU'
),
grouped AS (
SELECT
o1.jcpart,
o1.jcpric,
o1.jcvoll AS from_volume,
ISNULL(o2.jcvoll - 1, o1.jcvoll) AS to_volume -- next vol - 1
FROM ordered o1
LEFT JOIN ordered o2
ON o1.jcpart = o2.jcpart
AND o1.rn + 1 = o2.rn
AND o1.jcpric = o2.jcpric
)
SELECT *
FROM grouped
ORDER BY jcpart, from_volume;
SELECT * FROM cmsinterfacein.lgdat.iprcc WHERE jcplcd = 'NUEU'
SELECT item, listcode, vol_uom, vb_f, vb_t, price FROM usmidsap02.ubm.rlarp.plcore_fullcode_ranged r

View File

View File

@ -9,11 +9,11 @@ EXEC pricing.process_queue
EXEC pricing.single_price_call
@bill = 'GRIF0001',
@ship = 'GRIF0001',
@ship = 'JRSG0001',
@part = 'XNS0T1G3G18B096',
@stlc = 'XNS0T1G3',
@v1ds = 'v1:B..PLT..',
@vol = 20000;
@vol = 9600;
SELECT

View File

@ -0,0 +1,27 @@
CREATE OR ALTER FUNCTION dbo.LEAST_NUMERIC205(
@a NUMERIC(20,5),
@b NUMERIC(20,5)
)
RETURNS NUMERIC(20,5)
AS
BEGIN
RETURN CASE
WHEN @a IS NULL THEN @b
WHEN @b IS NULL THEN @a
WHEN @a < @b THEN @a ELSE @b
END
END
CREATE OR ALTER FUNCTION dbo.GREATEST_NUMERIC205(
@a NUMERIC(20,5),
@b NUMERIC(20,5)
)
RETURNS NUMERIC(20,5)
AS
BEGIN
RETURN CASE
WHEN @a IS NULL THEN @b
WHEN @b IS NULL THEN @a
WHEN @a > @b THEN @a ELSE @b
END
END

View File

@ -0,0 +1,55 @@
CREATE OR ALTER FUNCTION pricing.guidance_logic (
@target_price NUMERIC(20,5),
@last_price NUMERIC(20,5),
@list_price NUMERIC(20,5)
)
RETURNS @result TABLE (
guidance_price NUMERIC(20,5),
guidance_reason NVARCHAR(MAX)
)
AS
BEGIN
DECLARE @price NUMERIC(20,5);
DECLARE @reason NVARCHAR(MAX) = '';
DECLARE @floored NUMERIC(20,5);
DECLARE @capped NUMERIC(20,5);
DECLARE @effective_price NUMERIC(20,5);
IF @target_price IS NOT NULL AND @last_price IS NOT NULL
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
);
IF @price = @last_price
BEGIN
SET @reason = 'Cap at last price';
END
ELSE
BEGIN
SET @reason = 'Using target price';
IF @target_price < @last_price * 0.95
SET @reason += ', floored to 5% below last price';
IF @target_price > @last_price
SET @reason += ', capped to not exceed last price';
IF @list_price IS NOT NULL AND @price = @list_price AND @target_price > @list_price
SET @reason += ', capped to not exceed list price';
END
END
ELSE IF @last_price IS NOT NULL
BEGIN
SET @price = @last_price;
SET @reason = 'Last price - no target';
END
ELSE
BEGIN
SET @price = @target_price;
SET @reason = 'Target price - no prior sale';
END
INSERT INTO @result VALUES (@price, @reason);
RETURN;
END

View File

@ -9,35 +9,38 @@ AS
BEGIN
SET NOCOUNT ON;
DECLARE @phist NVARCHAR(MAX);
-- Declare table variable for the input row
-- Working table for enriched pricing request
DECLARE @queue TABLE (
bill VARCHAR(100),
ship VARCHAR(100),
part VARCHAR(100),
stlc VARCHAR(100),
v1ds VARCHAR(100),
vol NUMERIC(18,6),
chan VARCHAR(50),
cust VARCHAR(100),
tier VARCHAR(50),
pltq NUMERIC(18,6),
plevel NVARCHAR(20),
price NUMERIC(18,6),
expl NVARCHAR(MAX),
hist NVARCHAR(MAX),
LAST nvarchar(max)
bill VARCHAR(100),
ship VARCHAR(100),
part VARCHAR(100),
stlc VARCHAR(100),
v1ds VARCHAR(100),
vol NUMERIC(18,6),
chan VARCHAR(50),
cust VARCHAR(100),
tier VARCHAR(50),
pltq NUMERIC(18,6),
plevel NVARCHAR(20),
hist NVARCHAR(MAX),
last_price NUMERIC(20,5),
last_date DATE,
last_order NVARCHAR(10),
last_quote NVARCHAR(10),
tprice NUMERIC(20,5),
guidance_price NUMERIC(20,5),
guidance_reason NVARCHAR(MAX),
expl NVARCHAR(MAX)
);
--------------------------------------------------------------------------------
-- Step 1: Insert input row into queue
-- Step 1: Seed the queue with input row
--------------------------------------------------------------------------------
INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol)
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol);
INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol, expl)
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol, '{}');
--------------------------------------------------------------------------------
-- Step 2: Enrich the row with chan, tier, cust, pltq
-- Step 2: Enrich with channel, tier, customer, pack quantity, and price level
--------------------------------------------------------------------------------
UPDATE q
SET
@ -79,141 +82,143 @@ BEGIN
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
LEFT JOIN CMSInterfaceIn.[CMS.CUSLG].itemm i ON i.item = q.part;
--------------------------------------------------------------------------------
-- Step 3: Apply target price and embed metadata as JSON
--------------------------------------------------------------------------------
UPDATE q
SET
tprice = tp.price,
expl = (
SELECT
'target price' AS [source],
tp.price AS [target_price],
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,5)) AS [exact_pallets],
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '')) AS [volume range],
q.cust AS [customer],
q.chan AS [channel],
TRIM(q.tier) AS [tier],
JSON_QUERY(tp.math) AS [target math]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
FROM @queue q
INNER JOIN pricing.target_prices tp ON
q.stlc = tp.stlc
AND q.v1ds = tp.ds
AND q.chan = tp.chan
AND q.tier = tp.tier
AND FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tp.lower_bound
AND (
tp.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tp.upper_bound
);
--------------------------------------------------------------------------------
-- Step 4: Pull last sale data and embed in columns and JSON
--------------------------------------------------------------------------------
UPDATE q
SET
hist = JSON_MODIFY('{}', '$.full_history', JSON_QUERY(lp.part_stats)),
last_price = j.price,
last_date = j.odate,
last_order = j.ordnum,
last_quote = j.quoten,
expl = JSON_MODIFY(
JSON_MODIFY(
JSON_MODIFY(
JSON_MODIFY(
ISNULL(q.expl, '{}'),
'$.last_price', j.price
),
'$.last_date', CONVERT(NVARCHAR(10), j.odate, 23)
),
'$.last_order', j.ordnum
),
'$.last_quote', j.quoten
)
FROM @queue q
JOIN pricing.lastprice lp
ON lp.customer = q.cust
AND lp.mold = SUBSTRING(q.part, 1, 8)
OUTER APPLY (
SELECT TOP 1 *
FROM OPENJSON(lp.part_stats) AS p
OUTER APPLY OPENJSON(p.value)
WITH (
qty NUMERIC(20,5),
price NUMERIC(20,5),
odate DATE,
ordnum INT,
quoten INT
) AS j
WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part
ORDER BY j.odate DESC
) AS j;
--------------------------------------------------------------------------------
-- Step 5: Add list price info from external pricelist
--------------------------------------------------------------------------------
WITH ranked_prices AS (
SELECT
q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol,
CAST(p.price AS NUMERIC(20,5)) AS price,
p.jcplcd,
ROW_NUMBER() OVER (
PARTITION BY q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol
ORDER BY p.price ASC
) AS rn
FROM @queue q
INNER JOIN CMSInterfaceIn."CMS.CUSLG".IPRCBHC i
ON TRIM(i.jbplvl) = TRIM(q.plevel)
AND CAST(GETDATE() AS DATE) BETWEEN i.jbfdat AND i.jbtdat
INNER JOIN pricing.pricelist_ranged p
ON p.jcplcd = TRIM(i.jbplcd)
AND p.jcpart = q.part
AND q.vol >= p.vb_from
AND (p.vb_to IS NULL OR q.vol < p.vb_to)
)
UPDATE q
SET expl = JSON_MODIFY(
JSON_MODIFY(
ISNULL(q.expl, '{}'),
'$.list_price', rp.price
),
'$.list_code', rp.jcplcd
)
FROM @queue q
JOIN ranked_prices rp
ON q.bill = rp.bill
AND q.ship = rp.ship
AND q.part = rp.part
AND q.stlc = rp.stlc
AND q.v1ds = rp.v1ds
AND q.vol = rp.vol
AND rp.rn = 1;
--------------------------------------------------------------------------------
-- Step 3: Get last price info directly into @queue columns
-- Step 6: Compute guidance price and logic, and embed in JSON
--------------------------------------------------------------------------------
UPDATE q
SET
q.hist = (
SELECT
j.qty,
j.price,
j.odate,
j.ordnum,
j.quoten
FROM pricing.lastprice lp
OUTER APPLY OPENJSON(lp.part_stats) AS p
OUTER APPLY OPENJSON(p.value)
WITH (
qty NUMERIC(20,5),
price NUMERIC(20,5),
odate DATE,
ordnum INT,
quoten INT
) AS j
WHERE
lp.customer = q.cust
AND lp.mold = SUBSTRING(q.part,1,8)
AND p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part
ORDER BY j.odate DESC
FOR JSON PATH -- <<< this returns a JSON array of objects
),
q.last = (
SELECT TOP 1
CAST(ROUND(j.price, 5) AS NVARCHAR(50)) -- must be string to store in NVARCHAR column
FROM pricing.lastprice lp
OUTER APPLY OPENJSON(lp.part_stats) AS p
OUTER APPLY OPENJSON(p.value)
WITH (
qty NUMERIC(20,5),
price NUMERIC(20,5),
odate DATE,
ordnum INT,
quoten INT
) AS j
WHERE
lp.customer = q.cust
AND lp.mold = SUBSTRING(q.part,1,8)
AND p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part
ORDER BY j.odate DESC
)
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 4: Apply pricing and embed price history + last price from queue columns
--------------------------------------------------------------------------------
UPDATE q
SET
price = tp.price,
expl = (
SELECT
'target price' AS [source],
tp.price AS [target_price],
CAST(q.last AS NUMERIC(20,5)) AS [last_price],
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS [exact_pallets],
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '')) AS [volume range],
q.cust AS [customer],
q.chan AS [channel],
q.tier AS [tier],
JSON_QUERY(tp.math) AS [target math],
JSON_QUERY(q.hist) AS [price history]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
guidance_price = g.guidance_price,
guidance_reason = g.guidance_reason,
expl = JSON_MODIFY(
JSON_MODIFY(
ISNULL(q.expl, '{}'),
'$.guidance_reason',
g.guidance_reason
),
'$.guidance_price',
g.guidance_price
)
FROM @queue q
INNER JOIN pricing.target_prices tp ON
q.stlc = tp.stlc
AND q.v1ds = tp.ds
AND q.chan = tp.chan
AND q.tier = tp.tier
AND FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tp.lower_bound
AND (
tp.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tp.upper_bound
);
--------------------------------------------------------------------------------
-- Step 5: Enrich the row with price list
--------------------------------------------------------------------------------
WITH ranked_prices AS (
SELECT
q.bill,
q.ship,
q.part,
q.stlc,
q.v1ds,
q.vol,
CAST(p.price AS NUMERIC(20,5)) price,
p.jcplcd,
ROW_NUMBER() OVER (
PARTITION BY q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol
ORDER BY p.price ASC
) AS rn
FROM
@queue q
INNER JOIN CMSInterfaceIn."CMS.CUSLG".IPRCBHC i
ON TRIM(i.jbplvl) = TRIM(q.plevel)
AND CAST(GETDATE() AS DATE) BETWEEN i.jbfdat AND i.jbtdat
INNER JOIN pricing.pricelist_ranged p
ON p.jcplcd = TRIM(i.jbplcd)
AND p.jcpart = q.part
AND q.vol >= p.vb_from
AND (p.vb_to IS NULL OR q.vol < p.vb_to)
)
UPDATE q
SET expl = JSON_MODIFY(
JSON_MODIFY(
ISNULL(q.expl, '{}'),
'$.list_price', rp.price
),
'$.list_code', rp.jcplcd
)
FROM @queue q
JOIN ranked_prices rp
ON q.bill = rp.bill
AND q.ship = rp.ship
AND q.part = rp.part
AND q.stlc = rp.stlc
AND q.v1ds = rp.v1ds
AND q.vol = rp.vol
AND rp.rn = 1;
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))
) g;
--------------------------------------------------------------------------------
-- Step Last: Return just the enriched row
-- Final: Return the enriched result row
--------------------------------------------------------------------------------
SELECT * FROM @queue;
END;