diff --git a/build/act_to_fcst/exec_actual_to_forecast.sql b/build/act_to_fcst/exec_actual_to_forecast.sql new file mode 100644 index 0000000..963afec --- /dev/null +++ b/build/act_to_fcst/exec_actual_to_forecast.sql @@ -0,0 +1,2 @@ +DELETE FROM rlarp.osmf_dev WHERE dsm = 'PW'; +INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev; diff --git a/build/act_to_fcst/merge_actuals_pool.sql b/build/act_to_fcst/merge_actuals_pool.sql new file mode 100644 index 0000000..051d9dd --- /dev/null +++ b/build/act_to_fcst/merge_actuals_pool.sql @@ -0,0 +1,163 @@ +BEGIN; + +DELETE FROM rlarp.osm_pool WHERE quota_rep_descr = 'PW'; + +INSERT INTO rlarp.osm_pool +WITH +repc AS ( + SELECT + LTRIM(RTRIM(C.A9)) RCODE + ,C.A30 REPP + ,COALESCE(Q.DIR,'Other') DIRECTOR + FROM + LGDAT.CODE C + LEFT OUTER JOIN RLARP.QRH Q ON + Q.QR = LTRIM(RTRIM(C.A9)) + WHERE + C.A2 = 'MM' +) +,SEG AS ( + SELECT + GLEC + ,SEGM + FROM + ( + VALUES + ('1CU','Retail'), + ('1GR','Greenhouse'), + ('1NU','Nursery'), + ('1RE','Retail'), + ('2WI','Greenhouse'), + ('3BM','Other'), + ('3CO','Other'), + ('3PE','Other'), + ('3PP','Other'), + ('4CO','Other'), + ('4RA','Other'), + ('9MI','Other'), + ('9SA','Other'), + ('9TO','Other') + ) X(GLEC, SEGM) +) +----------------------------------------------------sales major codes---------------------------------------------------------------------------------------------------------------------------------- +,SJ AS ( + SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') = '' +) +----------------------------------------------------sales minor codes---------------------------------------------------------------------------------------------------------------------------------- +,SI AS ( + SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') <> '' +) +SELECT + fspr + ,plnt + ,promo + ,terms + ,bill_cust||' - '||bc.bvname bill_cust_descr + ,ship_cust||' - '||sc.bvname ship_cust_descr + ,dsm + ,coalesce(repc.repp,dsm) quota_rep_descr + ,repc.director + ,account billto_group + ,shipgrp shipto_group + ,chan + ,chansub + ,CASE seg.segm + WHEN 'Retail' THEN + CASE o.bill_class + WHEN 'RMAS' THEN 'MASS' + WHEN 'RNAT' THEN 'NATIONAL' + ELSE 'OTHER' + END + ELSE o.chan + END chan_retail + ,part + ,part||coalesce(' - '||i.descr,'') part_descr + ,stlcd part_group + ,brnd branding + ,o.majg||' - '||i.majgd majg_descr + ,o.ming||' - '||i.mingd ming_descr + ,o.majs||' - '||i.majsd majs_descr + ,o.mins||' - '||i.minsd mins_descr + ,seg.segm + ,CASE WHEN o.majg = '610' THEN 'Fiber' ELSE 'Plastic' END substance + ,fs_line + ,r_currency + ,r_rate + ,c_currency + ,c_rate + ,fb_qty units + ,fb_val_loc value_loc + ,fb_val_loc * r_rate value_usd + ,fb_cst_loc_cur cost_loc + ,fb_cst_loc_cur * c_rate cost_usd + ,calc_status + ,flag + ,o.odate order_date + ,to_char(CASE WHEN extract(month FROM o.odate) >= 6 THEN -5 ELSE 7 END + extract(month FROM o.odate),'FM00')||' - '||to_char(o.odate,'TMMon') order_month + ,oseas order_season + ,rdate request_date + ,to_char(CASE WHEN extract(month FROM o.rdate) >= 6 THEN -5 ELSE 7 END + extract(month FROM o.rdate),'FM00')||' - '||to_char(o.rdate,'TMMon') request_month + ,rseas request_season + ,sdate ship_date + ,to_char(CASE WHEN extract(month FROM o.sdate) >= 6 THEN -5 ELSE 7 END + extract(month FROM o.sdate),'FM00')||' - '||to_char(o.sdate,'TMMon') ship_month + ,sseas ship_season + ,version + ,iter + ,logload.id logid + ,logload.doc->>'tag' tag + ,logload.doc->>'message' "comment" + ,logload.doc->>'type' module +FROM + rlarp.osmfs_dev o + INNER JOIN rlarp.osm_log logload ON + logload.id = 1 + LEFT OUTER JOIN lgdat.cust bc ON + bc.bvcust = o.bill_cust + LEFT OUTER JOIN lgdat.cust sc ON + sc.bvcust = o.ship_cust + LEFT OUTER JOIN repc ON + repc.rcode = o.dsm + /* + LEFT OUTER JOIN lgdat.majg ON + bqgrp = o.majg + LEFT OUTER JOIN lgdat.mmgp ON + brmgrp = o.ming + AND BRGRP = o.majg + LEFT OUTER JOIN si ON + si.bsmjcd = o.majs + AND si.bsmncd = o.mins + LEFT OUTER JOIN sj ON + sj.bsmjcd = o.majs + */ + LEFT OUTER JOIN seg ON + seg.glec = o.glec + LEFT OUTER JOIN rlarp.itemm i ON + i.item = o.part +WHERE + dsm = 'PW'; + +/* +SELECT + "version", + iter, + order_season, + order_month , + sum(value_usd ) value_usd +FROM + RLARP.osm_pool op +WHERE + --oseas = 2020 + fs_line = '41010' + --AND odate < '2020-04-01' + AND CALC_STATUS <> 'CANCELED' + AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') +GROUP BY + "version", + iter, + order_season, + order_month; +*/ + +--ROLLBACK; + +commit; diff --git a/build/act_to_fcst/snap_cost_current.sql b/build/act_to_fcst/snap_cost_current.sql new file mode 100644 index 0000000..c27f95a --- /dev/null +++ b/build/act_to_fcst/snap_cost_current.sql @@ -0,0 +1,43 @@ +BEGIN; + +WITH +plist AS ( + SELECT DISTINCT + part + ,plnt + FROM + rlarp.osmfs_dev + -----prevent a list of fake parts + INNER JOIN lgdat.stka ON + v6part = part + AND v6plnt = plnt +) +,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; + --AND version = 'b21'; + +commit; diff --git a/build/act_to_fcst/snap_customer.sql b/build/act_to_fcst/snap_customer.sql new file mode 100644 index 0000000..ec61baf --- /dev/null +++ b/build/act_to_fcst/snap_customer.sql @@ -0,0 +1,209 @@ +----------------------------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; diff --git a/build/act_to_fcst/snap_fspr.sql b/build/act_to_fcst/snap_fspr.sql new file mode 100644 index 0000000..a6a3e13 --- /dev/null +++ b/build/act_to_fcst/snap_fspr.sql @@ -0,0 +1,30 @@ +UPDATE + rlarp.osmfs_dev f +SET + fspr = gld.fspr +FROM + ( + SELECT + N1COMP COMP + ,N1CCYY FSYRq + ,KPMAXP PERDS + ,N1FSPP PERD + ,to_char(N1FSYP,'FM0000') FSPR + ,N1SD01 SDAT + ,N1ED01 EDAT + ,to_char(N1ED01,'yymm') CAPR + ,N1ED01 - N1SD01 +1 NDAYS + ,CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(YEAR FROM N1ED01) + 1 ELSE EXTRACT(YEAR FROM N1ED01) END SSYR + ,to_char(CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(MONTH FROM N1ED01) -5 ELSE EXTRACT(MONTH FROM N1ED01) +7 END,'00') SSPR + FROM + LGDAT.GLDATREF + INNER JOIN LGDAT.GLDATE ON + KPCOMP = N1COMP AND + KPCCYY = N1CCYY + WHERE + N1COMP = 93 + --AND DIGITS(N1FSYP) = '1901' + ) gld +WHERE + f.sdate BETWEEN gld.sdat AND gld.edat + AND coalesce(f.fspr,'') <> gld.fspr; diff --git a/build/act_to_fcst/snap_fx.sql b/build/act_to_fcst/snap_fx.sql new file mode 100644 index 0000000..606d732 --- /dev/null +++ b/build/act_to_fcst/snap_fx.sql @@ -0,0 +1,9 @@ +------------update fx rates----------------------------------------------------------------- +UPDATE rlarp.osmf_dev SET r_rate = .7518 WHERE r_currency = 'CA' AND version = 'b21'; +UPDATE rlarp.osmf_dev SET r_rate = 1.0000 WHERE r_currency = 'US' AND version = 'b21'; +UPDATE rlarp.osmf_dev SET c_rate = .7518 WHERE c_currency = 'CA' AND version = 'b21'; +UPDATE rlarp.osmf_dev SET c_rate = 1.0000 WHERE c_currency = 'US' AND version = 'b21'; +UPDATE rlarp.osm_pool SET r_rate = .7518 WHERE r_currency = 'CA' AND version = 'b21'; +UPDATE rlarp.osm_pool SET value_usd = value_loc * r_rate WHERE r_currency = 'CA' AND version = 'b21'; +UPDATE rlarp.osm_pool SET c_rate = .7518 WHERE c_currency = 'CA' AND version = 'b21'; +UPDATE rlarp.osm_pool SET cost_usd = cost_loc * c_rate WHERE c_currency = 'CA' AND version = 'b21'; \ No newline at end of file diff --git a/build/act_to_fcst/snap_itemm.sql b/build/act_to_fcst/snap_itemm.sql new file mode 100644 index 0000000..299d77a --- /dev/null +++ b/build/act_to_fcst/snap_itemm.sql @@ -0,0 +1,27 @@ +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 diff --git a/build/act_to_fcst/stage_act_to_forecast.sql b/build/act_to_fcst/stage_act_to_forecast.sql new file mode 100644 index 0000000..b4cd26f --- /dev/null +++ b/build/act_to_fcst/stage_act_to_forecast.sql @@ -0,0 +1,299 @@ +--\timing +truncate table rlarp.osmfs_dev; + +WITH +gld AS ( + SELECT + N1COMP COMP + ,N1CCYY FSYR + ,KPMAXP PERDS + ,N1FSPP PERD + ,to_char(N1FSYP,'FM0000') FSPR + ,N1SD01 SDAT + ,N1ED01 EDAT + ,to_char(N1ED01,'yymm') CAPR + ,N1ED01 - N1SD01 +1 NDAYS + ,CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(YEAR FROM N1ED01) + 1 ELSE EXTRACT(YEAR FROM N1ED01) END SSYR + ,to_char(CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(MONTH FROM N1ED01) -5 ELSE EXTRACT(MONTH FROM N1ED01) +7 END,'00') SSPR + FROM + LGDAT.GLDATREF + INNER JOIN LGDAT.GLDATE ON + KPCOMP = N1COMP AND + KPCCYY = N1CCYY + WHERE + N1COMP = 93 + --AND DIGITS(N1FSYP) = '1901' +) +--SELECT * FROM gld +,baseline AS ( + SELECT + -----------documents------------- + null::int "ddord#" + ,null::int "dditm#" + ,null::int "fgbol#" + ,null::int "fgent#" + ,null::int "diinv#" + ,null::int "dilin#" + ,null::int quoten + ,null::int quotel + ----------dates/status------------------ + ,o.odate dcodat + ,o.rdate ddqdat + ,null::date dcmdat + ,null::date fesdat + ,greatest(least(o.sdate,gld.edat),gld.sdat) dhidat + ,null::text fesind + ,null::text dhpost + ,o.fspr + -----------measures-------------------- + ,null::numeric ddqtoi + ,null::numeric ddqtsi + ,null::numeric fgqshp + ,null::numeric diqtsh + ,null::numeric diext + ,null::numeric ditdis + ,null::jsonb discj + ,null::text dhincr + ,plnt + ,COALESCE(o.promo,'') promo + ,null::text return_reas + ,o.terms + ,null::text custpo + ,null::text remit_to + ,null::text bill_class + ,o.bill_cust + ,null::text bill_rep + ,null::text bill_terr + ,null::text ship_class + ,ship_cust + ,null::text ship_rep + ,null::text ship_terr + ,null::text dsm + ,null::text account + ,null::text shipgrp + ,null::text geo + ,null::text chan + ,null::text chansub + ,null::text orig_ctry + ,null::text orig_prov + ,null::text orig_post + ,null::text bill_ctry + ,null::text bill_prov + ,null::text bill_post + ,null::text dest_ctry + ,null::text dest_prov + ,null::text dest_post + ,o.part + ,null::text styc + ,null::text colc + ,null::text colgrp + ,null::text coltier + ,null::text colstat + ,null::text sizc + ,null::text pckg + ,null::text kit + ,null::text brnd + ,null::text majg + ,null::text ming + ,null::text majs + ,null::text mins + ,null::text gldco + ,null::text gldc + ,null::text glec + ,null::text harm + ,null::text clss + ,null::text brand + ,null::text assc + ,null::text ddunit + ,null::text unti + ,null::numeric lbs + ,null::numeric plt + ,null::text plcd + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,sum(o.fb_qty) fb_qty + ,sum(o.fb_val_loc) fb_val_loc + ,sum(o.fb_val_loc_dis) fb_val_loc_dis + ,sum(o.fb_val_loc_qt) fb_val_loc_qt + ,sum(o.fb_val_loc_pl) fb_val_loc_pl + ,sum(o.fb_val_loc_tar) fb_val_loc_tar + ,sum(o.fb_cst_loc) fb_cst_loc + ,sum(o.fb_cst_loc_cur) fb_cst_loc_cur + ,sum(o.fb_cst_loc_fut) fb_cst_loc_fut + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + -----when null, greatest/least is just going to act like coalesce + ,greatest(least(o.sdate,gld.edat),gld.sdat) sdate + ,ss.ssyr sseas + ,'15mo' "version" + ,'actuals' iter + FROM + rlarp.osm_dev o + --snap the ship dates of the historic fiscal period + LEFT OUTER JOIN gld ON + gld.fspr = o.fspr + --get the shipping season for open orders based on the snapped date + LEFT OUTER JOIN gld ss ON + greatest(least(o.sdate,gld.edat),gld.sdat) BETWEEN ss.sdat AND ss.edat + WHERE + ( + --base period orders booked.... + o.odate BETWEEN '2019-06-01' AND '2020-05-31' + --...or any open orders currently booked before cutoff.... + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2020-05-31') + OR o.fspr BETWEEN '2001' AND '2012' + ) + AND fs_line = '41010' + AND calc_status <> 'CANCELED' + AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') + AND version = 'ACTUALS' + AND dsm = 'PW' + GROUP BY + o.fspr + ,plnt + ,COALESCE(o.promo,'') + ,o.terms + ,o.bill_cust + ,ship_cust + ,o.part + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,greatest(least(o.sdate,gld.edat),gld.sdat) + ,ss.ssyr +) +,incr AS ( +SELECT + o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.quoten + ,o.quotel + ,o.dcodat + interval '1 year' --incremented + ,o.ddqdat + interval '1 year' --incremented + ,o.dcmdat + ,o.fesdat + ,o.dhidat + interval '1 year' --incremented + ,o.fesind + ,o.dhpost + ,gld.fspr --incremented + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,o.diext + ,o.ditdis + ,o.discj + ,o.dhincr + ,o.plnt + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.remit_to + ,o.bill_class + ,o.bill_cust + ,o.bill_rep + ,o.bill_terr + ,o.ship_class + ,o.ship_cust + ,o.ship_rep + ,o.ship_terr + ,o.dsm + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.chansub + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.bill_ctry + ,o.bill_prov + ,o.bill_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.styc + ,o.colc + ,o.colgrp + ,o.coltier + ,o.colstat + ,o.sizc + ,o.pckg + ,o.kit + ,o.brnd + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldco + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.ddunit + ,o.unti + ,o.lbs + ,o.plt + ,o.plcd + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.fb_qty + ,o.fb_val_loc + ,o.fb_val_loc_dis + ,o.fb_val_loc_qt + ,o.fb_val_loc_pl + ,o.fb_val_loc_tar + ,o.fb_cst_loc + ,o.fb_cst_loc_cur + ,o.fb_cst_loc_fut + ,o.calc_status + ,o.flag + ,o.odate + interval '1 year' --incremented + ,o.oseas + 1 --incremented + ,o.rdate + interval '1 year' --incremented + ,o.rseas + 1 --incremented + ,o.sdate + interval '1 year' --incremented + ,o.sseas + 1 --incremented + ,'b21' "version" + ,'copy' iter +FROM + baseline o + LEFT OUTER JOIN gld ON + o.sdate + interval '1 year' BETWEEN gld.sdat and gld.edat +) +INSERT INTO rlarp.osmfs_dev +SELECT * FROM incr +UNION ALL +SELECT * FROM baseline; + +---identify short ships: causes disconnect with actual sales------------------------------------------------------------------- +--UPDATE rlarp.osmfs SET iter = 'short ship' WHERE calc_status = 'CLOSED' AND flag = 'REMAINDER'; + +---identify goofy ship dates: causes disconnect with sales when splicing in a forecast that has this problem------------------- +--UPDATE rlarp.osmfs SET iter = 'bad date' WHERE adj_shipdate < adj_orderdate; diff --git a/build/convert_pool_all.sql b/build/convert_pool_all.sql new file mode 100644 index 0000000..20889d4 --- /dev/null +++ b/build/convert_pool_all.sql @@ -0,0 +1,422 @@ +BEGIN; + +DELETE FROM rlarp.osmfs_dev; + +INSERT INTO + rlarp.osmfs_dev +SELECT + null::int4, + null::int4, + null::int4, + null::int4, + null::int4, + null::int4, + null::int4, + null::int4, + order_date, + request_date, + null::date, + null::date, + ship_date, + null::text, + null::text, + fspr, + null::numeric, + null::numeric, + null::numeric, + null::numeric, + null::numeric, + null::numeric, + null::jsonb, + null::text, + plnt, + promo, + null::text, + terms, + null::text, + null::text, + null::text, + rtrim(substring(bill_cust_descr,1,8)), + null::text, + null::text, + null::text, + rtrim(substring(ship_cust_descr,1,8)), + null::text, + null::text, + dsm, + billto_group, + shipto_group, + null::text, + chan, + chan, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + part, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::text, + null::numeric, + null::numeric, + null::text, + fs_line, + r_currency, + r_rate, + c_currency, + c_rate, + units, + value_loc, + null::numeric, + null::numeric, + null::numeric, + null::numeric, + cost_loc, + null::numeric, + null::numeric, + calc_status, + flag, + order_date, + order_season, + request_date, + request_season, + ship_date, + ship_season, + version, + iter +FROM + rlarp.osm_pool; + +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; + +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 = .7518 +WHERE + r_currency = 'CA'; + +UPDATE + rlarp.osmfS_dev +SET + r_rate = 1 +WHERE + r_currency = 'US'; + +UPDATE + rlarp.osmfS_dev +SET + c_rate = .7518 +WHERE + c_currency = 'CA'; + +UPDATE + rlarp.osmfS_dev +SET + c_rate = 1 +WHERE + c_currency = 'US'; + +--DELETE FROM rlarp.osmf_dev WHERE iter IN ('adj price','adj volume'); + +--INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev; + +COMMIT; diff --git a/build/temp.sql b/build/temp.sql new file mode 100644 index 0000000..259a58d --- /dev/null +++ b/build/temp.sql @@ -0,0 +1,47 @@ +WITH +gld AS ( + SELECT + N1COMP COMP + ,N1CCYY FSYR + ,KPMAXP PERDS + ,N1FSPP PERD + ,to_char(N1FSYP,'FM0000') FSPR + ,N1SD01 SDAT + ,N1ED01 EDAT + ,to_char(N1ED01,'yymm') CAPR + ,N1ED01 - N1SD01 +1 NDAYS + ,CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(YEAR FROM N1ED01) + 1 ELSE EXTRACT(YEAR FROM N1ED01) END SSYR + ,to_char(CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(MONTH FROM N1ED01) -5 ELSE EXTRACT(MONTH FROM N1ED01) +7 END,'00') SSPR + FROM + LGDAT.GLDATREF + INNER JOIN LGDAT.GLDATE ON + KPCOMP = N1COMP AND + KPCCYY = N1CCYY + WHERE + N1COMP = 93 + --AND DIGITS(N1FSYP) = '1901' +) +--SELECT * FROM gld +select oseas, sum(fb_val_loc * r_rate) + FROM + rlarp.osm_dev o + --snap the ship dates of the historic fiscal period + LEFT OUTER JOIN gld ON + gld.fspr = o.fspr + --get the shipping season for open orders based on the snapped date + LEFT OUTER JOIN gld ss ON + greatest(least(o.sdate,gld.edat),gld.sdat) BETWEEN ss.sdat AND ss.edat + WHERE + ( + --base period orders booked.... + o.odate BETWEEN '2019-06-01' AND '2020-05-31' + --...or any open orders currently booked before cutoff.... + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2020-05-31') + OR o.sseas BETWEEN '2001' AND '2012' + ) + AND fs_line = '41010' + AND calc_status <> 'CANCELED' + AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') + AND dsm = 'PW' + and version = 'ACTUALS' +group by oseas