commit: 2025-07-28 14:46:47

This commit is contained in:
Paul Trowbridge 2025-07-28 14:46:47 -04:00
parent 2e881b238b
commit 5c5c03d4c3
4 changed files with 122 additions and 125 deletions

View File

@ -9,6 +9,7 @@ WITH srt AS (
customer, customer,
mold, mold,
part, part,
version,
qty, qty,
ROUND(sales_usd / qty, 5) AS price, ROUND(sales_usd / qty, 5) AS price,
odate, odate,
@ -16,12 +17,13 @@ WITH srt AS (
ordnum, ordnum,
quoten, quoten,
ROW_NUMBER() OVER ( ROW_NUMBER() OVER (
PARTITION BY customer, mold, part PARTITION BY customer, mold, part, version
ORDER BY odate DESC ORDER BY odate DESC
) AS rn ) AS rn
FROM rlarp.osm_stack FROM rlarp.osm_stack
WHERE WHERE
version = 'Actual' AND --quotes can't be integrated until we have datasegment or correct part code
version IN ('Actual'/*,'Quotes'*/) AND
customer IS NOT NULL AND customer IS NOT NULL AND
fs_line = '41010' AND fs_line = '41010' AND
calc_status <> 'CANCELLED' AND calc_status <> 'CANCELLED' AND
@ -33,10 +35,11 @@ json_rows AS (
customer, customer,
mold, mold,
part, part,
version,
CONCAT( CONCAT(
'"', part, '":', '"', part, '":',
( (
SELECT qty, price, odate, ordnum, quoten SELECT version, qty, price, odate, ordnum, quoten
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
) )
) AS part_json ) AS part_json
@ -53,7 +56,7 @@ GROUP BY customer, mold
) )
INSERT INTO pricing.lastprice SELECT * FROM onerow; INSERT INTO pricing.lastprice SELECT * FROM onerow;
CREATE UNIQUE INDEX lastprice_cust_mold ON pricing.lastprice(customer, mold); --CREATE UNIQUE INDEX lastprice_cust_mold ON pricing.lastprice(customer, mold);
SELECT count(*) FROM rlarp.osm_stack o INNER JOIN #lastprice l ON SELECT count(*) FROM rlarp.osm_stack o INNER JOIN #lastprice l ON

View File

@ -9,45 +9,24 @@ EXEC pricing.process_queue
EXEC pricing.single_price_call EXEC pricing.single_price_call
@bill = 'GRIF0001', @bill = 'GRIF0001',
@ship = 'JRSG0001', @ship = 'GRIF0001',
@part = 'XNS0T1G3G18B096', @part = 'XNS0T1G3G18B096',
@stlc = 'XNS0T1G3', @stlc = 'XNS0T1G3',
@v1ds = 'v1:T..PLT..', @v1ds = 'v1:T..PLT..',
@vol = 0; @vol = 9600;
EXEC pricing.single_price_call_nowrite
@bill = 'GRIF0001',
@ship = 'JRSG0001',
@part = 'XNS0T1G3G18B096',
@stlc = 'XNS0T1G3',
@v1ds = 'v1:T..PLT..',
@vol = 19200;
SELECT SELECT
price, expl price, expl
FROM pricing.fn_single_price_call( FROM pricing.single_price_call_fn(
'GRIF0001',
'GRIF0001', 'GRIF0001',
'JRSG0001',
'XNS0T1G3G18B096', 'XNS0T1G3G18B096',
'XNS0T1G3', 'XNS0T1G3',
'v1:T..PLT..', 'v1:B..PLT..',
12500 12500
) f ) f
SELECT
price
,expl
,JSON_VALUE(expl, '$."tier"') AS tier
,JSON_VALUE(expl, '$."customer"') AS cust
,JSON_QUERY(expl, '$."target math"') AS math
FROM pricing.fn_single_price_call(
'GRIF0001',
'JRSG0001',
'XNS0T1G3G18B096',
'XNS0T1G3',
'v1:T..PLT..',
12500
);
SELECT * INTO #result FROM pricing.price_queue WHERE 0=1 SELECT * INTO #result FROM pricing.price_queue WHERE 0=1
@ -61,3 +40,17 @@ EXEC pricing.single_price_call_nowrite
@vol = 19200; @vol = 19200;
SELECT * FROM #RESULT SELECT * FROM #RESULT
SELECT
q.*, p.*
FROM
rlarp.live_quotes q
OUTER APPLY pricing.single_price_call_fn(
q.billto
,q.shipto
,q.part
,substring(q.part,1,8)
,q.v1ds
,q.units_each
) p

View File

@ -1,4 +1,4 @@
CREATE OR ALTER FUNCTION pricing.fn_single_price_call ( CREATE OR ALTER FUNCTION pricing.single_price_call_fn (
@bill VARCHAR(100), @bill VARCHAR(100),
@ship VARCHAR(100), @ship VARCHAR(100),
@part VARCHAR(100), @part VARCHAR(100),
@ -6,49 +6,22 @@ CREATE OR ALTER FUNCTION pricing.fn_single_price_call (
@v1ds VARCHAR(100), @v1ds VARCHAR(100),
@vol NUMERIC(18,6) @vol NUMERIC(18,6)
) )
RETURNS @result TABLE ( RETURNS TABLE
bill VARCHAR(100),
ship VARCHAR(100),
part VARCHAR(100),
stlc VARCHAR(100),
v1ds VARCHAR(100),
vol NUMERIC(18,6),
cust VARCHAR(100),
chan VARCHAR(50),
tier VARCHAR(50),
pltq NUMERIC(18,6),
price NUMERIC(18,6),
expl NVARCHAR(MAX)
)
AS AS
BEGIN RETURN
DECLARE @queue TABLE ( (
bill VARCHAR(100), WITH queue AS (
ship VARCHAR(100), SELECT
part VARCHAR(100), @bill AS bill,
stlc VARCHAR(100), @ship AS ship,
v1ds VARCHAR(100), @part AS part,
vol NUMERIC(18,6), @stlc AS stlc,
cust VARCHAR(100), @v1ds AS v1ds,
chan VARCHAR(50), @vol AS vol
tier VARCHAR(50), ),
pltq NUMERIC(18,6), enriched AS (
price NUMERIC(18,6), SELECT
expl NVARCHAR(MAX) q.*,
);
--------------------------------------------------------------------------------
-- Step 1: Insert input row into real queue table
--------------------------------------------------------------------------------
INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol)
VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol);
--------------------------------------------------------------------------------
-- Step 2: Enrich the row with chan, tier, cust, pltq
--------------------------------------------------------------------------------
UPDATE q
SET
chan =
CASE SUBSTRING(bc.cclass, 2, 3) CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3) CASE SUBSTRING(sc.cclass, 2, 3)
@ -56,61 +29,89 @@ BEGIN
ELSE 'DRP' ELSE 'DRP'
END END
ELSE 'DIR' ELSE 'DIR'
END, END AS chan,
tier =
CASE SUBSTRING(bc.cclass, 2, 3) CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIR' THEN bc.tier WHEN 'DIR' THEN bc.tier
ELSE ISNULL(sc.tier, bc.tier) ELSE ISNULL(sc.tier, bc.tier)
END, END AS tier,
cust =
CASE SUBSTRING(bc.cclass, 2, 3) CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3) CASE SUBSTRING(sc.cclass, 2, 3)
WHEN 'DIS' THEN q.ship WHEN 'DIS' THEN bc.dba
ELSE q.ship ELSE sc.dba
END END
ELSE q.bill ELSE q.bill
END, END AS cust,
pltq = i.mpck i.mpck AS pltq
FROM @queue q FROM queue q
LEFT JOIN rlarp.cust bc ON bc.code = q.bill LEFT JOIN rlarp.cust bc ON bc.code = q.bill
LEFT JOIN rlarp.cust sc ON sc.code = q.ship LEFT JOIN rlarp.cust sc ON sc.code = q.ship
LEFT JOIN CMSInterfaceIn.[CMS.CUSLG].itemm i ON i.item = q.part; LEFT JOIN CMSInterfaceIn.[CMS.CUSLG].itemm i ON i.item = q.part
),
-------------------------------------------------------------------------------- hist AS (
-- Step 3: Apply pricing from target_prices SELECT TOP 1
-------------------------------------------------------------------------------- j.qty,
UPDATE q j.price,
SET j.odate,
price = tp.price, j.ordnum,
expl = ( j.quoten
SELECT FROM pricing.lastprice lp
'target price' AS [source], OUTER APPLY OPENJSON(lp.part_stats) AS p
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets], OUTER APPLY OPENJSON(p.value)
ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS [exact_pallets], WITH (
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '')) AS [volume range], qty NUMERIC(20,5),
q.cust AS [customer], price NUMERIC(20,5),
q.chan AS [channel], odate DATE,
q.tier AS [tier], ordnum INT,
JSON_QUERY(tp.math) AS [target math] -- important if math is JSON quoten INT
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER ) AS j
) INNER JOIN enriched e ON
FROM @queue q lp.customer = e.cust
INNER JOIN pricing.target_prices tp ON AND lp.mold = SUBSTRING(e.part,1,8)
q.stlc = tp.stlc WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = e.part
AND q.v1ds = tp.ds ORDER BY j.odate DESC
AND q.chan = tp.chan ),
AND q.tier = tp.tier hist_json AS (
AND FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tp.lower_bound SELECT
AND ( CAST(ROUND(h.price, 5) AS NVARCHAR(50)) AS last_price,
tp.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tp.upper_bound (
); SELECT qty, price, odate, ordnum, quoten
FROM hist h
-------------------------------------------------------------------------------- FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
-- Step 4: Return just the enriched row ) AS hist
-------------------------------------------------------------------------------- FROM hist h
INSERT INTO @result ),
SELECT * FROM @queue; final AS (
SELECT
RETURN; e.part,
END; tp.price,
(
SELECT
'target price' AS [source],
tp.price AS [target_price],
CAST(hj.last_price AS NUMERIC(20,5)) AS [last_price],
FLOOR(e.vol / NULLIF(e.pltq, 0)) AS [calculated_pallets],
ROUND(e.vol / NULLIF(e.pltq, 0), 5) AS [exact_pallets],
CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '')) AS [volume range],
e.cust AS [customer],
e.chan AS [channel],
e.tier AS [tier],
JSON_QUERY(tp.math) AS [target math],
JSON_QUERY(hj.hist) AS [price history]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
) AS expl
FROM enriched e
INNER JOIN pricing.target_prices tp ON
e.stlc = tp.stlc
AND e.v1ds = tp.ds
AND e.chan = tp.chan
AND e.tier = tp.tier
AND FLOOR(e.vol / NULLIF(e.pltq, 0)) >= tp.lower_bound
AND (
tp.upper_bound IS NULL
OR FLOOR(e.vol / NULLIF(e.pltq, 0)) < tp.upper_bound
)
LEFT JOIN hist_json hj ON 1 = 1
)
SELECT price, expl FROM final
);

View File

@ -8,4 +8,4 @@ SELECT
,price ,price
,to_jsonb(math)::text AS math ,to_jsonb(math)::text AS math
FROM FROM
pricequote.target_prices; pricequote.target_prices;