price_api/new_targets/procs/single_price_call.ms.sql

463 lines
17 KiB
Transact-SQL

CREATE OR ALTER PROCEDURE pricing.single_price_call
@bill VARCHAR(100),
@ship VARCHAR(100),
@part VARCHAR(100),
@v1ds VARCHAR(100),
@vol NUMERIC(18,6)
AS
BEGIN
SET NOCOUNT ON;
-- Working table for enriched pricing request
DECLARE @queue TABLE (
bill VARCHAR(100),
ship VARCHAR(100),
part VARCHAR(100),
stlc VARCHAR(100),
partgroup VARCHAR(100),
v1ds VARCHAR(100),
vol NUMERIC(18,6),
chan VARCHAR(50),
cust VARCHAR(100),
tier VARCHAR(50),
pltq NUMERIC(18,6),
volume_range TEXT,
plevel NVARCHAR(20),
listprice NUMERIC(20,5),
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),
-- 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)
);
--------------------------------------------------------------------------------
-- Step 1: Seed the queue with input row
--------------------------------------------------------------------------------
INSERT INTO @queue (bill, ship, part, v1ds, vol, expl)
VALUES (@bill, @ship, @part, @v1ds, @vol, '{}');
--------------------------------------------------------------------------------
-- Step 2: Enrich with channel, tier, customer, pack quantity, and price level
--------------------------------------------------------------------------------
UPDATE q
SET
chan =
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3)
WHEN 'DIS' THEN 'WHS'
ELSE 'DRP'
END
ELSE 'DIR'
END,
tier =
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIR' THEN bc.tier
ELSE ISNULL(sc.tier, bc.tier)
END,
cust =
CASE SUBSTRING(bc.cclass, 2, 3)
WHEN 'DIS' THEN
CASE SUBSTRING(sc.cclass, 2, 3)
WHEN 'DIS' THEN bc.dba
ELSE sc.dba
END
ELSE q.bill
END,
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,
stlc = substring(q.part,1,8),
partgroup = i.partgroup
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 target price and embed metadata as JSON
--------------------------------------------------------------------------------
UPDATE q
SET
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
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: 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]
-- JSON_QUERY(hist) AS [history]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 5: Add list price info from external pricelist
--------------------------------------------------------------------------------
WITH ranked_prices AS (
SELECT
q.bill, q.ship, q.part, q.stlc, q.v1ds, q.vol,
CAST(p.price AS NUMERIC(20,5)) AS 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
)
,listcode = rp.jcplcd
,listprice = rp.price
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 6: Compute guidance price and logic, and embed in JSON
--------------------------------------------------------------------------------
UPDATE q
SET
guidance_price = g.guidance_price,
guidance_reason = g.guidance_reason,
expl = JSON_MODIFY(
JSON_MODIFY(
ISNULL(q.expl, '{}'),
'$.guidance_reason',
g.guidance_reason
),
'$.guidance_price',
g.guidance_price
)
FROM @queue q
CROSS APPLY pricing.guidance_logic(
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(last_date AS DATE)
) g;
--------------------------------------------------------------------------------
-- Step 7: Clean up for UI
--------------------------------------------------------------------------------
UPDATE q
SET ui_json = (
SELECT
(
SELECT
panel.label,
JSON_QUERY(panel.details) AS details
FROM (
-- History Panel
SELECT
'History' AS label,
(
SELECT
CASE
WHEN q.last_price IS NOT NULL THEN 'Last Sale: ' + CAST(q.last_date AS varchar(10))
ELSE 'No Recent'
END AS label,
COALESCE(q.last_price,0) AS value,
CASE
WHEN q.last_price IS NOT NULL THEN 'currency'
ELSE 'currency'
END AS type,
CASE
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
) AS details
UNION ALL
-- List Panel
SELECT
'List' AS label,
(
SELECT
'List:' + q.listcode AS label,
q.listprice AS value,
'currency' AS type,
q.plevel AS note
FOR JSON PATH
)
UNION ALL
-- Target Support Panel
SELECT
'Target Support' AS label,
(
SELECT
RTRIM(SUBSTRING(value,1,18)) AS label,
TRY_CAST(SUBSTRING(value,23,7) AS NUMERIC(20,5))
+ CASE SUBSTRING(value,19,1) WHEN '+' THEN 0 ELSE -1 END AS value,
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'currency' ELSE 'percentage' END AS type,
CASE SUBSTRING(value,19,1) WHEN '+' THEN 'Price' ELSE 'Premium' END AS note
FROM OPENJSON(q.expl, '$.target_math')
WITH (value NVARCHAR(MAX) '$')
FOR JSON PATH
) AS details
UNION ALL
-- Guidance Panel
SELECT
'Guidance' AS label,
(
SELECT
'Price' AS label,
q.guidance_price AS value,
'currency' AS type,
q.guidance_reason AS note
FOR JSON PATH
)
) AS panel
FOR JSON PATH
) AS details,
JSON_QUERY(q.expl) AS data -- 👈 adds the full expl content as a JSON object
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER -- 👈 make it a single JSON object
)
FROM @queue q;
--------------------------------------------------------------------------------
-- Final: Return the enriched result row
--------------------------------------------------------------------------------
--SELECT guidance_price, hist, expl, ui_json FROM @queue;
SELECT * FROM @queue;
END;