call out evey last price object

This commit is contained in:
Paul Trowbridge 2025-08-06 14:11:38 -04:00
parent 8b6df1c917
commit d25f4fd838

View File

@ -27,14 +27,60 @@ BEGIN
listcode VARCHAR(10),
hist NVARCHAR(MAX),
last_price NUMERIC(20,5),
last_qty NUMERIC(20,5),
last_date DATE,
last_order NVARCHAR(10),
last_quote NVARCHAR(10),
last_dataseg NVARCHAR(20),
last_source NVARCHAR(100),
tprice NUMERIC(20,5),
tmath nvarchar(MAX),
guidance_price NUMERIC(20,5),
guidance_reason NVARCHAR(MAX),
expl NVARCHAR(MAX),
ui_json NVARCHAR(MAX)
ui_json NVARCHAR(MAX),
-- most recent sale
mrs_price NUMERIC(20,5),
mrs_qty NUMERIC(20,5),
mrs_dataseg VARCHAR(100),
mrs_date DATE ,
mrs_order VARCHAR(10),
mrs_quote VARCHAR(10),
-- most recent quote
mrq_price NUMERIC(20,5),
mrq_qty NUMERIC(20,5),
mrq_dataseg VARCHAR(100),
mrq_date DATE ,
mrq_order VARCHAR(10),
mrq_quote VARCHAR(10),
-- last volume sales
lvs_price NUMERIC(20,5),
lvs_qty NUMERIC(20,5),
lvs_dataseg VARCHAR(100),
lvs_date DATE ,
lvs_order VARCHAR(10),
lvs_quote VARCHAR(10),
-- last volume quote
lvq_price NUMERIC(20,5),
lvq_qty NUMERIC(20,5),
lvq_dataseg VARCHAR(100),
lvq_date DATE ,
lvq_order VARCHAR(10),
lvq_quote VARCHAR(10),
-- datasegment last sale
dss_price NUMERIC(20,5),
dss_qty NUMERIC(20,5),
dss_dataseg VARCHAR(100),
dss_date DATE ,
dss_order VARCHAR(10),
dss_quote VARCHAR(10),
-- datasegment last quote
dsq_price NUMERIC(20,5),
dsq_qty NUMERIC(20,5),
dsq_dataseg VARCHAR(100),
dsq_date DATE ,
dsq_order VARCHAR(10),
dsq_quote VARCHAR(10)
);
--------------------------------------------------------------------------------
@ -93,21 +139,9 @@ BEGIN
--------------------------------------------------------------------------------
UPDATE q
SET
tprice = tp.price,
expl = (
SELECT
'target price' AS [source],
tp.price AS [target_price],
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,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],
TRIM(q.tier) AS [tier],
JSON_QUERY(tp.math) AS [target_math]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
),
volume_range = CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), ''))
tprice = tp.price
,tmath = JSON_QUERY(tp.math)
,volume_range = CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), ''))
FROM @queue q
INNER JOIN pricing.target_prices tp ON
q.stlc = tp.stlc
@ -119,48 +153,153 @@ BEGIN
tp.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tp.upper_bound
);
--------------------------------------------------------------------------------
-- Step 4: Pull last sale data and embed in columns and JSON
--------------------------------------------------------------------------------
UPDATE q
SET
hist = JSON_MODIFY('{}', '$.full_history', JSON_QUERY(lp.part_stats)),
last_price = j.price,
last_date = j.odate,
last_order = j.ordnum,
last_quote = j.quoten,
expl = JSON_MODIFY(
JSON_MODIFY(
JSON_MODIFY(
JSON_MODIFY(
ISNULL(q.expl, '{}'),
'$.last_price', j.price
),
'$.last_date', CONVERT(NVARCHAR(10), j.odate, 23)
),
'$.last_order', j.ordnum
),
'$.last_quote', j.quoten
)
FROM @queue q
JOIN pricing.lastprice lp
ON lp.customer = q.cust
AND lp.partgroup = q.partgroup
OUTER APPLY (
SELECT TOP 1 *
FROM OPENJSON(lp.part_stats) AS p
OUTER APPLY OPENJSON(p.value)
WITH (
part VARCHAR(100),
qty NUMERIC(20,5),
price NUMERIC(20,5),
odate DATE,
ordnum INT,
quoten INT
) AS j
WHERE p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.v1ds
ORDER BY j.odate DESC
) AS j;
--------------------------------------------------------------------------------
-- Step 4: Pull last sale data and embed in columns and JSON
--------------------------------------------------------------------------------
UPDATE q
SET
hist = JSON_MODIFY('{}', '$.full_history', JSON_QUERY(lp.part_stats)),
-- Top-level flags
mrs_price = mrs.price, mrs_qty = mrs.qty, mrs_dataseg = mrs.datasegment, mrs_date = mrs.odate, mrs_order = mrs.ordnum, mrs_quote = mrs.quoten,
mrq_price = mrq.price, mrq_qty = mrq.qty, mrq_dataseg = mrq.datasegment, mrq_date = mrq.odate, mrq_order = mrq.ordnum, mrq_quote = mrq.quoten,
lvs_price = lvs.price, lvs_qty = lvs.qty, lvs_dataseg = lvs.datasegment, lvs_date = lvs.odate, lvs_order = lvs.ordnum, lvs_quote = lvs.quoten,
lvq_price = lvq.price, lvq_qty = lvq.qty, lvq_dataseg = lvq.datasegment, lvq_date = lvq.odate, lvq_order = lvq.ordnum, lvq_quote = lvq.quoten,
-- Data segment-local flags
dss_price = dss.price, dss_qty = dss.qty, dss_dataseg = dss.datasegment, dss_date = dss.odate, dss_order = dss.ordnum, dss_quote = dss.quoten,
dsq_price = dsq.price, dsq_qty = dsq.qty, dsq_dataseg = dsq.datasegment, dsq_date = dsq.odate, dsq_order = dsq.ordnum, dsq_quote = dsq.quoten
FROM @queue q
JOIN pricing.lastpricedetail lp
ON lp.customer = q.cust AND lp.partgroup = q.partgroup
-- Extract top-level keys
OUTER APPLY OPENJSON(lp.part_stats)
WITH (
mrs NVARCHAR(MAX) AS JSON,
mrq NVARCHAR(MAX) AS JSON,
lvs NVARCHAR(MAX) AS JSON,
lvq NVARCHAR(MAX) AS JSON
) AS flags
OUTER APPLY OPENJSON(flags.mrs)
WITH (
price NUMERIC(20,5),
qty NUMERIC(20,5),
datasegment VARCHAR(100),
odate DATE,
ordnum BIGINT,
quoten BIGINT
) AS mrs
OUTER APPLY OPENJSON(flags.mrq)
WITH (
price NUMERIC(20,5),
qty NUMERIC(20,5),
datasegment VARCHAR(100),
odate DATE,
ordnum BIGINT,
quoten BIGINT
) AS mrq
OUTER APPLY OPENJSON(flags.lvs)
WITH (
price NUMERIC(20,5),
qty NUMERIC(20,5),
datasegment VARCHAR(100),
odate DATE,
ordnum BIGINT,
quoten BIGINT
) AS lvs
OUTER APPLY OPENJSON(flags.lvq)
WITH (
price NUMERIC(20,5),
qty NUMERIC(20,5),
datasegment VARCHAR(100),
odate DATE,
ordnum BIGINT,
quoten BIGINT
) AS lvq
-- Extract per-datasegment block matching the input v1ds
OUTER APPLY (
SELECT value
FROM OPENJSON(lp.part_stats)
WHERE [key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.v1ds
) AS dsblock
-- Extract dss/dsq objects from segment block
OUTER APPLY OPENJSON(dsblock.value)
WITH (
dss NVARCHAR(MAX) AS JSON,
dsq NVARCHAR(MAX) AS JSON
) AS segflags
OUTER APPLY OPENJSON(segflags.dss)
WITH (
price NUMERIC(20,5),
qty NUMERIC(20,5),
datasegment VARCHAR(100),
odate DATE,
ordnum BIGINT,
quoten BIGINT
) AS dss
OUTER APPLY OPENJSON(segflags.dsq)
WITH (
price NUMERIC(20,5),
qty NUMERIC(20,5),
datasegment VARCHAR(100),
odate DATE,
ordnum BIGINT,
quoten BIGINT
) AS dsq;
--------------------------------------------------------------------------------
-- Step 4b.1: Populate composite fields from precedence chain
--------------------------------------------------------------------------------
UPDATE q
SET
last_price = COALESCE(dsq_price, dss_price, mrq_price, mrs_price),
last_qty = COALESCE(dsq_qty, dss_qty, mrq_qty, mrs_qty),
last_dataseg = COALESCE(dsq_dataseg, dss_dataseg, mrq_dataseg, mrs_dataseg),
last_date = COALESCE(dsq_date, dss_date, mrq_date, mrs_date),
last_order = COALESCE(dsq_order, dss_order, mrq_order, mrs_order),
last_quote = COALESCE(dsq_quote, dss_quote, mrq_quote, mrs_quote),
last_source =
CASE
WHEN dsq_price IS NOT NULL THEN 'dsq'
WHEN dss_price IS NOT NULL THEN 'dss'
WHEN mrq_price IS NOT NULL THEN 'mrq'
WHEN mrs_price IS NOT NULL THEN 'mrs'
ELSE NULL
END
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 4b.2: Build JSON explanation object from populated columns
--------------------------------------------------------------------------------
UPDATE q
SET expl = (
SELECT
q.last_price AS last_price,
q.last_qty AS last_qty,
q.last_dataseg AS last_dataseg,
q.last_source AS last_source,
FORMAT(q.last_date, 'yyyy-MM-dd') AS last_date,
q.tprice AS [target_price],
JSON_QUERY(q.tmath) AS [target_math],
FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets],
CAST(ROUND(q.vol / NULLIF(q.pltq, 0), 5) AS NUMERIC(20,5)) AS [exact_pallets],
q.cust AS [customer],
q.chan AS [channel],
TRIM(q.tier) AS [tier]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 5: Add list price info from external pricelist
@ -225,7 +364,7 @@ BEGIN
CAST(JSON_VALUE(q.expl, '$.target_price') AS NUMERIC(20,5)),
CAST(JSON_VALUE(q.expl, '$.last_price') AS NUMERIC(20,5)),
CAST(JSON_VALUE(q.expl, '$.list_price') AS NUMERIC(20,5)),
CAST(JSON_VALUE(q.expl, '$.last_date') AS DATE)
CAST(last_date AS DATE)
) g;
--------------------------------------------------------------------------------
@ -254,7 +393,7 @@ BEGIN
ELSE 'currency'
END AS type,
CASE
WHEN q.last_price IS NOT NULL THEN 'Ord# ' + q.last_order
WHEN q.last_price IS NOT NULL THEN q.last_source + CASE WHEN q.last_order = 0 THEN ' Qt# ' + q.last_quote ELSE ' Ord# ' + q.last_order END
ELSE NULL
END AS note
FOR JSON PATH
@ -317,5 +456,5 @@ BEGIN
--------------------------------------------------------------------------------
-- Final: Return the enriched result row
--------------------------------------------------------------------------------
SELECT * FROM @queue;
SELECT guidance_price, expl, ui_json FROM @queue;
END;