From e7904d50403dfb4688bffa936b8b46decd92a9ae Mon Sep 17 00:00:00 2001 From: Trowbridge Date: Wed, 12 Feb 2020 17:12:49 -0500 Subject: [PATCH] initial swipe at updating forecast structure --- route_sql/build/build_forecast.sql | 875 ++++++++++++++++------------- route_sql/columns.md | 241 ++++---- 2 files changed, 595 insertions(+), 521 deletions(-) diff --git a/route_sql/build/build_forecast.sql b/route_sql/build/build_forecast.sql index 26c188a..26490d5 100644 --- a/route_sql/build/build_forecast.sql +++ b/route_sql/build/build_forecast.sql @@ -25,480 +25,543 @@ gld AS ( --AND DIGITS(N1FSYP) = '1901' ) --SELECT * FROM gld -,cop AS ( +,baseline 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 + -----------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 - ,o.remit_to - ,o.bill_class + -----------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 + ,o.promo + ,null::text return_reas + ,o.terms + ,null::text custpo + ,null::text remit_to + ,null::text 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 + ,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 - ,o.ord_gldc - ,o.majg - ,o.ming - ,o.majs - ,o.mins - ,o.gldc - ,o.glec - ,o.harm - ,o.clss - ,o.brand - ,o.assc + ,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::text lbs + ,null::text plt + ,null::text plcd ,o.fs_line ,o.r_currency - ,o.r_rate + ,null::text r_rate ,o.c_currency - ,o.c_rate - ,o.ddqtoi - ,o.ddqtsi - ,o.fgqshp - ,o.diqtsh + ,null::text 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 - ,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 + ,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 ( - o.adj_orderdate BETWEEN '2019-06-01' AND '2019-01-31' - OR o.calc_status IN ('OPEN','BACKORDER') + o.odate BETWEEN '2019-06-01' AND '2019-01-31' + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2020-02-01') 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.fspr + ,plnt ,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 + ,ship_cust ,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) + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,greatest(least(o.sdate,gld.edat),gld.sdat) + ,ss.ssyr 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 + -----------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 + interval '1 year' dcodat + ,o.rdate + interval '1 year' ddqdat + ,null::date dcmdat + ,null::date fesdat + ,greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' dhidat + ,null::text fesind + ,null::text dhpost ,o.fspr - ,o.remit_to - ,o.bill_class + -----------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 + ,o.promo + ,null::text return_reas + ,o.terms + ,null::text custpo + ,null::text remit_to + ,null::text 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 + ,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 - ,o.ord_gldc - ,o.majg - ,o.ming - ,o.majs - ,o.mins - ,o.gldc - ,o.glec - ,o.harm - ,o.clss - ,o.brand - ,o.assc + ,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::text lbs + ,null::text plt + ,null::text plcd ,o.fs_line ,o.r_currency - ,o.r_rate + ,null::text r_rate ,o.c_currency - ,o.c_rate - ,o.ddqtoi - ,o.ddqtsi - ,o.fgqshp - ,o.diqtsh + ,null::text 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 - ,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 + ,o.odate + interval '1 year' odate + ,o.oseas + 1 rseas + ,o.rdate + interval '1 year' rdate + ,o.rseas + 1 rseas + -----when null, greatest/least is just going to act like coalesce + ,greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' sdate + ,ss.ssyr sseas + ,'actuals' "version" + ,'actuals_plug' iter FROM - rlarp.osmf o + rlarp.osm_dev o LEFT OUTER JOIN gld ON gld.fspr = o.fspr + LEFT OUTER JOIN gld ss ON + greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' BETWEEN ss.sdat AND ss.edat WHERE - o.adj_orderdate BETWEEN '2019-03-01' AND '2019-05-31' + o.odate BETWEEN '2019-02-01' AND '2019-05-31' + AND fs_line = '41010' + AND calc_status <> 'CANCELED' + ------exclude actuals for now and use forecast to get the plug for the rest of the year + AND false + GROUP BY + o.fspr + ,plnt + ,o.promo + ,o.terms + ,o.bill_cust + ,ship_cust + ,o.part + ,o.fs_line + ,o.r_currency + ,o.c_currency + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,greatest(least(o.sdate,gld.edat),gld.sdat) + ,ss.ssyr + UNION ALL + 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 + interval '1 year' dcodat + ,o.rdate + interval '1 year' ddqdat + ,null::date dcmdat + ,null::date fesdat + ,greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' 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 + ,o.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::text lbs + ,null::text plt + ,null::text plcd + ,o.fs_line + ,o.r_currency + ,null::text r_rate + ,o.c_currency + ,null::text 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 odate + ,o.oseas rseas + ,o.rdate rdate + ,o.rseas rseas + -----when null, greatest/least is just going to act like coalesce + ,greatest(least(o.sdate,gld.edat),gld.sdat) sdate + ,ss.ssyr sseas + ,'actuals' "version" + ,'forecast_plug' iter + FROM + rlarp.osmp_dev o + LEFT OUTER JOIN gld ON + gld.fspr = o.fspr + LEFT OUTER JOIN gld ss ON + greatest(least(o.sdate,gld.edat),gld.sdat) BETWEEN ss.sdat AND ss.edat + WHERE + o.odate BETWEEN '2020-02-01' AND '2020-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.fspr + ,plnt ,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 + ,ship_cust ,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) + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,greatest(least(o.sdate,gld.edat),gld.sdat) + ,ss.ssyr ) ,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' +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" + ,'baseline' iter +FROM + baseline o + LEFT OUTER JOIN gld ON + o.sdate + interval '1 year' BETWEEN gld.sdat and gld.edat ) -INSERT INTO rlarp.osmfs +INSERT INTO rlarp.osmf_dev SELECT * FROM incr UNION ALL -SELECT * FROM cop; +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'; diff --git a/route_sql/columns.md b/route_sql/columns.md index c5e4459..6dae6cb 100644 --- a/route_sql/columns.md +++ b/route_sql/columns.md @@ -1,115 +1,126 @@ -| 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 +|column |alt_name |osmp_dev|osm_fcpool|osmp_source|osm_stack_retain|ui |revised_pool| +|---------------|--------------|--------|----------|-----------|----------------|---|------------| +|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 | | |x | +|ddqtoi | |x | |forecast | | |x | +|ddqtsi | |x | |null | | | | +|fgqshp | |x | |null | | | | +|diqtsh | |x | |null | | | | +|diext | |x | |null | | | | +|ditdis | |x | |null | | | | +|discj | |x | |null | | | | +|dhincr | |x | |forecast | | |x | +|plnt | |x | |forecast |x | |x | +|promo | |x | |forecast |x |x |x | +|return_reas | |x | |null | | | | +|terms | |x | |forecast | | |x | +|custpo | |x | |null | | | | +|remit_to | |x | |forecast | | |x | +|bill_class | |x | |cust |x | | | +|bill_cust | |x | |forecast | | |x | +|bill_cust_descr| | | |ui_only | |x |x | +|bill_rep | |x | |cust | | | | +|bill_terr | |x | |cust | | | | +|ship_class | |x | |cust |x | | | +|ship_cust | |x | |forecast |x | |x | +|ship_cust_descr| | | |ui_only | |x |x | +|ship_rep | |x | |cust | | | | +|ship_terr | |x | |cust | | | | +|dsm |quota_rep |x | |forecast |x |x |x | +|quota_rep_descr| | | |ui_only | |x |x | +|account |billto_group |x | |cust |x |x |x | +|shipgrp |shipto_group |x | |cust |x |x |x | +|geo | |x | |cust |x | | | +|chan | |x | |cust |x |x |x | +|chansub |mod_chan |x | |cust |x |x |x | +|chanretail |mod_chansub | | |ui_only | |x |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 | |x | +|part_descr | | | |ui_only | |x |x | +|part_group | | | |ui_only | |x |x | +|styc | |x | |itemm |x | | | +|colc |color |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 |branding |x | |itemm |x |x |x | +|majg | |x | |itemm |x | | | +|majgd |majg_descr | | |ui_only | |x |x | +|ming | |x | |itemm |x | | | +|mingd |ming_descr | | |ui_only | |x |x | +|majs | |x | |itemm |x | | | +|majsd |majs_descr | | |ui_only | |x |x | +|mins | |x | |itemm |x | | | +|minsd |mins_descr | | |ui_only | |x |x | +|gldco |ord_gldc |x | |itemm | | | | +|gldc | |x | |itemm | | | | +|glec | |x | |itemm |x | | | +|segm | | | |ui_only | |x |x | +|harm | |x | |itemm | | | | +|clss | |x | |itemm |x | | | +|brand | |x | |itemm | | | | +|assc | |x | |itemm | | | | +|ddunit | |x | |itemm | | | | +|unti |units |x | |itemm | | | | +|lbs | |x | |itemm |x | | | +|plt | |x | |punit |x | | | +|plcd | |x | |iprcbhc |x | | | +|fs_line | |x | |forecast |x | |x | +|r_currency | |x | |forecast |x | |x | +|r_rate | |x | |forecast |x | |x | +|c_currency | |x | |forecast |x | |x | +|c_rate | |x | |forecast |x | |x | +|fb_qty | |x | |forecast |x |x |x | +|fb_val_loc |value_loc |x | |forecast |x |x |x | +|value_usd | | | |ui_only | |x |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 |cost_loc |x | |forecast |x |x |x | +|cost_usd | | | |ui_only | |x |x | +|fb_cst_loc_cur | |x | |icstx |x | | | +|fb_cst_loc_fut | |x | |icstx | | | | +|calc_status | |x | |forecast |x | |x | +|flag | |x | |forecast |x | |x | +|odate |orderdate |x | |forecast |x |x |x | +|order_month | | | |ui_only | |x |x | +|oseas |order_season |x | |forecast |x |x |x | +|rdate |requestdate |x | |forecast |x |x |x | +|request_month | | | |ui_only | |x |x | +|rseas |request_season|x | |forecast |x |x |x | +|sdate |shipdate |x | |forecast |x |x |x | +|ship_month | | | |ui_only | |x |x | +|sseas |ship_season |x | |forecast |x |x |x | +|version | |x | |forecast | |x |x | +|iter | |x | |forecast | |x |x | +|log | |x | |forecast | |x |x | +|comment | | | |ui_only | |x |x | +|iterdet | | | |forecast | | |x | +|iterdef | | | |forecast | | |x | +|director_descr | | | |forecast | | |x |