diff --git a/new_targets/scripts/pricelist_ranged.ms.sql b/new_targets/scripts/pricelist_ranged.ms.sql deleted file mode 100644 index d79370b..0000000 --- a/new_targets/scripts/pricelist_ranged.ms.sql +++ /dev/null @@ -1,184 +0,0 @@ ---XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX ------------------------------------------------------------traverse unit of measure graph----------------------------------------------------------------------- ---XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX --------------setup table to hold target conversions--------------------- - - -SELECT DISTINCT - jcpart partn - ,jcunit fu - ,'PC' tu - ,cast(null as numeric) factor -INTO - #anchor -FROM - cmsinterfacein.lgdat.iprcc -WHERE - 1=1; - ---SELECT * FROM #anchor - --------pre-build punit stacked on itself with the columns flipped so you can go either direction per join--------- -SELECT - * -INTO - #g -FROM - ( - SELECT - IHPART IHPART, - rtrim(IHUNT1) IHUNT1, - rtrim(IHUNT2) IHUNT2, - IHCNV1 IHCNV1, - IHCNV2 IHCNV2 - FROM - CMSInterfaceIN.LGDAT.PUNIT pu - --only deal with parts in the anchor table or the &&global parts - INNER JOIN ( - SELECT DISTINCT partn FROM #anchor - ) items ON - items.partn = pu.ihpart - OR pu.ihpart = '&&GLOBAL' - UNION - SELECT - IHPART IHPART, - rtrim(IHUNT2) IHUNT1, - rtrim(IHUNT1) IHUNT2, - IHCNV2 IHCNV1, - IHCNV1 IHCNV2 - FROM - CMSInterfaceIN.LGDAT.PUNIT pu - --only deal with parts in the anchor table or the &&global parts - INNER JOIN ( - SELECT DISTINCT partn FROM #anchor - ) items ON - items.partn = pu.ihpart - OR pu.ihpart = '&&GLOBAL' - ) x ; - -CREATE INDEX g_idx on #g(ihpart,ihunt1); - -WITH ---------do the expansion on all paths until the target uom is matched---------------------------------------------- ---(complains about types not matching between anchor and recursion, explicitly just casting everything) -uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, uom_list) AS -( - SELECT - cast(partn as varchar(20)) --partn - ,cast(partn as varchar(20)) --partx - ,cast(0 as int) --lvl - ,fu --mastf - ,tu --mastt - ,cast(fu as varchar(3)) --xf - ,cast(fu as varchar(3)) --xt - ,CAST(1 AS FLOAT) --factor - ,CAST(1 AS FLOAT) --xfactor - ,CAST(1 AS FLOAT) --xnum - ,CAST(1 AS FLOAT) --xden - ,format(row_number() over (ORDER BY partn),'000000') - ,cast(trim(fu) as varchar(max)) - FROM - #anchor - UNION ALL - SELECT - cast(uom.partn as varchar(20)) --partn - ,cast(ihpart as varchar(20)) --partx - ,CAST(uom.lvl + 1 AS INT) --lvl - ,uom.mastf --mastf - ,uom.mastt --mastt - ,cast(p.ihunt1 as varchar(3)) --xf - ,cast(p.ihunt2 as varchar(3)) --xt - ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) --factor - ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) * uom.xfactor --xfactor - ,p.ihcnv2 * uom.xnum --xnum - ,p.ihcnv1 * uom.xden --xden - ,uom.id + '.' + format(row_number() over (PARTITION BY uom.id ORDER BY partn),'00') - ,uom.uom_list + '.' + trim(p.ihunt2) - FROM - uom - INNER JOIN #g p ON - p.ihpart IN (uom.partn,'&&GLOBAL') - AND p.ihunt1 = uom.xt - WHERE - 1=1 - --AND p.ihunt2 not in ('BD','BG','BU','BX','CA','CS','PA','PL','SL','C','K','DOZ','PR') - AND p.ihunt1 <> uom.mastt - --prevent recursion: newest joined UOM can't be in the history - AND charindex(p.ihunt2,uom.uom_list) = 0 -) ---SELECT COUNT(*) FROM UOM ---------------uom is going to have multiple rows per requested conversion, need to use row_number to pick the best row------------------------------ -,sorted AS ( -SELECT - partn, mastf from_uom, xt to_uom, xfactor factor, lvl steps, row_number() OVER (PARTITION BY partn, mastf, mastt ORDER BY lvl ASC, factor ASC) rn -FROM - uom -WHERE - xt = mastt -) -SELECT * INTO #uom FROM sorted WHERE rn = 1; ---so far so good - -drop table #anchor; -drop table #g; - -TRUNCATE TABLE pricing.pricelist_ranged; - -WITH -conv AS ( - SELECT - p.jcplcd, - p.jcpart, - p.jcunit, - p.jcvoll, - p.jcpric, - u.factor, - -- Normalize volume and price to PC - p.jcvoll * u.factor AS vol_pc, - p.jcpric / u.factor AS price_pc - FROM - cmsinterfacein.lgdat.iprcc p - INNER JOIN #uom u - ON u.partn = p.jcpart - AND u.from_uom = p.jcunit - AND u.to_uom = 'PC' -), -sorted AS ( - SELECT - c.*, - ROW_NUMBER() OVER (PARTITION BY c.jcplcd, c.jcpart ORDER BY vol_pc ASC) AS rn - FROM conv c -), -ranged AS ( - SELECT - curr.jcplcd, - curr.jcpart, - curr.jcunit, - curr.jcvoll, - curr.jcpric, - curr.vol_pc, - curr.price_pc, - curr.vol_pc AS vb_from, - COALESCE(next.vol_pc, 9999999.0) AS vb_to - FROM - sorted curr - LEFT JOIN sorted next - ON curr.jcplcd = next.jcplcd - AND curr.jcpart = next.jcpart - AND curr.rn + 1 = next.rn -) -INSERT INTO - pricing.pricelist_ranged -SELECT - RTRIM(jcplcd) jcplcd, - RTRIM(jcpart) jcpart, - jcunit, - jcvoll, - jcpric, - vb_from, - vb_to, - price_pc AS price -FROM - ranged; - ---CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to); \ No newline at end of file diff --git a/new_targets/tables/pricelist_ranged.ms.sql b/new_targets/tables/pricelist_ranged.ms.sql index 93723f7..d25fc9b 100644 --- a/new_targets/tables/pricelist_ranged.ms.sql +++ b/new_targets/tables/pricelist_ranged.ms.sql @@ -12,3 +12,188 @@ CREATE TABLE pricing.pricelist_ranged ( ); CREATE NONCLUSTERED INDEX pricelist_ranged_idx ON FAnalysis.PRICING.pricelist_ranged ( jcpart ASC , jcplcd ASC , vb_from ASC , vb_to ASC ) ; + +--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX +-----------------------------------------------------------traverse unit of measure graph----------------------------------------------------------------------- +--XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX +-------------setup table to hold target conversions--------------------- + + +SELECT DISTINCT + jcpart partn + ,jcunit fu + ,'PC' tu + ,cast(null as numeric) factor +INTO + #anchor +FROM + cmsinterfacein.lgdat.iprcc +WHERE + 1=1; + +--SELECT * FROM #anchor + +-------pre-build punit stacked on itself with the columns flipped so you can go either direction per join--------- +SELECT + * +INTO + #g +FROM + ( + SELECT + IHPART IHPART, + rtrim(IHUNT1) IHUNT1, + rtrim(IHUNT2) IHUNT2, + IHCNV1 IHCNV1, + IHCNV2 IHCNV2 + FROM + CMSInterfaceIN.LGDAT.PUNIT pu + --only deal with parts in the anchor table or the &&global parts + INNER JOIN ( + SELECT DISTINCT partn FROM #anchor + ) items ON + items.partn = pu.ihpart + OR pu.ihpart = '&&GLOBAL' + UNION + SELECT + IHPART IHPART, + rtrim(IHUNT2) IHUNT1, + rtrim(IHUNT1) IHUNT2, + IHCNV2 IHCNV1, + IHCNV1 IHCNV2 + FROM + CMSInterfaceIN.LGDAT.PUNIT pu + --only deal with parts in the anchor table or the &&global parts + INNER JOIN ( + SELECT DISTINCT partn FROM #anchor + ) items ON + items.partn = pu.ihpart + OR pu.ihpart = '&&GLOBAL' + ) x ; + +CREATE INDEX g_idx on #g(ihpart,ihunt1); + +WITH +--------do the expansion on all paths until the target uom is matched---------------------------------------------- +--(complains about types not matching between anchor and recursion, explicitly just casting everything) +uom (partn, partx, lvl, mastf, mastt, xf, xt, factor, xfactor, xnum, xden, id, uom_list) AS +( + SELECT + cast(partn as varchar(20)) --partn + ,cast(partn as varchar(20)) --partx + ,cast(0 as int) --lvl + ,fu --mastf + ,tu --mastt + ,cast(fu as varchar(3)) --xf + ,cast(fu as varchar(3)) --xt + ,CAST(1 AS FLOAT) --factor + ,CAST(1 AS FLOAT) --xfactor + ,CAST(1 AS FLOAT) --xnum + ,CAST(1 AS FLOAT) --xden + ,format(row_number() over (ORDER BY partn),'000000') + ,cast(trim(fu) as varchar(max)) + FROM + #anchor + UNION ALL + SELECT + cast(uom.partn as varchar(20)) --partn + ,cast(ihpart as varchar(20)) --partx + ,CAST(uom.lvl + 1 AS INT) --lvl + ,uom.mastf --mastf + ,uom.mastt --mastt + ,cast(p.ihunt1 as varchar(3)) --xf + ,cast(p.ihunt2 as varchar(3)) --xt + ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) --factor + ,CAST(p.ihcnv2/p.ihcnv1 AS FLOAT) * uom.xfactor --xfactor + ,p.ihcnv2 * uom.xnum --xnum + ,p.ihcnv1 * uom.xden --xden + ,uom.id + '.' + format(row_number() over (PARTITION BY uom.id ORDER BY partn),'00') + ,uom.uom_list + '.' + trim(p.ihunt2) + FROM + uom + INNER JOIN #g p ON + p.ihpart IN (uom.partn,'&&GLOBAL') + AND p.ihunt1 = uom.xt + WHERE + 1=1 + --AND p.ihunt2 not in ('BD','BG','BU','BX','CA','CS','PA','PL','SL','C','K','DOZ','PR') + AND p.ihunt1 <> uom.mastt + --prevent recursion: newest joined UOM can't be in the history + AND charindex(p.ihunt2,uom.uom_list) = 0 +) +--SELECT COUNT(*) FROM UOM +--------------uom is going to have multiple rows per requested conversion, need to use row_number to pick the best row------------------------------ +,sorted AS ( +SELECT + partn, mastf from_uom, xt to_uom, xfactor factor, lvl steps, row_number() OVER (PARTITION BY partn, mastf, mastt ORDER BY lvl ASC, factor ASC) rn +FROM + uom +WHERE + xt = mastt +) +SELECT * INTO #uom FROM sorted WHERE rn = 1; +--so far so good + +drop table #anchor; +drop table #g; + +TRUNCATE TABLE pricing.pricelist_ranged; + +WITH +conv AS ( + SELECT + p.jcplcd, + p.jcpart, + p.jcunit, + p.jcvoll, + p.jcpric, + u.factor, + -- Normalize volume and price to PC + p.jcvoll * u.factor AS vol_pc, + p.jcpric / u.factor AS price_pc + FROM + cmsinterfacein.lgdat.iprcc p + INNER JOIN #uom u + ON u.partn = p.jcpart + AND u.from_uom = p.jcunit + AND u.to_uom = 'PC' +), +sorted AS ( + SELECT + c.*, + ROW_NUMBER() OVER (PARTITION BY c.jcplcd, c.jcpart ORDER BY vol_pc ASC) AS rn + FROM conv c +), +ranged AS ( + SELECT + curr.jcplcd, + curr.jcpart, + curr.jcunit, + curr.jcvoll, + curr.jcpric, + curr.vol_pc, + curr.price_pc, + curr.vol_pc AS vb_from, + COALESCE(next.vol_pc, 9999999.0) AS vb_to + FROM + sorted curr + LEFT JOIN sorted next + ON curr.jcplcd = next.jcplcd + AND curr.jcpart = next.jcpart + AND curr.rn + 1 = next.rn +) +INSERT INTO + pricing.pricelist_ranged +SELECT + RTRIM(jcplcd) jcplcd, + RTRIM(jcpart) jcpart, + jcunit, + jcvoll, + jcpric, + vb_from, + vb_to, + price_pc AS price +FROM + ranged; + +--CREATE INDEX pricelist_ranged_idx ON pricing.pricelist_ranged(jcpart, jcplcd, vb_from, vb_to); diff --git a/new_targets/tables/target_prices.ms.sql b/new_targets/tables/target_prices.ms.sql index 9385860..8c38661 100644 --- a/new_targets/tables/target_prices.ms.sql +++ b/new_targets/tables/target_prices.ms.sql @@ -16,3 +16,26 @@ ALTER TABLE pricing.target_prices ADD CONSTRAINT uq_target_prices_unique_combo UNIQUE (stlc, ds, chan, tier, vol, lower_bound); +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