convert price history to work off part group and data segment

This commit is contained in:
Paul Trowbridge 2025-08-05 20:53:14 -04:00
parent 7a73748b2a
commit f013c5ccc2
2 changed files with 36 additions and 28 deletions

View File

@ -14,6 +14,7 @@ BEGIN
ship VARCHAR(100), ship VARCHAR(100),
part VARCHAR(100), part VARCHAR(100),
stlc VARCHAR(100), stlc VARCHAR(100),
partgroup VARCHAR(100),
v1ds VARCHAR(100), v1ds VARCHAR(100),
vol NUMERIC(18,6), vol NUMERIC(18,6),
chan VARCHAR(50), chan VARCHAR(50),
@ -80,7 +81,8 @@ BEGIN
END END
ELSE bc.plevel ELSE bc.plevel
END, END,
stlc = substring(q.part,1,8) stlc = substring(q.part,1,8),
partgroup = i.partgroup
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
@ -143,19 +145,20 @@ BEGIN
FROM @queue q FROM @queue q
JOIN pricing.lastprice lp JOIN pricing.lastprice lp
ON lp.customer = q.cust ON lp.customer = q.cust
AND lp.mold = SUBSTRING(q.part, 1, 8) AND lp.partgroup = q.partgroup
OUTER APPLY ( OUTER APPLY (
SELECT TOP 1 * SELECT TOP 1 *
FROM OPENJSON(lp.part_stats) AS p FROM OPENJSON(lp.part_stats) AS p
OUTER APPLY OPENJSON(p.value) OUTER APPLY OPENJSON(p.value)
WITH ( WITH (
part VARCHAR(100),
qty NUMERIC(20,5), qty NUMERIC(20,5),
price NUMERIC(20,5), price NUMERIC(20,5),
odate DATE, odate DATE,
ordnum INT, ordnum INT,
quoten INT quoten INT
) AS j ) AS j
WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.v1ds
ORDER BY j.odate DESC ORDER BY j.odate DESC
) AS j; ) AS j;

View File

@ -3,47 +3,49 @@
-------------------------------------------------------------------------------- --------------------------------------------------------------------------------
DELETE FROM pricing.lastprice; DELETE FROM pricing.lastprice;
WITH WITH
--------SORT-------- --------SORT--------
srt AS ( srt AS (
SELECT SELECT
"Customer" customer, o."Customer" customer,
"Part Group" partgroup, o."Part Group" partgroup,
i.v1ds dataseg, RTRIM(i.V1DS) dataseg,
"Data Source" version, o."Data Source" version,
"Units" qty, o."Part Code" part,
ROUND(sales_usd / qty, 5) AS price, o."Units" qty,
odate, ROUND(o.[Value USD] / o.[Units], 5) AS price,
oseas, o.[Order Date] odate,
ordnum, o.[Order Season] oseas,
quoten, o.[Order Number] ordnum,
o.[Quote Number] quoten,
ROW_NUMBER() OVER ( ROW_NUMBER() OVER (
PARTITION BY customer, mold, part, version PARTITION BY o.Customer , o.[Part Group] , i.V1DS, o.[Data Source]
ORDER BY odate DESC ORDER BY o."Order Date" DESC
) AS rn ) AS rn
FROM FROM
rlarp.osm_stack_pretty o rlarp.osm_stack_pretty o
INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i ON INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i ON
i.item = o.part i.item = o.[Part Code]
WHERE WHERE
--quotes can't be integrated until we have datasegment or correct part code --quotes can't be integrated until we have datasegment or correct part code
version IN ('Actual'/*,'Quotes'*/) AND o.[Data Source] IN ('Actual'/*,'Quotes'*/) AND
customer IS NOT NULL AND customer IS NOT NULL AND
fs_line = '41010' AND [Financial Statement Line] = '41010' AND
calc_status <> 'CANCELLED' AND o.[Order Status] <> 'CANCELLED' AND
qty <> 0 AND o.Units <> 0 AND
mold <> '' o.[Part Group] <> ''
), ),
json_rows AS ( json_rows AS (
SELECT SELECT
customer, customer,
mold, partgroup,
part, dataseg,
version, version,
CONCAT( CONCAT(
'"', part, '":', '"', dataseg, '":',
( (
SELECT version, qty, price, odate, ordnum, quoten SELECT version, part, qty, price, odate, ordnum, quoten
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
) )
) AS part_json ) AS part_json
@ -53,11 +55,14 @@ json_rows AS (
,onerow AS ( ,onerow AS (
SELECT SELECT
customer, customer,
mold, partgroup,
CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats
FROM json_rows FROM json_rows
GROUP BY customer, mold GROUP BY customer, partgroup
) )
--SELECT * INTO pricing.lastprice FROM onerow;
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); --SELECT * FROM pricing.lastprice l
CREATE UNIQUE INDEX lastprice_cust_partgroup ON pricing.lastprice(customer, partgroup);