diff --git a/new_targets/procs/single_price_call_func.ms.sql b/new_targets/procs/single_price_call_func.ms.sql index af04210..b543701 100644 --- a/new_targets/procs/single_price_call_func.ms.sql +++ b/new_targets/procs/single_price_call_func.ms.sql @@ -1,26 +1,53 @@ -CREATE OR ALTER FUNCTION pricing.single_price_call_fn ( - @bill VARCHAR(100), - @ship VARCHAR(100), - @part VARCHAR(100), - @stlc VARCHAR(100), - @v1ds VARCHAR(100), - @vol NUMERIC(18, 6) +DROP FUNCTION pricing.single_price_call_fn; + +CREATE FUNCTION pricing.single_price_call_fn ( + @bill VARCHAR(100), + @ship VARCHAR(100), + @part VARCHAR(100), + @v1ds VARCHAR(100), + @vol NUMERIC(18,6) +) +RETURNS @queue TABLE ( + bill VARCHAR(100), + ship VARCHAR(100), + part VARCHAR(100), + stlc 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_date DATE, + last_order NVARCHAR(10), + last_quote NVARCHAR(10), + tprice NUMERIC(20,5), + guidance_price NUMERIC(20,5), + guidance_reason NVARCHAR(MAX), + expl NVARCHAR(MAX), + ui_json NVARCHAR(MAX) ) -RETURNS TABLE AS -RETURN ( - WITH queue AS ( - SELECT - @bill AS bill, - @ship AS ship, - @part AS part, - @stlc AS stlc, - @v1ds AS v1ds, - @vol AS vol - ), - enriched AS ( - SELECT - q.*, +BEGIN + + -------------------------------------------------------------------------------- + -- 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) @@ -28,11 +55,13 @@ RETURN ( ELSE 'DRP' END ELSE 'DIR' - END AS chan, + END, + tier = CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIR' THEN bc.tier ELSE ISNULL(sc.tier, bc.tier) - END AS tier, + END, + cust = CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) @@ -40,8 +69,9 @@ RETURN ( ELSE sc.dba END ELSE q.bill - END AS cust, - i.mpck AS pltq, + END, + pltq = i.mpck, + plevel = CASE SUBSTRING(bc.cclass, 2, 3) WHEN 'DIS' THEN CASE SUBSTRING(sc.cclass, 2, 3) @@ -49,116 +79,230 @@ RETURN ( ELSE bc.plevel END ELSE bc.plevel - END AS plevel - 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 - ), - hist AS ( - SELECT TOP 1 - e.part, - j.qty, - j.price AS last_price, - j.odate AS last_date, - j.ordnum AS last_order, - j.quoten AS last_quote, - JSON_QUERY(lp.part_stats) AS full_history - FROM pricing.lastprice lp - OUTER APPLY OPENJSON(lp.part_stats) AS p + END, + stlc = substring(q.part,1,8) + 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, + 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), '∞')) + 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)), + 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.mold = SUBSTRING(q.part, 1, 8) + OUTER APPLY ( + SELECT TOP 1 * + FROM OPENJSON(lp.part_stats) AS p OUTER APPLY OPENJSON(p.value) - WITH ( - qty NUMERIC(20, 5), - price NUMERIC(20, 5), - odate DATE, - ordnum INT, - quoten INT - ) AS j - INNER JOIN enriched e ON - lp.customer = e.cust AND - lp.mold = SUBSTRING(e.part, 1, 8) - WHERE - p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = e.part + WITH ( + 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.part ORDER BY j.odate DESC - ), - list_price_cte AS ( - SELECT *, - ROW_NUMBER() OVER (PARTITION BY e.part ORDER BY p.price ASC) AS rn - FROM enriched e - INNER JOIN CMSInterfaceIn."CMS.CUSLG".IPRCBHC i - ON TRIM(i.jbplvl) = TRIM(e.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 = e.part - AND e.vol >= p.vb_from - AND (p.vb_to IS NULL OR e.vol < p.vb_to) - ), - FINAL AS ( + ) AS j; + + -------------------------------------------------------------------------------- + -- Step 5: Add list price info from external pricelist + -------------------------------------------------------------------------------- + WITH ranked_prices AS ( SELECT - e.part, - tp.price, - e.plevel, - h.full_history, - h.last_price, - h.last_date, - h.last_order, - h.last_quote, - lp.price AS list_price, - lp.jcplcd AS list_code, - g.guidance_price, - g.guidance_reason, + 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(JSON_VALUE(q.expl, '$.last_date') AS DATE) + ) g; + + -------------------------------------------------------------------------------- + -- Step 7: Clean up for UI + -------------------------------------------------------------------------------- +UPDATE q +SET ui_json = ( + SELECT + panel.label, + JSON_QUERY(panel.details) AS details + FROM ( + -- History Panel + SELECT + 'History' AS label, + ( + SELECT + 'Last Sale: ' + CAST(q.last_date AS varchar(10)) AS label, + q.last_price AS value, + 'currency' AS type, + 'Ord# ' + q.last_order 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 - 'target price' AS source, - tp.price AS target_price, - h.last_price, - FORMAT(h.last_date, 'yyyy-MM-dd') AS last_date, - h.last_order, - h.last_quote, - lp.price AS list_price, - lp.jcplcd AS list_code, - FLOOR(e.vol / NULLIF(e.pltq, 0)) AS calculated_pallets, - CAST(e.vol / NULLIF(e.pltq, 0) AS NUMERIC(20,5)) AS exact_pallets, - CONCAT(tp.lower_bound, '-', ISNULL(CAST(tp.upper_bound AS VARCHAR), '∞')) AS [volume range], - e.cust AS customer, - e.chan AS channel, - RTRIM(e.tier) AS tier, - JSON_QUERY(tp.math) AS [target math], --- JSON_QUERY(h.full_history) AS [price history], - g.guidance_price, - g.guidance_reason - FOR JSON PATH, WITHOUT_ARRAY_WRAPPER - ) AS expl - FROM enriched e - INNER JOIN pricing.target_prices tp ON - e.stlc = tp.stlc AND - e.v1ds = tp.ds AND - e.chan = tp.chan AND - RTRIM(e.tier) = RTRIM(tp.tier) AND - FLOOR(e.vol / NULLIF(e.pltq, 0)) >= tp.lower_bound AND - (tp.upper_bound IS NULL OR FLOOR(e.vol / NULLIF(e.pltq, 0)) < tp.upper_bound) - LEFT JOIN hist h ON h.part = e.part - LEFT JOIN list_price_cte lp ON lp.part = e.part AND lp.rn = 1 - CROSS APPLY pricing.guidance_logic( - tp.price, - h.last_price, - lp.price - ) g - ) - SELECT - part, - price AS target_price, - plevel, - last_price, - last_date, - last_order, - last_quote, - list_price, - list_code, - guidance_price, - guidance_reason, - expl - FROM FINAL -); + -- parse each item in target_math + RTRIM(SUBSTRING(value,1,18)) 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, + SUBSTRING(value,19,1) 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 + 'Last Price Capped' AS label, + q.guidance_price AS value, + 'currency' AS type, + CONCAT( + 'Last price ', q.last_price, + ' capped at ', + ROUND((q.last_price - q.guidance_price) / NULLIF(q.last_price, 0) * 100, 2), + '%' + ) AS note + FOR JSON PATH + ) + ) AS panel + FOR JSON PATH, ROOT('details') +) +FROM @queue q; + + + -------------------------------------------------------------------------------- + -- Final: Return the enriched result row + -------------------------------------------------------------------------------- + RETURN; +END;