diff --git a/new_targets/basic_setup/lastprice.ms.sql b/new_targets/basic_setup/lastprice.ms.sql new file mode 100644 index 0000000..5ee8da1 --- /dev/null +++ b/new_targets/basic_setup/lastprice.ms.sql @@ -0,0 +1,13 @@ +-- FAnalysis.PRICING.lastprice definition + +-- Drop table + +-- DROP TABLE FAnalysis.PRICING.lastprice; + +CREATE TABLE pricing.lastprice ( + customer varchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, + mold varchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, + part_stats nvarchar(MAX) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL +); + +CREATE UNIQUE NONCLUSTERED INDEX lastprice_cust_mold ON FAnalysis.PRICING.lastprice (customer ASC, mold ASC) ; diff --git a/new_targets/basic_setup/make_hist.ms.sql b/new_targets/basic_setup/make_hist.ms.sql new file mode 100644 index 0000000..ad930a9 --- /dev/null +++ b/new_targets/basic_setup/make_hist.ms.sql @@ -0,0 +1,59 @@ +-------------------------------------------------------------------------------- +-- Step 1: Rebuild last price history at sales matrix refresh time +-------------------------------------------------------------------------------- + +DELETE FROM pricing.lastprice; + +WITH srt AS ( + SELECT + customer, + mold, + part, + version, + qty, + ROUND(sales_usd / qty, 5) AS price, + odate, + oseas, + ordnum, + quoten, + ROW_NUMBER() OVER ( + PARTITION BY customer, mold, part, version + ORDER BY odate DESC + ) AS rn + FROM rlarp.osm_stack + WHERE + --quotes can't be integrated until we have datasegment or correct part code + version IN ('Actual'/*,'Quotes'*/) AND + customer IS NOT NULL AND + fs_line = '41010' AND + calc_status <> 'CANCELLED' AND + qty <> 0 AND + mold <> '' +), +json_rows AS ( + SELECT + customer, + mold, + part, + version, + CONCAT( + '"', part, '":', + ( + SELECT version, qty, price, odate, ordnum, quoten + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER + ) + ) AS part_json + FROM srt + WHERE rn = 1 +) +,onerow AS ( +SELECT + customer, + mold, + CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats +FROM json_rows +GROUP BY customer, mold +) +INSERT INTO pricing.lastprice SELECT * FROM onerow; + +--CREATE UNIQUE INDEX lastprice_cust_mold ON pricing.lastprice(customer, mold); diff --git a/new_targets/basic_setup/setup.md b/new_targets/basic_setup/setup.md new file mode 100644 index 0000000..d7b5e27 --- /dev/null +++ b/new_targets/basic_setup/setup.md @@ -0,0 +1,17 @@ +minimal setup to run a single pricing call: +```sql +EXEC pricing.single_price_call + @bill = 'GRIF0001', + @ship = 'GRIF0001', + @part = 'XNS0T1G3G18B096', + @stlc = 'XNS0T1G3', + @v1ds = 'v1:T..PLT..', + @vol = 9600; +``` + +1.) make sure pricing schema is setup +2.) create target table: target_prices.ms.sql +3.) populate targets: target_prices_copy.ms.sql +4.) create history table: lastprice.ms.sql +5.) populate history: make_hist.ms.sql +6.) create proc: single_price_call.ms.sql diff --git a/new_targets/basic_setup/single_price_call.ms.sql b/new_targets/basic_setup/single_price_call.ms.sql new file mode 100644 index 0000000..9210fb4 --- /dev/null +++ b/new_targets/basic_setup/single_price_call.ms.sql @@ -0,0 +1,162 @@ +CREATE OR ALTER PROCEDURE pricing.single_price_call + @bill VARCHAR(100), + @ship VARCHAR(100), + @part VARCHAR(100), + @stlc VARCHAR(100), + @v1ds VARCHAR(100), + @vol NUMERIC(18,6) +AS +BEGIN + SET NOCOUNT ON; + + DECLARE @phist NVARCHAR(MAX); + + -- Declare table variable for the input row + DECLARE @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), + price NUMERIC(18,6), + expl NVARCHAR(MAX), + hist NVARCHAR(MAX), + LAST nvarchar(max) + ); + + -------------------------------------------------------------------------------- + -- Step 1: Insert input row into queue + -------------------------------------------------------------------------------- + INSERT INTO @queue (bill, ship, part, stlc, v1ds, vol) + VALUES (@bill, @ship, @part, @stlc, @v1ds, @vol); + + -------------------------------------------------------------------------------- + -- Step 2: Enrich the row with chan, tier, cust, pltq + -------------------------------------------------------------------------------- + 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 + 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: Get last price info directly into @queue columns + -------------------------------------------------------------------------------- + UPDATE q + SET + q.hist = ( + SELECT TOP 1 + j.qty, + j.price, + j.odate, + j.ordnum, + j.quoten + FROM pricing.lastprice lp + OUTER APPLY 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 + WHERE + lp.customer = q.cust + AND lp.mold = SUBSTRING(q.part,1,8) + AND p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part + ORDER BY j.odate DESC + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER + ), + q.last = ( + SELECT TOP 1 + CAST(ROUND(j.price, 5) AS NVARCHAR(50)) -- must be string to store in NVARCHAR column + FROM pricing.lastprice lp + OUTER APPLY 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 + WHERE + lp.customer = q.cust + AND lp.mold = SUBSTRING(q.part,1,8) + AND p.[key] COLLATE SQL_Latin1_General_CP1_CI_AS = q.part + ORDER BY j.odate DESC + ) + FROM @queue q; + + + + -------------------------------------------------------------------------------- + -- Step 4: Apply pricing and embed price history + last price from queue columns + -------------------------------------------------------------------------------- + UPDATE q + SET + price = tp.price, + expl = ( + SELECT + 'target price' AS [source], + tp.price AS [target_price], + CAST(q.last AS NUMERIC(20,5)) AS [last_price], + FLOOR(q.vol / NULLIF(q.pltq, 0)) AS [calculated_pallets], + ROUND(q.vol / NULLIF(q.pltq, 0), 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], + q.tier AS [tier], + JSON_QUERY(tp.math) AS [target math], + JSON_QUERY(q.hist) AS [price history] + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER + ) + 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 Last: Return just the enriched row + -------------------------------------------------------------------------------- + SELECT price, expl FROM @queue; +END; diff --git a/new_targets/basic_setup/target_prices.ms.sql b/new_targets/basic_setup/target_prices.ms.sql new file mode 100644 index 0000000..9385860 --- /dev/null +++ b/new_targets/basic_setup/target_prices.ms.sql @@ -0,0 +1,18 @@ +DROP TABLE pricing.target_prices; + +CREATE TABLE pricing.target_prices ( + stlc nvarchar(8) NOT NULL, + ds nvarchar(20) NOT NULL, + chan nvarchar(3) NOT NULL, + tier nvarchar(1) NOT NULL, + vol nvarchar(20) NOT NULL, + lower_bound int NOT NULL, + upper_bound int NULL, + price numeric(28,6) NOT NULL, + math nvarchar(MAX) NULL +); + +ALTER TABLE pricing.target_prices +ADD CONSTRAINT uq_target_prices_unique_combo +UNIQUE (stlc, ds, chan, tier, vol, lower_bound); + diff --git a/new_targets/basic_setup/target_prices_copy.ms.sql b/new_targets/basic_setup/target_prices_copy.ms.sql new file mode 100644 index 0000000..34eac26 --- /dev/null +++ b/new_targets/basic_setup/target_prices_copy.ms.sql @@ -0,0 +1,23 @@ +DELETE FROM pricing.target_prices; + +INSERT INTO + pricing.target_prices +SELECT + stlc, + ds, + chan, + tier, + vol, + -- Extract lower bound: text between '[' and ',' + TRY_CAST(SUBSTRING(vol, 2, CHARINDEX(',', vol) - 2) AS INT) AS lower_bound, + -- Extract upper bound: text between ',' and ')' + CASE + WHEN RIGHT(vol, 2) = ',)' THEN NULL + ELSE TRY_CAST(SUBSTRING(vol, CHARINDEX(',', vol) + 1, LEN(vol) - CHARINDEX(',', vol) - 1) AS INT) + END AS upper_bound, + price, + math +FROM + usmidsap02.ubm.pricequote.target_prices_view; + +--SELECT COUNT(*) FROM pricing.target_prices \ No newline at end of file diff --git a/new_targets/make_hist.ms.sql b/new_targets/make_hist.ms.sql deleted file mode 100644 index be85c36..0000000 --- a/new_targets/make_hist.ms.sql +++ /dev/null @@ -1,152 +0,0 @@ --------------------------------------------------------------------------------- --- Step 1: Rebuild last price history at sales matrix refresh time --------------------------------------------------------------------------------- - -DELETE FROM pricing.lastprice; - -WITH srt AS ( - SELECT - customer, - mold, - part, - version, - qty, - ROUND(sales_usd / qty, 5) AS price, - odate, - oseas, - ordnum, - quoten, - ROW_NUMBER() OVER ( - PARTITION BY customer, mold, part, version - ORDER BY odate DESC - ) AS rn - FROM rlarp.osm_stack - WHERE - --quotes can't be integrated until we have datasegment or correct part code - version IN ('Actual'/*,'Quotes'*/) AND - customer IS NOT NULL AND - fs_line = '41010' AND - calc_status <> 'CANCELLED' AND - qty <> 0 AND - mold <> '' -), -json_rows AS ( - SELECT - customer, - mold, - part, - version, - CONCAT( - '"', part, '":', - ( - SELECT version, qty, price, odate, ordnum, quoten - FOR JSON PATH, WITHOUT_ARRAY_WRAPPER - ) - ) AS part_json - FROM srt - WHERE rn = 1 -) -,onerow AS ( -SELECT - customer, - mold, - CONCAT('{', STRING_AGG(part_json, ','), '}') AS part_stats -FROM json_rows -GROUP BY customer, mold -) -INSERT INTO pricing.lastprice SELECT * FROM onerow; - ---CREATE UNIQUE INDEX lastprice_cust_mold ON pricing.lastprice(customer, mold); - - -SELECT count(*) FROM rlarp.osm_stack o INNER JOIN #lastprice l ON - l.customer = o.customer AND o.mold = l.mold - - SELECT * FROM #lastprice - -SELECT - o.ordnum, - o.part, - o.odate, - lp.customer, - lp.mold, - p.[key] AS part, -- this is the part number - j.qty, - j.price, - j.odate, - j.ordnum, - j.quoten -FROM - rlarp.osm_stack o - LEFT OUTER JOIN pricing.lastprice lp ON - lp.customer = o.customer - AND lp.mold = o.mold - CROSS APPLY OPENJSON(lp.part_stats) AS p -- unpacks part keys - CROSS APPLY OPENJSON(p.value) - WITH ( - qty FLOAT, - price FLOAT, - odate DATE, - ordnum INT, - quoten INT - ) AS j -WHERE - o.customer = 'ALTMAN PLANTS' - AND o.mold = 'XPR15CS1' - AND o.ordnum = 935360 - -WITH exploded AS ( - SELECT - lp.customer, - lp.mold, - p.[key] AS part_key, - j.qty, - j.price, - j.odate, - j.ordnum, - j.quoten, - CASE WHEN p.[key] = o.part COLLATE Latin1_General_BIN2 THEN 1 ELSE 0 END AS is_exact_match, - ROW_NUMBER() OVER (PARTITION BY lp.customer, lp.mold ORDER BY j.odate DESC) AS rn_most_recent - FROM rlarp.osm_stack o - LEFT JOIN pricing.lastprice lp ON lp.customer = o.customer AND lp.mold = o.mold - CROSS APPLY OPENJSON(lp.part_stats) AS p - CROSS APPLY OPENJSON(p.value) - WITH ( - qty FLOAT, - price FLOAT, - odate DATE, - ordnum INT, - quoten INT - ) AS j - WHERE - o.customer = 'ALTMAN PLANTS' - AND o.mold = 'XPR15CS1' - AND o.ordnum = 935360 -), -tagged AS ( - SELECT - part_key, - qty, - price, - odate, - ordnum, - quoten, - IIF(is_exact_match = 1, 1, NULL) AS is_exact_match, - IIF(rn_most_recent = 1, 1, NULL) AS is_most_recent - FROM exploded -) ---SELECT * FROM taggeg -SELECT ( - SELECT - part_key AS [key], - qty, - price, - odate, - ordnum, - quoten, - is_exact_match, - is_most_recent - FROM tagged - FOR JSON PATH, INCLUDE_NULL_VALUES -) AS updated_json_array; - diff --git a/new_targets/make_hist.pg.sql b/new_targets/make_hist.pg.sql deleted file mode 100644 index 14bd136..0000000 --- a/new_targets/make_hist.pg.sql +++ /dev/null @@ -1,50 +0,0 @@ -CREATE TABLE pricequote.lastprice AS ( -WITH ---------SORT-------- -srt AS ( -SELECT - customer - ,partgroup - ,dataseg - ,qtyord - ,ROUND(sales_usd/qty,5) price - ,odate - ,oseas - ,ordnum - ,quoten - ,row_number() OVER (PARTITION BY customer, partgroup, dataseg, version ORDER BY odate DESC) seq - ,version -FROM - rlarp.osm_stack -WHERE - version IN ('Actual','Quotes') - AND customer IS NOT NULL - AND fs_line = '41010' - AND calc_status <> 'CANCELLED' - -- AND customer = 'ALTMAN PLANTS' - AND qty <> 0 - AND partgroup <> '' - AND version = 'Actual' --- LIMIT 10000 -) -,onerow AS ( -SELECT - customer, - partgroup, - -- Latest per-dataseg sales wrapped as JSONB object - jsonb_object_agg( - dataseg, - to_jsonb(srt) - ORDER BY odate DESC - ) AS dataseg_stats -FROM - srt -WHERE - seq = 1 - -- AND customer = 'ALTMAN PLANTS' - -- AND partgroup ~ 'XPR15CS' -GROUP BY customer, partgroup --- ORDER BY customer, partgroup -) -SELECT * FROM onerow --WHERE customer = 'ALTMAN PLANTS' AND partgroup = 'XPR15CS1' -) WITH DATA; diff --git a/new_targets/tables/lastprice.ms.sql b/new_targets/tables/lastprice.ms.sql new file mode 100644 index 0000000..5ee8da1 --- /dev/null +++ b/new_targets/tables/lastprice.ms.sql @@ -0,0 +1,13 @@ +-- FAnalysis.PRICING.lastprice definition + +-- Drop table + +-- DROP TABLE FAnalysis.PRICING.lastprice; + +CREATE TABLE pricing.lastprice ( + customer varchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, + mold varchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL, + part_stats nvarchar(MAX) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL +); + +CREATE UNIQUE NONCLUSTERED INDEX lastprice_cust_mold ON FAnalysis.PRICING.lastprice (customer ASC, mold ASC) ;