forecast_api/route_sql/copy_orders.sql

513 lines
12 KiB
MySQL
Raw Normal View History

2019-03-24 16:03:32 -04:00
BEGIN;
--\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 o
LEFT OUTER JOIN gld ON
gld.fspr = o.fspr
WHERE
(
o.adj_orderdate BETWEEN '2018-06-01' AND '2019-03-24'
OR o.calc_status IN ('OPEN','BACKORDER')
OR o.fspr BETWEEN '1901' AND '1910'
)
AND fs_line = '41010'
AND calc_status <> 'CANCELED'
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
--AND adj_orderdate <= adj_shipdate --exclude poorly date
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-25' AND '2019-05-31'
AND fs_line = '41010'
AND calc_status <> 'CANCELED'
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
AND adj_orderdate <= adj_shipdate --exclude bogus ship date orders
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;
COMMIT;