diff --git a/route_sql/build/build_forecast.sql b/route_sql/build/build_forecast.sql new file mode 100644 index 0000000..26c188a --- /dev/null +++ b/route_sql/build/build_forecast.sql @@ -0,0 +1,507 @@ +--\timing +truncate table rlarp.osmfs; + +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 +,cop AS ( + SELECT + o.plnt + ,o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.dhincr + ,o.diext + ,o.ditdis + ,o.dcodat + ,o.ddqdat + ,o.dcmdat + ,o.dhidat + ,o.fspr + ,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.quota_rep + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.ord_gldc + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,sum(o.fb_qty) fb_qty + ,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 + ,sum(o.fb_val_loc) fb_val_loc + ,sum(o.fb_val_loc_pl) fb_val_loc_pl + ,o.calc_status + ,o.flag + ,o.orderdate + ,o.requestdate + ,greatest(least(o.shipdate,gld.edat),gld.sdat) shipdate + ,o.adj_orderdate + ,o.adj_requestdate + ,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) adj_shipdate + ,'9p3' "version" + ,'actual' iter + FROM + rlarp.osm_dev o + LEFT OUTER JOIN gld ON + gld.fspr = o.fspr + WHERE + ( + o.adj_orderdate BETWEEN '2019-06-01' AND '2019-01-31' + OR o.calc_status IN ('OPEN','BACKORDER') + OR o.fspr BETWEEN '2001' AND '2008' + ) + AND fs_line = '41010' + AND calc_status <> 'CANCELED' + GROUP BY + o.plnt + ,o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.dhincr + ,o.diext + ,o.ditdis + ,o.dcodat + ,o.ddqdat + ,o.dcmdat + ,o.dhidat + ,o.fspr + ,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.quota_rep + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.ord_gldc + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,o.calc_status + ,o.flag + ,o.orderdate + ,o.requestdate + ,greatest(least(o.shipdate,gld.edat),gld.sdat) + ,o.adj_orderdate + ,o.adj_requestdate + ,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) + UNION ALL + SELECT + o.plnt + ,o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.dhincr + ,o.diext + ,o.ditdis + ,o.dcodat + ,o.ddqdat + ,o.dcmdat + ,o.dhidat + ,o.fspr + ,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.quota_rep + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.ord_gldc + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,sum(o.fb_qty) fb_qty + ,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 + ,sum(o.fb_val_loc) fb_val_loc + ,sum(o.fb_val_loc_pl) fb_val_loc_pl + ,o.calc_status + ,o.flag + ,o.orderdate + ,o.requestdate + ,greatest(least(o.shipdate,gld.edat),gld.sdat) shipdate + ,o.adj_orderdate + ,o.adj_requestdate + ,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) adj_shipdate + ,'9p3' "version" + ,'forecast' iter + FROM + rlarp.osmf o + LEFT OUTER JOIN gld ON + gld.fspr = o.fspr + WHERE + o.adj_orderdate BETWEEN '2019-03-01' AND '2019-05-31' + AND fs_line = '41010' + AND calc_status <> 'CANCELED' + GROUP BY + o.plnt + ,o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.dhincr + ,o.diext + ,o.ditdis + ,o.dcodat + ,o.ddqdat + ,o.dcmdat + ,o.dhidat + ,o.fspr + ,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.quota_rep + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.ord_gldc + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,o.calc_status + ,o.flag + ,o.orderdate + ,o.requestdate + ,greatest(least(o.shipdate,gld.edat),gld.sdat) + ,o.adj_orderdate + ,o.adj_requestdate + ,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) +) +,incr AS ( + SELECT + o.plnt + ,o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.dhincr + ,o.diext + ,o.ditdis + ,o.dcodat + ,o.ddqdat + ,o.dcmdat + ,o.dhidat + ,gld.fspr + ,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.quota_rep + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.ord_gldc + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,sum(o.fb_qty) fb_qty + ,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 + ,sum(o.fb_val_loc) fb_val_loc + ,sum(o.fb_val_loc_pl) fb_val_loc_pl + ,o.calc_status + ,o.flag + ----these dates should already be snapped since the derive from the adjusted set + ,o.orderdate + interval '1 year' orderdate + ,o.requestdate + interval '1 year' requestdate + ,o.shipdate + interval '1 year' shipdate + ,o.adj_orderdate + interval '1 year' adj_orderdate + ,o.adj_requestdate + interval '1 year' adj_requestdate + ,o.adj_shipdate + interval '1 year' adj_shipdate + ,'b20' "version" + ,'copy' iter + FROM + cop o + LEFT OUTER JOIN gld ON + (o.adj_shipdate + interval '1 year') BETWEEN gld.sdat AND gld.edat + WHERE + adj_orderdate BETWEEN '2018-06-01' AND '2019-05-31' + GROUP BY + o.plnt + ,o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.dhincr + ,o.diext + ,o.ditdis + ,o.dcodat + ,o.ddqdat + ,o.dcmdat + ,o.dhidat + ,gld.fspr + ,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.quota_rep + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.ord_gldc + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,o.calc_status + ,o.flag + ,o.orderdate + interval '1 year' + ,o.requestdate + interval '1 year' + ,o.shipdate + interval '1 year' + ,o.adj_orderdate + interval '1 year' + ,o.adj_requestdate + interval '1 year' + ,o.adj_shipdate + interval '1 year' +) +INSERT INTO rlarp.osmfs +SELECT * FROM incr +UNION ALL +SELECT * FROM cop; + +---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; \ No newline at end of file diff --git a/route_sql/columns.md b/route_sql/columns.md new file mode 100644 index 0000000..c5e4459 --- /dev/null +++ b/route_sql/columns.md @@ -0,0 +1,115 @@ +| column | osmp_dev | source | osm_stack_retain | ui | +| -------------- | -------- | -------- | ---------------- | --- | +| ddord# | x | null | x | | +| dditm# | x | null | | | +| fgbol# | x | null | | | +| fgent# | x | null | | | +| diinv# | x | null | x | | +| dilin# | x | null | | | +| quoten | x | null | x | | +| quotel | x | null | | | +| dcodat | x | null | | | +| ddqdat | x | null | | | +| dcmdat | x | null | | | +| fesdat | x | null | | | +| dhidat | x | null | | | +| fesind | x | null | | | +| dhpost | x | null | | | +| fspr | x | forecast | | | +| ddqtoi | x | forecast | | | +| ddqtsi | x | null | | | +| fgqshp | x | null | | | +| diqtsh | x | null | | | +| diext | x | null | | | +| ditdis | x | null | | | +| discj | x | null | | | +| dhincr | x | forecast | | | +| plnt | x | forecast | x | | +| promo | x | forecast | x | x | +| return_reas | x | null | | | +| terms | x | forecast | | | +| custpo | x | null | | | +| remit_to | x | forecast | | | +| bill_class | x | cust | x | | +| bill_cust | x | forecast | | x | +| bill_rep | x | cust | | | +| bill_terr | x | cust | | | +| ship_class | x | cust | x | | +| ship_cust | x | forecast | x | x | +| ship_rep | x | cust | | | +| ship_terr | x | cust | | | +| dsm | x | forecast | x | x | +| account | x | cust | x | x | +| shipgrp | x | cust | x | x | +| geo | x | cust | x | | +| chan | x | cust | x | x | +| chansub | x | cust | x | x | +| chanretail | | ui_only | | x | +| orig_ctry | x | plnt | | | +| orig_prov | x | plnt | | | +| orig_post | x | plnt | | | +| bill_ctry | x | cust | x | | +| bill_prov | x | cust | x | | +| bill_post | x | cust | x | | +| dest_ctry | x | cust | x | | +| dest_prov | x | cust | x | | +| dest_post | x | cust | x | | +| part | x | forecast | x | | +| partd | | ui_only | | x | +| part_groupd | | ui_only | | x | +| styc | x | itemm | x | | +| colc | x | itemm | x | | +| colgrp | x | itemm | x | | +| coltier | x | itemm | x | | +| colstat | x | itemm | | | +| sizc | x | itemm | x | | +| pckg | x | itemm | x | | +| kit | x | itemm | x | | +| brnd | x | itemm | x | x | +| majg | x | itemm | x | | +| majgd | | ui_only | | x | +| ming | x | itemm | x | | +| mingd | | ui_only | | x | +| majs | x | itemm | x | | +| majsd | | ui_only | | x | +| mins | x | itemm | x | | +| minsd | | ui_only | | x | +| gldco | x | itemm | | | +| gldc | x | itemm | | | +| glec | x | itemm | x | | +| segm | | ui_only | | x | +| harm | x | itemm | | | +| clss | x | itemm | x | | +| brand | x | itemm | | | +| assc | x | itemm | | | +| ddunit | x | itemm | | | +| unti | x | itemm | | | +| lbs | x | itemm | x | | +| plt | x | punit | x | | +| plcd | x | iprcbhc | x | | +| fs_line | x | forecast | x | | +| r_currency | x | forecast | x | | +| r_rate | x | forecast | x | | +| c_currency | x | forecast | x | | +| c_rate | x | forecast | x | | +| fb_qty | x | forecast | x | x | +| fb_val_loc | x | forecast | x | x | +| value_usd | | ui_only | | x | +| fb_val_loc_dis | x | null | | | +| fb_val_loc_qt | x | null | x | | +| fb_val_loc_pl | x | pricel | x | | +| fb_val_loc_tar | x | target | x | | +| fb_cst_loc | x | forecast | x | x | +| cost_loc | | ui_only | | x | +| fb_cst_loc_cur | x | icstx | x | | +| fb_cst_loc_fut | x | icstx | | | +| calc_status | x | forecast | x | | +| flag | x | forecast | x | | +| odate | x | forecast | x | x | +| oseas | x | forecast | x | x | +| rdate | x | forecast | x | x | +| rseas | x | forecast | x | x | +| sdate | x | forecast | x | x | +| sseas | x | forecast | x | x | +| version | x | forecast | | x | +| iter | x | forecast | | x | \ No newline at end of file