build ranged price list and include in return json

This commit is contained in:
Paul Trowbridge 2025-07-28 17:39:16 -04:00
parent 9df0b1fd12
commit 92d95ee571
4 changed files with 110 additions and 10 deletions

29
Scripts/Script-3.sql Normal file
View File

@ -0,0 +1,29 @@
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

@ -23,6 +23,7 @@ BEGIN
cust VARCHAR(100),
tier VARCHAR(50),
pltq NUMERIC(18,6),
plevel NVARCHAR(20),
price NUMERIC(18,6),
expl NVARCHAR(MAX),
hist NVARCHAR(MAX),
@ -63,7 +64,16 @@ BEGIN
END
ELSE q.bill
END,
pltq = i.mpck
pltq = i.mpck,
plevel =
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3)
WHEN 'DIS' THEN sc.plevel
ELSE bc.plevel
END
ELSE bc.plevel
END
FROM @queue q
LEFT JOIN rlarp.cust bc ON bc.code = q.bill
LEFT JOIN rlarp.cust sc ON sc.code = q.ship
@ -153,10 +163,57 @@ BEGIN
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;
--------------------------------------------------------------------------------
-- Step Last: Return just the enriched row
--------------------------------------------------------------------------------
SELECT price, expl FROM @queue;
SELECT * FROM @queue;
END;

View File

@ -116,13 +116,13 @@ FROM
WHERE
xt = mastt
)
SELECT * INTO #uom FROM sorted WHERE rn = 1
SELECT * INTO #uom FROM sorted WHERE rn = 1;
--so far so good
drop table #anchor;
drop table #g;
DELETE FROM pricing.pricelist_ranged;
TRUNCATE TABLE pricing.pricelist_ranged;
WITH
conv AS (
@ -138,7 +138,7 @@ conv AS (
p.jcpric / u.factor AS price_pc
FROM
cmsinterfacein.lgdat.iprcc p
LEFT OUTER JOIN #uom u
INNER JOIN #uom u
ON u.partn = p.jcpart
AND u.from_uom = p.jcunit
AND u.to_uom = 'PC'
@ -170,8 +170,8 @@ ranged AS (
INSERT INTO
pricing.pricelist_ranged
SELECT
jcplcd,
jcpart,
RTRIM(jcplcd) jcplcd,
RTRIM(jcpart) jcpart,
jcunit,
jcvoll,
jcpric,
@ -179,6 +179,6 @@ SELECT
vb_to,
price_pc AS price
FROM
ranged
ORDER BY
jcpart, vb_from;
ranged;
--CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to);

View File

@ -0,0 +1,14 @@
DROP TABLE pricing.pricelist_ranged;
CREATE TABLE pricing.pricelist_ranged (
jcplcd varchar(5) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
jcpart varchar(20) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
jcunit varchar(3) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
jcvoll numeric(12,5) NOT NULL,
jcpric numeric(12,5) NOT NULL,
vb_from float NULL,
vb_to float NULL,
price float NOT NULL
);
CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON FAnalysis.PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ;