get rid of old files and update matrix process to mirror single price calls

This commit is contained in:
Paul Trowbridge 2025-08-07 00:24:28 -04:00
parent 8d1c6995c6
commit 3468ba1faf
4 changed files with 117 additions and 354 deletions

View File

@ -1,264 +0,0 @@
--------------------------------------------------------------------------------
-- Step 1: Rebuild last price history at sales matrix refresh time
--------------------------------------------------------------------------------
DELETE FROM pricing.lastprice;
WITH
--------SORT--------
srt AS (
SELECT
o."Customer" customer,
o."Part Group" partgroup,
RTRIM(i.V1DS) dataseg,
o."Data Source" version,
o."Part Code" part,
o."Units" qty,
ROUND(o.[Value USD] / o.[Units], 5) AS price,
o.[Order Date] odate,
o.[Order Season] oseas,
o.[Order Number] ordnum,
o.[Quote Number] quoten,
ROW_NUMBER() OVER (
PARTITION BY o.Customer , o.[Part Group] , i.V1DS, o.[Data Source]
ORDER BY o."Order Date" DESC
) AS rn
FROM
rlarp.osm_stack_pretty o
INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i ON
i.item = o.[Part Code]
WHERE
--quotes can't be integrated until we have datasegment or correct part code
o.[Data Source] IN ('Actual','Quotes') AND
customer IS NOT NULL AND
[Financial Statement Line] = '41010' AND
o.[Order Status] <> 'CANCELLED' AND
o.Units <> 0 AND
o.[Part Group] <> ''
),
json_rows AS (
SELECT
customer,
partgroup,
dataseg,
version,
CONCAT(
'"', dataseg, '":',
(
SELECT version, part, qty, price, odate, ordnum, quoten
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
) AS part_json
FROM srt
WHERE rn = 1
)
,onerow AS (
SELECT
customer,
partgroup,
CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats
FROM json_rows
GROUP BY customer, partgroup
)
--SELECT * INTO pricing.lastprice FROM onerow;
INSERT INTO pricing.lastprice SELECT * FROM onerow;
--SELECT * FROM pricing.lastprice l
CREATE UNIQUE INDEX lastprice_cust_partgroup ON pricing.lastprice(customer, partgroup);
--------------------------------------------------------------------------------
-- Step 1: Rebuild last price history with flags for recency & feature-match
--------------------------------------------------------------------------------
--------------------------------------------------------------------------------
-- Step 1: Rebuild last price history with global recency + part-level feature match
--------------------------------------------------------------------------------
DELETE FROM pricing.lastprice;
WITH base AS (
SELECT
o."Customer" AS customer,
o."Part Group" AS partgroup,
RTRIM(i.V1DS) AS dataseg,
o."Data Source" AS version, -- 'Actual' or 'Quotes'
o."Part Code" AS part,
o."Units" AS qty,
ROUND(o.[Value USD] / o.[Units], 5) AS price,
o.[Order Date] AS odate,
o.[Order Number] AS ordnum,
o.[Quote Number] AS quoten
FROM
rlarp.osm_stack_pretty o
INNER JOIN CMSInterfaceIn.[CMS.CUSLG].ITEMM i
ON i.item = o.[Part Code]
WHERE
o.[Data Source] IN ('Actual', 'Quotes') AND
o."Customer" IS NOT NULL AND
o."Financial Statement Line" = '41010' AND
o."Order Status" <> 'CANCELLED' AND
o."Units" <> 0 AND
o."Part Group" <> ''
),
ranked AS (
SELECT
b.*,
ROW_NUMBER() OVER (
PARTITION BY b.customer, b.partgroup
ORDER BY CASE WHEN b.version = 'Actual' THEN b.odate ELSE NULL END DESC
) AS rn_recent_sale,
ROW_NUMBER() OVER (
PARTITION BY b.customer, b.partgroup
ORDER BY CASE WHEN b.version = 'Quotes' THEN b.odate ELSE NULL END DESC
) AS rn_recent_quote
FROM base b
),
last_feature_sale AS (
SELECT *
FROM (
SELECT *,
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup, part
ORDER BY odate DESC
) AS rn
FROM base
WHERE version = 'Actual'
) x
WHERE rn = 1
),
last_feature_quote AS (
SELECT *
FROM (
SELECT *,
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup, part
ORDER BY odate DESC
) AS rn
FROM base
WHERE version = 'Quotes'
) x
WHERE rn = 1
),
flagged AS (
SELECT
r.*,
CASE WHEN rn_recent_sale = 1 THEN 'most_recent_sale' END AS flag1,
CASE WHEN rn_recent_quote = 1 THEN 'most_recent_quote' END AS flag2,
CASE
WHEN r.version = 'Actual'
AND r.customer = s.customer
AND r.partgroup = s.partgroup
AND r.part = s.part
AND r.odate = s.odate
AND r.ordnum = s.ordnum
THEN 'last_feature_match_sale'
END AS flag3,
CASE
WHEN r.version = 'Quotes'
AND r.customer = q.customer
AND r.partgroup = q.partgroup
AND r.part = q.part
AND r.odate = q.odate
AND r.quoten = q.quoten
THEN 'last_feature_match_quote'
END AS flag4
FROM ranked r
LEFT JOIN last_feature_sale s
ON r.version = 'Actual'
AND r.customer = s.customer
AND r.partgroup = s.partgroup
AND r.part = s.part
LEFT JOIN last_feature_quote q
ON r.version = 'Quotes'
AND r.customer = q.customer
AND r.partgroup = q.partgroup
AND r.part = q.part
)
SELECT * FROM flagged WHERE customer LIKE 'ESBENSHADE%' AND partgroup = 'XNS0T1G3' AND flag3 = 'last_feature_match_sale'
flags_aggregated AS (
SELECT
customer,
partgroup,
dataseg,
version,
part,
qty,
price,
odate,
ordnum,
quoten,
JSON_QUERY(
'[' + STRING_AGG(QUOTENAME(flag, '"'), ',') + ']'
) AS flags
FROM (
SELECT
customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten,
flag
FROM flagged
CROSS APPLY (VALUES (flag1), (flag2), (flag3), (flag4)) AS f(flag)
WHERE flag IS NOT NULL
) AS flags_expanded
GROUP BY customer, partgroup, dataseg, version, part, qty, price, odate, ordnum, quoten
),
all_rows_with_flags AS (
SELECT
b.customer,
b.partgroup,
b.dataseg,
b.version,
b.part,
b.qty,
b.price,
b.odate,
b.ordnum,
b.quoten,
ISNULL(f.flags, JSON_QUERY('[]')) AS flags
FROM base b
LEFT JOIN flags_aggregated f
ON b.customer = f.customer
AND b.partgroup = f.partgroup
AND b.dataseg = f.dataseg
AND b.version = f.version
AND b.part = f.part
AND b.qty = f.qty
AND b.price = f.price
AND b.odate = f.odate
AND b.ordnum = f.ordnum
AND ISNULL(b.quoten, -1) = ISNULL(f.quoten, -1)
),
json_rows AS (
SELECT
customer,
partgroup,
dataseg,
CONCAT(
'"', dataseg, '":',
(
SELECT
version, part, qty, price, odate, ordnum, quoten, flags
FROM all_rows_with_flags sub
WHERE sub.customer = main.customer
AND sub.partgroup = main.partgroup
AND sub.dataseg = main.dataseg
FOR JSON PATH
)
) AS part_json
FROM all_rows_with_flags main
GROUP BY customer, partgroup, dataseg
),
onerow AS (
SELECT
customer,
partgroup,
CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats
FROM json_rows
GROUP BY customer, partgroup
)
INSERT INTO pricing.lastprice
SELECT * FROM onerow;
CREATE UNIQUE INDEX lastprice_cust_partgroup ON pricing.lastprice(customer, partgroup);

