From d5e19bc309d316fb95dc17fc031c6fbf7e4e81d4 Mon Sep 17 00:00:00 2001 From: Trowbridge Date: Tue, 25 Feb 2020 15:07:38 -0500 Subject: [PATCH] work on scripting rebuilds --- build/convert_pool.sql | 319 +++++++++++++++++++++++++++++++++++++- build/rebuild_forecast.sh | 6 + 2 files changed, 322 insertions(+), 3 deletions(-) create mode 100644 build/rebuild_forecast.sh diff --git a/build/convert_pool.sql b/build/convert_pool.sql index ad5fa78..85e835c 100644 --- a/build/convert_pool.sql +++ b/build/convert_pool.sql @@ -1,7 +1,9 @@ -DELETE FROM rlarp.osmf_dev WHERE iter IN ('adj price','adj volume'); +BEGIN; + +DELETE FROM rlarp.osmfs_dev; INSERT INTO - rlarp.osmf_dev + rlarp.osmfs_dev SELECT null::int4, null::int4, @@ -109,4 +111,315 @@ SELECT FROM rlarp.osm_pool WHERE - iter IN ('adj price','adj volume'); \ No newline at end of file + iter IN ('adj price','adj volume'); + +WITH +plist AS ( + SELECT DISTINCT + part + ,plnt + FROM + rlarp.osmfS_dev +) +,clist AS ( + SELECT + p.part + ,p.plnt + ,COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs) stdcost + FROM + plist p + LEFT OUTER JOIN lgdat.icstm im ON + im.cgpart = p.part + AND im.cgplnt = p.plnt + LEFT OUTER JOIN lgdat.icstp ip ON + ip.chpart = p.part + AND ip.chplnt = p.plnt + LEFT OUTER JOIN lgdat.icstr ir ON + ir.y0part = p.part + AND ir.y0plnt = p.plnt +) + + +UPDATE + rlarp.osmfS_dev o +SET + fb_cst_loc_cur = c.stdcost * o.fb_qty +FROM + clist c +WHERE + c.part = o.part + AND c.plnt = o.plnt; + +----------------------------SET BILL-TO REP------------------------------------ + +UPDATE + RLARP.OSMFS_DEV S +SET + BILL_REP = C.BVSALM + ,BILL_CLASS = C.BVCLAS + ,BILL_TERR = C.BVTERR + ,BILL_CTRY = C.bvctry + ,bill_prov = C.bvprcd + ,bill_post = C.bvpost + ,remit_to = c.bvcomp + ,ACCOUNT = CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END +FROM + LGDAT.CUST C +WHERE + C.BVCUST = S.BILL_CUST + AND ( + COALESCE(S.BILL_REP,'') <> C.BVSALM + OR COALESCE(S.BILL_CLASS,'') <> C.BVCLAS + OR COALESCE(S.BILL_TERR,'') <> C.BVTERR + OR COALESCE(BILL_CTRY,'') <> C.bvctry + OR COALESCE(bill_prov,'') <> C.bvprcd + OR COALESCE(bill_post,'') <> C.bvpost + OR COALESCE(remit_to,'') <> c.bvcomp::text + ); + +----------------------------SET SHIP-TO REP------------------------------------ + +UPDATE + RLARP.OSMFS_DEV S +SET + SHIP_REP = C.BVSALM + ,SHIP_CLASS = C.BVCLAS + ,SHIP_TERR = C.BVTERR + ,dest_CTRY = C.bvctry + ,dest_prov = C.bvprcd + ,dest_post = C.bvpost +FROM + LGDAT.CUST C +WHERE + C.BVCUST = S.SHIP_CUST + AND ( + COALESCE(S.SHIP_REP,'') <> C.BVSALM + OR COALESCE(S.SHIP_CLASS,'') <> C.BVCLAS + OR COALESCE(S.SHIP_TERR,'') <> C.BVTERR + OR COALESCE(dest_CTRY,'') <> C.bvctry + OR COALESCE(dest_prov,'') <> C.bvprcd + OR COALESCE(dest_post,'') <> C.bvpost + ); + +----------------------------SET BILLTO GROUP------------------------------------ + +UPDATE + RLARP.OSMFS_DEV O +SET + ACCOUNT = CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END +FROM + LGDAT.CUST C +WHERE + C.BVCUST = O.BILL_CUST + AND coalesce(account,'') <> CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END; + + + +----------------------------SET SHIPTO GROUP------------------------------------ + +UPDATE + RLARP.OSMFS_DEV O +SET + SHIPGRP = CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END +FROM + LGDAT.CUST C +WHERE + C.BVCUST = O.SHIP_CUST + AND CASE BVADR6 WHEN '' THEN BVNAME ELSE BVADR6 END <> COALESCE(O.SHIPGRP,''); + + +---------------------------SET CHANNEL----------------------------------------- + + +UPDATE + rlarp.osmFS_dev +SET + CHAN = CASE SUBSTRING(BILL_CLASS,2,3) + --if the bill to class is ditsributor, then it's either warehouse or drop + WHEN 'DIS' THEN + --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse + CASE SUBSTRING(SHIP_CLASS,2,3) + WHEN 'DIS' THEN 'WHS' + ELSE 'DRP' + END + --CASE WHEN RTRIM(SUBSTRING(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTRING(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END + --everything else does not involve a distributor and is considered direct + ELSE 'DIR' + END, + CHANSUB = CASE SUBSTRING(BILL_CLASS,2,3) + WHEN 'DIS' THEN + --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse + CASE SUBSTRING(SHIP_CLASS,2,3) + WHEN 'DIS' THEN 'WHS' + ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END + END + WHEN 'MAS' THEN 'RMN' + WHEN 'NAT' THEN 'RMN' + ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END + END +WHERE + COALESCE(CHAN,'') <> CASE SUBSTRING(BILL_CLASS,2,3) + --if the bill to class is ditsributor, then it's either warehouse or drop + WHEN 'DIS' THEN + --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse + CASE SUBSTRING(SHIP_CLASS,2,3) + WHEN 'DIS' THEN 'WHS' + ELSE 'DRP' + END + --CASE WHEN RTRIM(SUBSTRING(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTRING(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END + --everything else does not involve a distributor and is considered direct + ELSE 'DIR' + END + OR + COALESCE(CHANSUB,'') <> CASE SUBSTRING(BILL_CLASS,2,3) + WHEN 'DIS' THEN + --if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse + CASE SUBSTRING(SHIP_CLASS,2,3) + WHEN 'DIS' THEN 'WHS' + ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END + END + WHEN 'MAS' THEN 'RMN' + WHEN 'NAT' THEN 'RMN' + ELSE CASE SUBSTRING(SHIP_CLASS,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END + END; + + +---------------------------SET QUOTA REP--------------------------------------- + + +UPDATE + RLARP.OSMFS_DEV S +SET + DSM = CR.QUOTA_REP +FROM +( + SELECT DISTINCT + VERSION, + COALESCE(GLEC,'') GLEC, + COALESCE(MING,'') MING, + BILL_CUST, + SHIP_CUST, + ------------quota rep column-------------- + RTRIM( + --retail items go to currep, or if null go to 90005 + CASE WHEN S.GLEC IN ('1RE','1CU') THEN + CASE WHEN BVCTRY = 'CAN' THEN + --Rachel Bowman + '50300' + ELSE + --select customers go to select reps + CASE ACCOUNT + ------Alecia Latini------------------------------- + WHEN 'DO IT BEST' THEN '90006' + WHEN 'ACE HARDWARE' THEN '90006' + WHEN 'ALDI' THEN '90006' + WHEN 'AMAZON.COM' THEN '90006' + WHEN 'GARDEN RIDGE CORP' THEN '90006' --AKA "At Home" + WHEN 'TRUE VALUE' THEN '90006' + WHEN 'WAYFAIR' THEN '90006' + WHEN 'GRIFFIN' THEN '90006' + WHEN 'WAL-MART' THEN '90006' + ------Tony Landino-------------------------------- + WHEN 'THE HOME DEPOT' THEN '50802' + WHEN 'FRED MEYER' THEN '50802' + WHEN 'MENARDS' THEN '50802' + WHEN 'KROGER' THEN '50802' + WHEN 'OCEAN STATE JOBBERS' THEN '50802' + WHEN 'AURORA WHOLESALE' THEN '50802' + WHEN 'LEON KORRAL' THEN '50802' + --all other retail goes to Doran Marable----------- + ELSE '50200' + END + END + --minor group b52 goes to dedicated rep + ELSE + CASE WHEN MING = 'B52' THEN + 'PW' + --gdir, ndir go to bill-to rep + ELSE + CASE WHEN BILL_CLASS IN ('GDIR','NDIR') THEN + BILL_REP + ELSE + SHIP_REP + END + END + END + ) QUOTA_REP + FROM + RLARP.OSMFS_DEV S + LEFT OUTER JOIN LGDAT.CUST ON + BVCUST = BILL_CUST + WHERE + COALESCE(GLEC,'') IS NOT NULL + ) CR +WHERE + CR.VERSION = S.VERSION + AND CR.GLEC = COALESCE(S.GLEC,'') + AND CR.MING = COALESCE(S.MING,'') + AND CR.BILL_CUST = S.BILL_CUST + AND CR.SHIP_CUST = S.SHIP_CUST + AND COALESCE(S.DSM,'') <> CR.QUOTA_REP; + + +UPDATE + rlarp.osmfS_dev +SET + r_rate = .7597 +WHERE + r_currency = 'CA'; + +UPDATE + rlarp.osmfS_dev +SET + r_rate = 1 +WHERE + r_currency = 'US'; + +UPDATE + rlarp.osmfS_dev +SET + c_rate = .7597 +WHERE + c_currency = 'CA'; + +UPDATE + rlarp.osmfS_dev +SET + c_rate = 1 +WHERE + c_currency = 'US'; + + +UPDATE + RLARP.OSMFS_DEV O +SET + COLC = M.COLC + ,COLGRP = M.COLGRP + ,COLTIER = M.COLTIER + ,COLSTAT = M.COLSTAT + ,SIZC = M.SIZC + ,PCKG = M.PACKAGE + ,KIT = M.KIT + ,BRND = M.BRANDING + ,MAJG = M.MAJG + ,MING = M.MING + ,MAJS = M.MAJS + ,MINS = M.MINS + ,GLDC = M.GLCD + ,GLEC = M.GLEC + ,HARM = M.HARM + ,CLSS = M.CLSS + ,BRAND = M.BRAND + ,ASSC = M.ASSC + ,LBS = CASE M.NWUN WHEN 'KG' THEN 2.2046 ELSE 1 END*M.NWHT + ,UNTI = M.UNTI +FROM + RLARP.ITEMM M +WHERE + M.ITEM = O.PART; + +DELETE FROM rlarp.osmf_dev WHERE iter IN ('adj price','adj volume'); + +INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev; + +COMMIT; \ No newline at end of file diff --git a/build/rebuild_forecast.sh b/build/rebuild_forecast.sh new file mode 100644 index 0000000..0cdb827 --- /dev/null +++ b/build/rebuild_forecast.sh @@ -0,0 +1,6 @@ +psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/build_forecast.sql +psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/snap_cost_current.sql +psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/fx.sql +psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/customer.sql +psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/snap_itemm.sql +psql -U ptrowbridge -d ubm -p 5030 -h usmidlnx01 -f build/build_pool.sql \ No newline at end of file