diff --git a/new_targets/procs/lastprice_logic.ms.sql b/new_targets/procs/lastprice_logic.ms.sql new file mode 100644 index 0000000..fb29eb7 --- /dev/null +++ b/new_targets/procs/lastprice_logic.ms.sql @@ -0,0 +1,89 @@ + +-- JSON-based helper function for last price selection +CREATE OR ALTER FUNCTION pricing.pick_last_price_from_hist_json ( + @part_stats NVARCHAR(MAX), + @v1ds NVARCHAR(100) +) +RETURNS @result TABLE ( + price NUMERIC(20,5), + source NVARCHAR(10), + odate DATE, + qty NUMERIC(20,5), + dataseg NVARCHAR(100), + ord NVARCHAR(20), + quote NVARCHAR(20) +) +AS +BEGIN + DECLARE @age_threshold DATE = DATEADD(year, -1, GETDATE()); + + -- Extract all relevant objects from JSON + DECLARE @dsq NVARCHAR(MAX), @dss NVARCHAR(MAX), @mrq NVARCHAR(MAX), @mrs NVARCHAR(MAX); + SELECT @dsq = segflags.dsq, @dss = segflags.dss + FROM OPENJSON(@part_stats, '$."' + @v1ds + '"') + WITH (dss NVARCHAR(MAX) AS JSON, dsq NVARCHAR(MAX) AS JSON) segflags; + SELECT @mrq = flags.mrq, @mrs = flags.mrs + FROM OPENJSON(@part_stats) + WITH (mrq NVARCHAR(MAX) AS JSON, mrs NVARCHAR(MAX) AS JSON) flags; + + -- Helper to extract fields from a JSON object + DECLARE @dsq_price NUMERIC(20,5), @dsq_date DATE, @dsq_qty NUMERIC(20,5), @dsq_dataseg NVARCHAR(100), @dsq_ord NVARCHAR(20), @dsq_quote NVARCHAR(20); + DECLARE @dss_price NUMERIC(20,5), @dss_date DATE, @dss_qty NUMERIC(20,5), @dss_dataseg NVARCHAR(100), @dss_ord NVARCHAR(20), @dss_quote NVARCHAR(20); + DECLARE @mrq_price NUMERIC(20,5), @mrq_date DATE, @mrq_qty NUMERIC(20,5), @mrq_dataseg NVARCHAR(100), @mrq_ord NVARCHAR(20), @mrq_quote NVARCHAR(20); + DECLARE @mrs_price NUMERIC(20,5), @mrs_date DATE, @mrs_qty NUMERIC(20,5), @mrs_dataseg NVARCHAR(100), @mrs_ord NVARCHAR(20), @mrs_quote NVARCHAR(20); + + IF @dsq IS NOT NULL + SELECT @dsq_price = price, @dsq_date = odate, @dsq_qty = qty, @dsq_dataseg = datasegment, @dsq_ord = ordnum, @dsq_quote = quoten + FROM OPENJSON(@dsq) + WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20)); + IF @dss IS NOT NULL + SELECT @dss_price = price, @dss_date = odate, @dss_qty = qty, @dss_dataseg = datasegment, @dss_ord = ordnum, @dss_quote = quoten + FROM OPENJSON(@dss) + WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20)); + IF @mrq IS NOT NULL + SELECT @mrq_price = price, @mrq_date = odate, @mrq_qty = qty, @mrq_dataseg = datasegment, @mrq_ord = ordnum, @mrq_quote = quoten + FROM OPENJSON(@mrq) + WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20)); + IF @mrs IS NOT NULL + SELECT @mrs_price = price, @mrs_date = odate, @mrs_qty = qty, @mrs_dataseg = datasegment, @mrs_ord = ordnum, @mrs_quote = quoten + FROM OPENJSON(@mrs) + WITH (price NUMERIC(20,5), qty NUMERIC(20,5), datasegment NVARCHAR(100), odate DATE, ordnum NVARCHAR(20), quoten NVARCHAR(20)); + + -- Use the same selection logic as before + -- 1. Prefer the most recent of dss/dsq if either is within the age threshold + IF (@dsq_date IS NOT NULL AND @dsq_date > @age_threshold) + OR (@dss_date IS NOT NULL AND @dss_date > @age_threshold) + BEGIN + IF @dsq_date IS NOT NULL AND (@dss_date IS NULL OR @dsq_date >= @dss_date) AND @dsq_date > @age_threshold + INSERT INTO @result VALUES (@dsq_price, 'dsq', @dsq_date, @dsq_qty, @dsq_dataseg, @dsq_ord, @dsq_quote); + ELSE IF @dss_date IS NOT NULL AND @dss_date > @age_threshold + INSERT INTO @result VALUES (@dss_price, 'dss', @dss_date, @dss_qty, @dss_dataseg, @dss_ord, @dss_quote); + RETURN; + END + + -- 2. If both dss/dsq are older than the threshold, use the most recent of mrs/mrq if either exists + IF (@mrq_date IS NOT NULL OR @mrs_date IS NOT NULL) + BEGIN + IF @mrq_date IS NOT NULL AND (@mrs_date IS NULL OR @mrq_date >= @mrs_date) + INSERT INTO @result VALUES (@mrq_price, 'mrq', @mrq_date, @mrq_qty, @mrq_dataseg, @mrq_ord, @mrq_quote); + ELSE IF @mrs_date IS NOT NULL + INSERT INTO @result VALUES (@mrs_price, 'mrs', @mrs_date, @mrs_qty, @mrs_dataseg, @mrs_ord, @mrs_quote); + RETURN; + END + + -- 3. If all are at least as old as the threshold, pick the least oldest price available + DECLARE @best_price NUMERIC(20,5) = NULL, @best_source NVARCHAR(10) = NULL, @best_date DATE = NULL, @best_qty NUMERIC(20,5) = NULL, @best_dataseg NVARCHAR(100) = NULL, @best_ord NVARCHAR(20) = NULL, @best_quote NVARCHAR(20) = NULL; + IF @dsq_date IS NOT NULL + SELECT @best_price = @dsq_price, @best_source = 'dsq', @best_date = @dsq_date, @best_qty = @dsq_qty, @best_dataseg = @dsq_dataseg, @best_ord = @dsq_ord, @best_quote = @dsq_quote; + IF @dss_date IS NOT NULL AND (@best_date IS NULL OR @dss_date > @best_date) + SELECT @best_price = @dss_price, @best_source = 'dss', @best_date = @dss_date, @best_qty = @dss_qty, @best_dataseg = @dss_dataseg, @best_ord = @dss_ord, @best_quote = @dss_quote; + IF @mrq_date IS NOT NULL AND (@best_date IS NULL OR @mrq_date > @best_date) + SELECT @best_price = @mrq_price, @best_source = 'mrq', @best_date = @mrq_date, @best_qty = @mrq_qty, @best_dataseg = @mrq_dataseg, @best_ord = @mrq_ord, @best_quote = @mrq_quote; + IF @mrs_date IS NOT NULL AND (@best_date IS NULL OR @mrs_date > @best_date) + SELECT @best_price = @mrs_price, @best_source = 'mrs', @best_date = @mrs_date, @best_qty = @mrs_qty, @best_dataseg = @mrs_dataseg, @best_ord = @mrs_ord, @best_quote = @mrs_quote; + + IF @best_price IS NOT NULL + INSERT INTO @result VALUES (@best_price, @best_source, @best_date, @best_qty, @best_dataseg, @best_ord, @best_quote); + + RETURN; +END diff --git a/new_targets/procs/single_price_call.ms.sql b/new_targets/procs/single_price_call.ms.sql index 75c6469..0752cc9 100644 --- a/new_targets/procs/single_price_call.ms.sql +++ b/new_targets/procs/single_price_call.ms.sql @@ -1,371 +1,232 @@ CREATE OR ALTER PROCEDURE pricing.single_price_call - @bill VARCHAR(100), - @ship VARCHAR(100), - @part VARCHAR(100), - @v1ds VARCHAR(100), - @vol NUMERIC(18,6) + @bill VARCHAR(100), + @ship VARCHAR(100), + @part VARCHAR(100), + @v1ds VARCHAR(100), + @vol NUMERIC(18,6) AS BEGIN - SET NOCOUNT ON; + 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) - ); + -- 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) + ); - -------------------------------------------------------------------------------- - -- Step 1: Seed the queue with input row - -------------------------------------------------------------------------------- - INSERT INTO @queue (bill, ship, part, v1ds, vol, expl) - VALUES (@bill, @ship, @part, @v1ds, @vol, '{}'); + -------------------------------------------------------------------------------- + -- 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 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 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 + hist = lp.part_stats 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; + ON lp.customer = q.cust AND lp.partgroup = q.partgroup; -------------------------------------------------------------------------------- - -- Step 4b.1: Populate composite fields from precedence chain + -- 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 - 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; + last_price = b.price, + last_source = b.source, + last_date = b.odate, + last_qty = b.qty, + last_dataseg = b.dataseg, + last_order = b.ord, + last_quote = b.quote + 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 -------------------------------------------------------------------------------- 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 - ) + 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 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 - ) + 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) + 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; -------------------------------------------------------------------------------- @@ -373,90 +234,90 @@ BEGIN -------------------------------------------------------------------------------- UPDATE q SET ui_json = ( - SELECT - ( - SELECT - panel.label, - JSON_QUERY(panel.details) AS details - FROM ( - -- History Panel + 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 + '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 + 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 - ) + -- 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 + 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 + -- 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 + 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 + -- 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; + -------------------------------------------------------------------------------- + -- Final: Return the enriched result row + -------------------------------------------------------------------------------- + --SELECT guidance_price, hist, expl, ui_json FROM @queue; +SELECT * FROM @queue; +END; \ No newline at end of file