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,
mold,
part,
version,
qty,
ROUND(sales_usd / qty, 5) AS price,
odate,
@ -16,12 +17,13 @@ WITH srt AS (
ordnum,
quoten,
ROW_NUMBER() OVER (
PARTITION BY customer, mold, part
PARTITION BY customer, mold, part, version
ORDER BY odate DESC
) AS rn
FROM rlarp.osm_stack
WHERE
version = 'Actual' AND
WHERE
--quotes can't be integrated until we have datasegment or correct part code
version IN ('Actual'/*,'Quotes'*/) AND
customer IS NOT NULL AND
fs_line = '41010' AND
calc_status <> 'CANCELLED' AND
@ -33,10 +35,11 @@ json_rows AS (
customer,
mold,
part,
version,
CONCAT(
'"', part, '":',
(
SELECT qty, price, odate, ordnum, quoten
SELECT version, qty, price, odate, ordnum, quoten
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
) AS part_json
@ -53,7 +56,7 @@ GROUP BY customer, mold
)
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

View File

@ -9,45 +9,24 @@ EXEC pricing.process_queue
EXEC pricing.single_price_call
@bill = 'GRIF0001',
@ship = 'JRSG0001',
@ship = 'GRIF0001',
@part = 'XNS0T1G3G18B096',
@stlc = 'XNS0T1G3',
@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
price, expl
FROM pricing.fn_single_price_call(
FROM pricing.single_price_call_fn(
'GRIF0001',
'GRIF0001',
'JRSG0001',
'XNS0T1G3G18B096',
'XNS0T1G3',
'v1:T..PLT..',
'v1:B..PLT..',
12500
) 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
@ -61,3 +40,17 @@ EXEC pricing.single_price_call_nowrite
@vol = 19200;
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),
@ship VARCHAR(100),
@part VARCHAR(100),
@ -6,49 +6,22 @@ CREATE OR ALTER FUNCTION pricing.fn_single_price_call (
@v1ds VARCHAR(100),
@vol NUMERIC(18,6)
)
RETURNS @result 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)
)
RETURNS TABLE
AS
BEGIN
DECLARE @queue 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)
);
--------------------------------------------------------------------------------
-- 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 =
RETURN
(
WITH queue AS (
SELECT
@bill AS bill,
@ship AS ship,
@part AS part,
@stlc AS stlc,
@v1ds AS v1ds,
@vol AS vol
),
enriched AS (
SELECT
q.*,
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3)
@ -56,61 +29,89 @@ BEGIN
ELSE 'DRP'
END
ELSE 'DIR'
END,
tier =
END AS chan,
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIR' THEN bc.tier
ELSE ISNULL(sc.tier, bc.tier)
END,
cust =
END AS tier,
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3)
WHEN 'DIS' THEN q.ship
ELSE q.ship
WHEN 'DIS' THEN bc.dba
ELSE sc.dba
END
ELSE q.bill
END,
pltq = i.mpck
FROM @queue q
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
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 pricing from target_prices
--------------------------------------------------------------------------------
UPDATE q
SET
price = tp.price,
expl = (
SELECT
'target price' AS [source],
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] -- important if math is JSON
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: Return just the enriched row
--------------------------------------------------------------------------------
INSERT INTO @result
SELECT * FROM @queue;
RETURN;
END;
END AS cust,
i.mpck AS pltq
FROM queue q
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
LEFT JOIN CMSInterfaceIn.[CMS.CUSLG].itemm i ON i.item = q.part
),
hist AS (
SELECT TOP 1
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
INNER JOIN enriched e ON
lp.customer = e.cust
AND lp.mold = SUBSTRING(e.part,1,8)
WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = e.part
ORDER BY j.odate DESC
),
hist_json AS (
SELECT
CAST(ROUND(h.price, 5) AS NVARCHAR(50)) AS last_price,
(
SELECT qty, price, odate, ordnum, quoten
FROM hist h
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
) AS hist
FROM hist h
),
final AS (
SELECT
e.part,
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
,to_jsonb(math)::text AS math
FROM
pricequote.target_prices;
pricequote.target_prices;