View File

@ -1,52 +0,0 @@
CREATE TABLE pricequote.lastprice AS (
WITH
--------SORT--------
srt AS (
SELECT
customer
,partgroup
,dataseg
,qtyord
,ROUND(sales_usd/qty,5) price
,odate
,oseas
,ordnum
,quoten
,row_number() OVER (PARTITION BY customer, partgroup, dataseg, version ORDER BY odate DESC) seq
,version
FROM
rlarp.osm_stack
WHERE
version IN ('Actual','Quotes')
AND customer IS NOT NULL
AND fs_line = '41010'
AND calc_status <> 'CANCELLED'
-- AND customer = 'ALTMAN PLANTS'
AND qty <> 0
AND partgroup <> ''
AND version = 'Actual'
-- LIMIT 10000
)
,onerow AS (
SELECT
customer,
partgroup,
-- Latest per-dataseg sales wrapped as JSONB object
jsonb_object_agg(
dataseg,
to_jsonb(srt)
ORDER BY odate DESC
) AS dataseg_stats
FROM
srt
WHERE
seq = 1
-- AND customer = 'ALTMAN PLANTS'
-- AND partgroup ~ 'XPR15CS'
GROUP BY customer, partgroup
-- ORDER BY customer, partgroup
)
SELECT * FROM onerow --WHERE customer = 'ALTMAN PLANTS' AND partgroup = 'XPR15CS1'
) WITH DATA;
SELECT * FROM pricequote.lastprice

