From f8c62e5d2733610b06a7130573614a510a9c6b4a Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Fri, 8 Aug 2025 02:45:06 -0400 Subject: [PATCH] handle differences quoted product versus product on list if customized or last price if no exact match found --- procs/single_price_call.ms.sql | 257 +++++++++++++++++++++++---------- 1 file changed, 184 insertions(+), 73 deletions(-) diff --git a/procs/single_price_call.ms.sql b/procs/single_price_call.ms.sql index 8ff792d..0509fe9 100644 --- a/procs/single_price_call.ms.sql +++ b/procs/single_price_call.ms.sql @@ -53,14 +53,24 @@ BEGIN partgroup VARCHAR(100), v1ds VARCHAR(100), vol NUMERIC(18,6), + part_v1ds VARCHAR(50), + curstd_orig NUMERIC(20,5), + futstd_orig NUMERIC(20,5), + v0ds VARCHAR(10), + curstd NUMERIC(20,5), + futstd NUMERIC(20,5), + customized VARCHAR(100), + last_premium NUMERIC(20,5), chan VARCHAR(50), cust VARCHAR(100), tier VARCHAR(50), pltq NUMERIC(18,6), - volume_range TEXT, + volume_range VARCHAR(100), plevel NVARCHAR(20), listprice NUMERIC(20,5), listcode VARCHAR(10), + listprice_eff NUMERIC(20,5), + list_relevance NVARCHAR(100), hist NVARCHAR(MAX), last_price NUMERIC(20,5), last_qty NUMERIC(20,5), @@ -69,7 +79,14 @@ BEGIN last_quote NVARCHAR(10), last_dataseg NVARCHAR(20), last_source NVARCHAR(100), - tprice NUMERIC(20,5), + last_isdiff NVARCHAR(100), + last_v0ds VARCHAR(10), + last_price_norm NUMERIC(20,5), + last_premium_method VARCHAR(100), + curstd_last NUMERIC(20,5), + futstd_last NUMERIC(20,5), + tprice_last NUMERIC(20,5), + tprice NUMERIC(20,5), tmath nvarchar(MAX), guidance_price NUMERIC(20,5), guidance_reason NVARCHAR(MAX), @@ -122,30 +139,20 @@ BEGIN ELSE bc.plevel END, stlc = substring(q.part,1,8), - partgroup = i.partgroup + partgroup = i.partgroup, + part_v1ds = 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 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 @@ -156,10 +163,7 @@ BEGIN FROM @queue q JOIN pricing.lastpricedetail lp ON lp.customer = q.cust AND lp.partgroup = q.partgroup; - - -------------------------------------------------------------------------------- - -- Step 4b.1: Populate composite fields from precedence chain using JSON-based helper - -------------------------------------------------------------------------------- + -- Use new helper to select best last price, source, and date directly from JSON UPDATE q SET @@ -168,36 +172,111 @@ BEGIN 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_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 4b.2: Build JSON explanation object from populated columns + -- Step 3: Apply target price and embed metadata as JSON -------------------------------------------------------------------------------- + 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 + 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 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 ) - FROM @queue q; + 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 FLOOR(q.vol / NULLIF(q.pltq, 0)) >= tpl.lower_bound + AND ( + tpl.upper_bound IS NULL OR FLOOR(q.vol / NULLIF(q.pltq, 0)) < tpl.upper_bound + ); + + -------------------------------------------------------------------------------- + -- Step 3.b: Apply secondary cost data + -------------------------------------------------------------------------------- + + -- goal datasegment will inherit original but if it is customerd, will pull available average + 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 5: Add list price info from external pricelist @@ -222,15 +301,11 @@ BEGIN 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 + 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 @@ -240,30 +315,66 @@ BEGIN 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 - ) + guidance_price = g.guidance_price + ,guidance_reason = g.guidance_reason 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; + 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 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_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 + ,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 + ,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 7: Clean up for UI @@ -305,7 +416,7 @@ BEGIN 'List:' + q.listcode AS label, q.listprice AS value, 'currency' AS type, - q.plevel AS note + q.list_relevance AS note FOR JSON PATH ) @@ -319,7 +430,7 @@ BEGIN 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 '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) '$') @@ -354,4 +465,4 @@ BEGIN -------------------------------------------------------------------------------- --SELECT guidance_price, hist, expl, ui_json FROM @queue; SELECT * FROM @queue; -END; \ No newline at end of file +END;