price_api/procs/single_price_call.ms.sql

531 lines
20 KiB
Transact-SQL

/*
====================================================================================
Script: single_price_call.ms.sql
Purpose:
Single price call logic for SQL Server, designed to process a single scenario
(bill-to, ship-to, part, volume, and target data segment) and return enriched
pricing guidance along with explanation JSON for UI or API use.
-----------------------------------------------------------------------------------
Core Workflow:
1. **Seed Input**: Initialize queue with bill, ship, part, v1ds, vol.
2. **Customer & Channel Enrichment**:
- Resolve customer, channel, tier, pack quantity, price level.
- Classify and flag customized part scenarios when v1ds differs from part's own v1ds.
- Capture standard costs (current/future) and derive v0ds from v1ds.
3. **Last Price History**:
- Pull `part_stats` JSON from `pricing.lastpricedetail`.
- Extract most recent sale/quote via `pricing.pick_last_price_from_hist_json`.
- Flag part/dataseg mismatches (`last_isdiff`) and derive last v0ds.
4. **Target Price Application**:
- Lookup current and last target prices (matching respective v1ds).
- Store target price math JSON and pallet volume range.
5. **Cost Substitution & Normalization**:
- For customized or differing dataseg, substitute average costs from v1/v0 sources.
- Compute premiums and normalize last prices for comparison.
- Record calculation method (`Target Price Ratio` or `Cost Ratio`).
6. **List Price Selection**:
- From external `pricelist_ranged`, pick lowest valid list price in volume band.
- Nullify list price when customized, with relevance flag.
7. **Guidance Logic**:
- Pass target, normalized last, and list prices into `pricing.guidance_logic`.
- Return computed guidance price and rationale.
8. **JSON Explanation Build**:
- Assemble all pricing components into `expl` JSON for structured storage.
9. **UI JSON Build**:
- Package human-readable panels (History, List, Target Support, Guidance)
plus raw `expl` JSON into `ui_json`.
-----------------------------------------------------------------------------------
Inputs:
- @bill, @ship, @part, @v1ds, @vol
Reference Tables:
- pricing.target_prices
- pricing.lastpricedetail
- pricing.pricelist_ranged
- rlarp.cust
- CMS.CUSLG.itemm
- CMS.CUSLG.IPRCBHC
- rlarp.cost_v1ds / cost_v0ds
Outputs:
- Single row with:
* Enriched pricing attributes
* Target, last, list, and guidance prices
* Cost data and premiums
* `expl` JSON (raw detail)
* `ui_json` JSON (UI-ready panels)
Dependencies:
- pricing.guidance_logic()
- pricing.pick_last_price_from_hist_json()
Notes:
- Designed for single-row queries; see matrix_guidance.pg.sql for batch mode.
- Last price normalization ensures cross-segment comparisons are cost/target aligned.
- List price is ignored for customized part scenarios.
- Sequencing ensures:
* Historical context (last price) is established before guidance logic
* Target price and cost adjustments precede list price selection
====================================================================================
*/
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),
v1ds VARCHAR(100),
vol NUMERIC(18,6),
------------step 1 lookup scenario------------
chan VARCHAR(50),
tier VARCHAR(50),
cust VARCHAR(100),
pltq NUMERIC(18,6),
plevel NVARCHAR(20),
stlc VARCHAR(100),
partgroup VARCHAR(100),
part_v1ds VARCHAR(50),
v0ds VARCHAR(10),
curstd_orig NUMERIC(20,5),
futstd_orig NUMERIC(20,5),
customized VARCHAR(100),
calculated_pallets numeric(20,0),
exact_pallets numeric(20,5),
----------- step 2 last price------------------
hist NVARCHAR(MAX),
last_price NUMERIC(20,5),
last_source NVARCHAR(100),
last_date DATE,
last_qty NUMERIC(20,5),
last_dataseg NVARCHAR(20),
last_v0ds VARCHAR(10),
last_order NVARCHAR(10),
last_quote NVARCHAR(10),
last_isdiff NVARCHAR(100),
------------step 3 lookup target---------------
tprice NUMERIC(20,5),
tprice_last NUMERIC(20,5),
tmath nvarchar(MAX),
volume_range VARCHAR(100),
------------step 4 normalize last price--------
curstd NUMERIC(20,5),
futstd NUMERIC(20,5),
curstd_last NUMERIC(20,5),
futstd_last NUMERIC(20,5),
last_premium NUMERIC(20,5),
last_price_norm NUMERIC(20,5),
last_premium_method VARCHAR(100),
------------step 5 list price lookup-----------
listcode VARCHAR(10),
listprice NUMERIC(20,5),
listprice_eff NUMERIC(20,5),
list_relevance NVARCHAR(100),
------------step 6 compute guidance------------
guidance_price NUMERIC(20,5),
guidance_reason NVARCHAR(MAX),
------------step 7 build json------------------
expl NVARCHAR(MAX),
ui_json NVARCHAR(MAX)
);
--------------------------------------------------------------------------------
-- Step 1: Seed input
--------------------------------------------------------------------------------
INSERT INTO @queue (bill, ship, part, v1ds, vol, expl)
VALUES (@bill, @ship, @part, @v1ds, @vol, '{}');
--------------------------------------------------------------------------------
-- Step 2: Look up master data & costs
--------------------------------------------------------------------------------
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 = TRIM(i.partgroup),
part_v1ds = TRIM(i.v1ds),
v0ds =
CASE substring(q.v1ds,4,1) WHEN 'B' THEN 'B' ELSE 'C' END
+ CASE substring(q.v1ds,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END,
curstd_orig = i.curstdus,
futstd_orig = i.futstdus,
customized = CASE WHEN i.v1ds IS NOT NULL AND q.v1ds IS NOT NULL AND i.v1ds <> q.v1ds
THEN 'Customized' ELSE '' END,
calculated_pallets = FLOOR(q.vol / NULLIF(i.mpck, 0)),
exact_pallets = CAST(ROUND(q.vol / NULLIF(i.mpck, 0), 5) AS NUMERIC(20,5))
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: Lookup Last Price
--------------------------------------------------------------------------------
UPDATE q
SET
hist = lp.part_stats
FROM @queue q
JOIN pricing.lastpricedetail lp
ON lp.customer = q.cust AND lp.partgroup = q.partgroup;
-- Use new helper to select best last price, source, and date directly from JSON
UPDATE q
SET
last_price = b.price,
last_source = b.source,
last_date = b.odate,
last_qty = b.qty,
last_dataseg = b.dataseg,
last_v0ds =
CASE substring(b.dataseg,4,1) WHEN 'B' THEN 'B' ELSE 'C' END
+ CASE substring(b.dataseg,6,1) WHEN 'L' THEN 'L' WHEN 'P' THEN 'P' ELSE '' END,
last_order = b.ord,
last_quote = b.quote,
last_isdiff = CASE WHEN b.dataseg IS NOT NULL AND q.v1ds IS NOT NULL AND b.dataseg <> q.v1ds
THEN 'Last Sale Diff Part' ELSE '' END
FROM @queue q
CROSS APPLY (
SELECT TOP 1 price, source, odate, qty, dataseg, ord, quote
FROM pricing.pick_last_price_from_hist_json(q.hist, q.v1ds)
) b;
--------------------------------------------------------------------------------
-- Step 4: Lookup Target Price
--------------------------------------------------------------------------------
UPDATE q
SET
tprice = tp.price
,tprice_last = tpl.price
,tmath = JSON_QUERY(tp.math)
,volume_range = CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), ''))
FROM @queue q
LEFT 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 q.calculated_pallets >= tp.lower_bound
AND (
tp.upper_bound IS NULL OR q.calculated_pallets < tp.upper_bound
)
LEFT JOIN pricing.target_prices tpl ON
q.stlc = tpl.stlc
AND q.last_dataseg = tpl.ds
AND q.chan = tpl.chan
AND q.tier = tpl.tier
AND q.calculated_pallets >= tpl.lower_bound
AND (
tpl.upper_bound IS NULL OR q.calculated_pallets < tpl.upper_bound
);
--------------------------------------------------------------------------------
-- Step 5: Normalize last price if different from target product
--------------------------------------------------------------------------------
-- Goal data segment inherits part's original segment; if customized, pull available v1/v0 averages.
UPDATE q
SET
curstd = CASE WHEN customized = '' THEN q.curstd_orig ELSE COALESCE(v1.curstdus, v0.curstdus) END
,futstd = CASE WHEN customized = '' THEN q.futstd_orig ELSE COALESCE(v1.futstdus, v0.futstdus) END
,curstd_last = CASE WHEN last_isdiff = '' THEN q.curstd_orig ELSE COALESCE(v1l.curstdus, v0l.curstdus) END
,futstd_last = CASE WHEN last_isdiff = '' THEN q.futstd_orig ELSE COALESCE(v1l.futstdus, v0l.futstdus) END
FROM @queue q
LEFT JOIN rlarp.cost_v1ds v1 ON
v1.stlc = q.stlc
AND v1.v1ds = q.v1ds
LEFT JOIN rlarp.cost_v0ds v0 ON
v0.stlc = q.stlc
AND v0.v0ds = q.v0ds
LEFT JOIN rlarp.cost_v1ds v1l ON
v1l.stlc = q.stlc
AND v1l.v1ds = q.last_dataseg
LEFT JOIN rlarp.cost_v0ds v0l ON
v0l.stlc = q.stlc
AND v0l.v0ds = q.last_v0ds;
UPDATE q
SET
last_premium =
CASE WHEN q.last_isdiff <> '' THEN
CASE
WHEN tprice_last IS NOT NULL AND tprice IS NOT NULL AND tprice_last <> 0
THEN CAST(tprice / tprice_last AS NUMERIC(20,5))
WHEN curstd_last IS NOT NULL AND curstd IS NOT NULL AND curstd_last <> 0
THEN CAST(curstd / curstd_last AS NUMERIC(20,5))
ELSE NULL
END
ELSE NULL
END
,last_price_norm =
CASE WHEN q.last_isdiff <> '' THEN
CASE
WHEN tprice_last IS NOT NULL AND tprice IS NOT NULL AND tprice_last <> 0
THEN CAST(ROUND(q.last_price * (tprice / tprice_last), 5) AS NUMERIC(20,5))
WHEN curstd_last IS NOT NULL AND curstd IS NOT NULL AND curstd_last <> 0
THEN CAST(ROUND(q.last_price * (curstd / curstd_last), 5) AS NUMERIC(20,5))
ELSE q.last_price
END
ELSE q.last_price
END
,last_premium_method =
CASE
WHEN q.last_isdiff <> '' THEN
CASE
WHEN tprice_last IS NOT NULL AND tprice IS NOT NULL AND tprice_last <> 0
THEN 'Target Price Ratio'
WHEN curstd_last IS NOT NULL AND curstd IS NOT NULL AND curstd_last <> 0
THEN 'Cost Ratio'
ELSE 'Unknown'
END
ELSE NULL
END
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 6: Lookup List Price
--------------------------------------------------------------------------------
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
listcode = rp.jcplcd
,listprice = rp.price
,listprice_eff = CASE WHEN q.customized <> '' THEN NULL ELSE q.listprice END
,list_relevance = CASE WHEN q.customized <> '' THEN 'Ignore - Customized' ELSE '' END
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 7: Compute guidance logic from target, normalized last, list price, and last date.
--------------------------------------------------------------------------------
UPDATE q
SET
guidance_price = g.guidance_price
,guidance_reason = g.guidance_reason
FROM @queue q
CROSS APPLY pricing.guidance_logic(
TRY_CAST(q.tprice AS NUMERIC(20,5)),
TRY_CAST(q.last_price_norm AS NUMERIC(20,5)),
TRY_CAST(q.listprice_eff AS NUMERIC(20,5)),
TRY_CAST(q.last_date AS DATE)
) g;
--------------------------------------------------------------------------------
-- Step 8: Assemble structured 'expl' JSON 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_v0ds AS last_v0ds
,q.last_source AS last_source
,FORMAT(q.last_date, 'yyyy-MM-dd') AS last_date
,q.last_isdiff AS last_isdiff
,q.tprice_last AS tprice_last
,q.tprice AS target_price
,JSON_QUERY(q.tmath) AS target_math
,q.calculated_pallets AS calculated_pallets
,q.exact_pallets AS exact_pallets
,q.cust AS customer
,q.chan AS channel
,q.part AS part
,q.stlc AS stlc
,TRIM(q.tier) AS tier
,q.vol AS vol
,q.pltq AS pltq
,q.v1ds AS v1ds
,q.part_v1ds AS part_v1ds
,q.curstd_orig AS curstd_orig
,q.futstd_orig AS futstd_orig
,q.v0ds AS v0ds
,q.curstd AS curstd
,q.futstd AS futstd
,q.curstd_last AS curstd_last
,q.futstd_last AS futstd_last
,q.customized AS customized
,q.last_premium AS last_premium
,q.last_premium_method AS last_premium_method
,q.last_price_norm AS last_price_norm
,q.listcode AS listcode
,q.listprice AS listprice
,q.listprice_eff AS listprice_eff
,q.list_relevance AS list_relevance
,q.guidance_price AS guidance_price
,q.guidance_reason AS guidance_reason
-- JSON_QUERY(hist) AS [history]
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER
)
FROM @queue q;
--------------------------------------------------------------------------------
-- Step 9: Create 'ui_json' with panels (History, List, Target Support, Guidance) and include raw 'expl' JSON.
--------------------------------------------------------------------------------
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: ' + ISNULL(CONVERT(varchar(10), q.last_date, 120), '')
ELSE 'No Recent'
END AS label,
ISNULL(q.last_price, 0) AS value,
'currency' AS type,
CASE
WHEN q.last_price IS NOT NULL THEN
CONCAT(
CASE ISNULL(q.last_source, '')
WHEN 'mrq' THEN 'Recent similar quote'
WHEN 'mra' THEN 'Recent similar sales'
WHEN 'dsq' THEN 'Last quote'
WHEN 'mrq' THEN 'Last sale'
ELSE ''
END,
CASE WHEN ISNULL(q.last_order, '0') = '0'
THEN ' Qt# ' + ISNULL(q.last_quote, '')
ELSE ' Ord# ' + ISNULL(q.last_order, '')
END
)
ELSE NULL
END AS note
FOR JSON PATH -- array with one object (no WITHOUT_ARRAY_WRAPPER)
) AS details
UNION ALL
-- List Panel
SELECT
'List' AS label,
(
SELECT
'List:' + q.listcode AS label,
q.listprice AS value,
'currency' AS type,
q.list_relevance 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 'Percent' 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 all calculated fields and JSON payloads.
--------------------------------------------------------------------------------
SELECT guidance_price, ui_json FROM @queue;
END;