View File

@ -14,16 +14,21 @@ CREATE TABLE pricequote.queue (
pltq NUMERIC, pltq NUMERIC,
plevel TEXT, plevel TEXT,
last_price NUMERIC, last_price NUMERIC,
last_qty NUMERIC,
last_dataseg TEXT,
last_date DATE, last_date DATE,
last_order TEXT, last_order TEXT,
last_quote TEXT, last_quote TEXT,
last_source TEXT,
tprice NUMERIC, tprice NUMERIC,
tmath JSONB,
volume_range TEXT,
list_price NUMERIC, list_price NUMERIC,
list_code TEXT, list_code TEXT,
guidance_price NUMERIC, guidance_price NUMERIC,
guidance_reason TEXT, guidance_reason TEXT,
expl JSONB, expl JSONB,
this JSONB, ui_json JSONB,
partgroup TEXT partgroup TEXT
); );
@ -48,7 +53,7 @@ ON pricequote.queue (
vol vol
); );
--DROP PROCEDURE IF EXISTS pricequote.process_queue; --DROP PROCEDURE IF EXISTS pricequote.process_queue;
CREATE OR REPLACE PROCEDURE pricequote.process_queue() CREATE OR REPLACE PROCEDURE pricequote.process_queue()
@ -162,24 +167,111 @@ BEGIN
AND FLOOR(q.vol / NULLIF(q.pltq, 0))::int <@ tp.vol; AND FLOOR(q.vol / NULLIF(q.pltq, 0))::int <@ tp.vol;
----------------------------------------------------------------------- -----------------------------------------------------------------------
-- Step 4: Lookup most recent price history and embed it -- Step 4: Lookup price history and embed all relevant keys and precedence
----------------------------------------------------------------------- -----------------------------------------------------------------------
UPDATE pricequote.queue q UPDATE pricequote.queue q
SET SET
last_price = ((lp.dataseg_stats -> q.v1ds)::jsonb ->> 'price')::numeric, last_price = COALESCE(
last_date = ((lp.dataseg_stats -> q.v1ds)::jsonb ->> 'odate')::date, (hist -> q.v1ds -> 'dsq' ->> 'price')::numeric,
last_order = (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'ordnum', (hist -> q.v1ds -> 'dss' ->> 'price')::numeric,
last_quote = (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'quoten', (hist -> 'mrq' ->> 'price')::numeric,
(hist -> 'mrs' ->> 'price')::numeric
),
last_qty = COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'qty')::numeric,
(hist -> q.v1ds -> 'dss' ->> 'qty')::numeric,
(hist -> 'mrq' ->> 'qty')::numeric,
(hist -> 'mrs' ->> 'qty')::numeric
),
last_dataseg = COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'datasegment'),
(hist -> q.v1ds -> 'dss' ->> 'datasegment'),
(hist -> 'mrq' ->> 'datasegment'),
(hist -> 'mrs' ->> 'datasegment')
),
last_date = COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'odate')::date,
(hist -> q.v1ds -> 'dss' ->> 'odate')::date,
(hist -> 'mrq' ->> 'odate')::date,
(hist -> 'mrs' ->> 'odate')::date
),
last_order = COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'ordnum'),
(hist -> q.v1ds -> 'dss' ->> 'ordnum'),
(hist -> 'mrq' ->> 'ordnum'),
(hist -> 'mrs' ->> 'ordnum')
),
last_quote = COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'quoten'),
(hist -> q.v1ds -> 'dss' ->> 'quoten'),
(hist -> 'mrq' ->> 'quoten'),
(hist -> 'mrs' ->> 'quoten')
),
last_source = CASE
WHEN (hist -> q.v1ds -> 'dsq' ->> 'price') IS NOT NULL THEN 'dsq'
WHEN (hist -> q.v1ds -> 'dss' ->> 'price') IS NOT NULL THEN 'dss'
WHEN (hist -> 'mrq' ->> 'price') IS NOT NULL THEN 'mrq'
WHEN (hist -> 'mrs' ->> 'price') IS NOT NULL THEN 'mrs'
ELSE NULL
END,
expl = q.expl || jsonb_build_object( expl = q.expl || jsonb_build_object(
'last_price', ((lp.dataseg_stats -> q.v1ds)::jsonb ->> 'price')::numeric, 'last_price', COALESCE(
'last_date', (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'odate', (hist -> q.v1ds -> 'dsq' ->> 'price')::numeric,
'last_order', (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'ordnum', (hist -> q.v1ds -> 'dss' ->> 'price')::numeric,
'last_quote', (lp.dataseg_stats -> q.v1ds)::jsonb ->> 'quoten' (hist -> 'mrq' ->> 'price')::numeric,
(hist -> 'mrs' ->> 'price')::numeric
),
'last_qty', COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'qty')::numeric,
(hist -> q.v1ds -> 'dss' ->> 'qty')::numeric,
(hist -> 'mrq' ->> 'qty')::numeric,
(hist -> 'mrs' ->> 'qty')::numeric
),
'last_dataseg', COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'datasegment'),
(hist -> q.v1ds -> 'dss' ->> 'datasegment'),
(hist -> 'mrq' ->> 'datasegment'),
(hist -> 'mrs' ->> 'datasegment')
),
'last_source', CASE
WHEN (hist -> q.v1ds -> 'dsq' ->> 'price') IS NOT NULL THEN 'dsq'
WHEN (hist -> q.v1ds -> 'dss' ->> 'price') IS NOT NULL THEN 'dss'
WHEN (hist -> 'mrq' ->> 'price') IS NOT NULL THEN 'mrq'
WHEN (hist -> 'mrs' ->> 'price') IS NOT NULL THEN 'mrs'
ELSE NULL
END,
'last_date', COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'odate')::date,
(hist -> q.v1ds -> 'dss' ->> 'odate')::date,
(hist -> 'mrq' ->> 'odate')::date,
(hist -> 'mrs' ->> 'odate')::date
),
'last_order', COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'ordnum'),
(hist -> q.v1ds -> 'dss' ->> 'ordnum'),
(hist -> 'mrq' ->> 'ordnum'),
(hist -> 'mrs' ->> 'ordnum')
),
'last_quote', COALESCE(
(hist -> q.v1ds -> 'dsq' ->> 'quoten'),
(hist -> q.v1ds -> 'dss' ->> 'quoten'),
(hist -> 'mrq' ->> 'quoten'),
(hist -> 'mrs' ->> 'quoten')
),
'mrs', hist -> 'mrs',
'mrq', hist -> 'mrq',
'lvs', hist -> 'lvs',
'lvq', hist -> 'lvq',
'dss', hist -> q.v1ds -> 'dss',
'dsq', hist -> q.v1ds -> 'dsq'
) )
FROM pricequote.lastprice lp FROM (
WHERE SELECT q.ctid, lp.part_stats AS hist
lp.customer = q.cust FROM pricequote.queue q
AND lp.partgroup = q.partgroup; JOIN pricequote.lastpricedetail lp
ON lp.customer = q.cust AND lp.partgroup = q.partgroup
) sub
WHERE q.ctid = sub.ctid;
----------------------------------------------------------------------- -----------------------------------------------------------------------
-- Step 5: Resolve best list price and insert it with list code -- Step 5: Resolve best list price and insert it with list code
@ -244,16 +336,16 @@ BEGIN
----------------------------------------------------------------------- -----------------------------------------------------------------------
-- Step 7: merge the results back into sales matrix -- Step 7: merge the results back into sales matrix
----------------------------------------------------------------------- -----------------------------------------------------------------------
UPDATE rlarp.osm_stack o UPDATE rlarp.osm_stack o
SET pricing = pricing || q.expl SET pricing = pricing || q.expl
FROM pricequote.queue q FROM pricequote.queue q
WHERE WHERE
o.bill_cust = q.bill o.bill_cust = q.bill
AND o.ship_cust IS NOT DISTINCT FROM q.ship AND o.ship_cust IS NOT DISTINCT FROM q.ship
AND o.part = q.part AND o.part = q.part
AND o.stlc = q.stlc AND o.stlc = q.stlc
AND o.dataseg = q.v1ds AND o.dataseg = q.v1ds
AND o.qtyord = q.vol AND o.qtyord = q.vol
AND o.fs_line = '41010' AND o.fs_line = '41010'
AND o.calc_status <> 'CANCELLED' AND o.calc_status <> 'CANCELLED'
AND o.version IN ('Actual', 'Forecast', 'Quotes') AND o.version IN ('Actual', 'Forecast', 'Quotes')

View File

@ -1,13 +0,0 @@
-- FAnalysis.PRICING.lastprice definition
-- Drop table
-- DROP TABLE FAnalysis.PRICING.lastprice;
CREATE TABLE pricing.lastprice (
customer varchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
mold varchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
part_stats nvarchar(MAX) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL
);
CREATE UNIQUE NONCLUSTERED INDEX lastprice_cust_mold ON FAnalysis.PRICING.lastprice (customer ASC, mold ASC) ;