initial swipe at updating forecast structure

This commit is contained in:
Trowbridge 2020-02-12 17:12:49 -05:00
parent f111c8818f
commit e7904d5040
2 changed files with 595 additions and 521 deletions

View File

@ -25,480 +25,543 @@ gld AS (
--AND DIGITS(N1FSYP) = '1901' --AND DIGITS(N1FSYP) = '1901'
) )
--SELECT * FROM gld --SELECT * FROM gld
,cop AS ( ,baseline AS (
SELECT SELECT
o.plnt -----------documents-------------
,o."ddord#" null::int "ddord#"
,o."dditm#" ,null::int "dditm#"
,o."fgbol#" ,null::int "fgbol#"
,o."fgent#" ,null::int "fgent#"
,o."diinv#" ,null::int "diinv#"
,o."dilin#" ,null::int "dilin#"
,o.promo ,null::int quoten
,o.return_reas ,null::int quotel
,o.terms ----------dates/status------------------
,o.custpo ,o.odate dcodat
,o.dhincr ,o.rdate ddqdat
,o.diext ,null::date dcmdat
,o.ditdis ,null::date fesdat
,o.dcodat ,greatest(least(o.sdate,gld.edat),gld.sdat) dhidat
,o.ddqdat ,null::text fesind
,o.dcmdat ,null::text dhpost
,o.dhidat
,o.fspr ,o.fspr
,o.remit_to -----------measures--------------------
,o.bill_class ,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_cust
,o.bill_rep ,null::text bill_rep
,o.bill_terr ,null::text bill_terr
,o.ship_class ,null::text ship_class
,o.ship_cust ,ship_cust
,o.ship_rep ,null::text ship_rep
,o.ship_terr ,null::text ship_terr
,o.quota_rep ,null::text dsm
,o.account ,null::text account
,o.shipgrp ,null::text shipgrp
,o.geo ,null::text geo
,o.chan ,null::text chan
,o.orig_ctry ,null::text chansub
,o.orig_prov ,null::text orig_ctry
,o.orig_post ,null::text orig_prov
,o.dest_ctry ,null::text orig_post
,o.dest_prov ,null::text bill_ctry
,o.dest_post ,null::text bill_prov
,null::text bill_post
,null::text dest_ctry
,null::text dest_prov
,null::text dest_post
,o.part ,o.part
,o.ord_gldc ,null::text styc
,o.majg ,null::text colc
,o.ming ,null::text colgrp
,o.majs ,null::text coltier
,o.mins ,null::text colstat
,o.gldc ,null::text sizc
,o.glec ,null::text pckg
,o.harm ,null::text kit
,o.clss ,null::text brnd
,o.brand ,null::text majg
,o.assc ,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.fs_line
,o.r_currency ,o.r_currency
,o.r_rate ,null::text r_rate
,o.c_currency ,o.c_currency
,o.c_rate ,null::text c_rate
,o.ddqtoi
,o.ddqtsi
,o.fgqshp
,o.diqtsh
,sum(o.fb_qty) fb_qty ,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) fb_cst_loc
,sum(o.fb_cst_loc_cur) fb_cst_loc_cur ,sum(o.fb_cst_loc_cur) fb_cst_loc_cur
,sum(o.fb_cst_loc_fut) fb_cst_loc_fut ,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.calc_status
,o.flag ,o.flag
,o.orderdate ,o.odate
,o.requestdate ,o.oseas
,greatest(least(o.shipdate,gld.edat),gld.sdat) shipdate ,o.rdate
,o.adj_orderdate ,o.rseas
,o.adj_requestdate -----when null, greatest/least is just going to act like coalesce
,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) adj_shipdate ,greatest(least(o.sdate,gld.edat),gld.sdat) sdate
,'9p3' "version" ,ss.ssyr sseas
,'actual' iter ,'15mo' "version"
,'actuals' iter
FROM FROM
rlarp.osm_dev o rlarp.osm_dev o
--snap the ship dates of the historic fiscal period
LEFT OUTER JOIN gld ON LEFT OUTER JOIN gld ON
gld.fspr = o.fspr 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 WHERE
( (
o.adj_orderdate BETWEEN '2019-06-01' AND '2019-01-31' o.odate BETWEEN '2019-06-01' AND '2019-01-31'
OR o.calc_status IN ('OPEN','BACKORDER') OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2020-02-01')
OR o.fspr BETWEEN '2001' AND '2008' OR o.fspr BETWEEN '2001' AND '2008'
) )
AND fs_line = '41010' AND fs_line = '41010'
AND calc_status <> 'CANCELED' AND calc_status <> 'CANCELED'
GROUP BY GROUP BY
o.plnt o.fspr
,o."ddord#" ,plnt
,o."dditm#"
,o."fgbol#"
,o."fgent#"
,o."diinv#"
,o."dilin#"
,o.promo ,o.promo
,o.return_reas
,o.terms ,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_cust
,o.bill_rep ,ship_cust
,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.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.fs_line
,o.r_currency ,o.r_currency
,o.r_rate
,o.c_currency ,o.c_currency
,o.c_rate
,o.ddqtoi
,o.ddqtsi
,o.fgqshp
,o.diqtsh
,o.calc_status ,o.calc_status
,o.flag ,o.flag
,o.orderdate ,o.odate
,o.requestdate ,o.oseas
,greatest(least(o.shipdate,gld.edat),gld.sdat) ,o.rdate
,o.adj_orderdate ,o.rseas
,o.adj_requestdate ,greatest(least(o.sdate,gld.edat),gld.sdat)
,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) ,ss.ssyr
UNION ALL UNION ALL
SELECT SELECT
o.plnt -----------documents-------------
,o."ddord#" null::int "ddord#"
,o."dditm#" ,null::int "dditm#"
,o."fgbol#" ,null::int "fgbol#"
,o."fgent#" ,null::int "fgent#"
,o."diinv#" ,null::int "diinv#"
,o."dilin#" ,null::int "dilin#"
,o.promo ,null::int quoten
,o.return_reas ,null::int quotel
,o.terms ----------dates/status------------------
,o.custpo ,o.odate + interval '1 year' dcodat
,o.dhincr ,o.rdate + interval '1 year' ddqdat
,o.diext ,null::date dcmdat
,o.ditdis ,null::date fesdat
,o.dcodat ,greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' dhidat
,o.ddqdat ,null::text fesind
,o.dcmdat ,null::text dhpost
,o.dhidat
,o.fspr ,o.fspr
,o.remit_to -----------measures--------------------
,o.bill_class ,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_cust
,o.bill_rep ,null::text bill_rep
,o.bill_terr ,null::text bill_terr
,o.ship_class ,null::text ship_class
,o.ship_cust ,ship_cust
,o.ship_rep ,null::text ship_rep
,o.ship_terr ,null::text ship_terr
,o.quota_rep ,null::text dsm
,o.account ,null::text account
,o.shipgrp ,null::text shipgrp
,o.geo ,null::text geo
,o.chan ,null::text chan
,o.orig_ctry ,null::text chansub
,o.orig_prov ,null::text orig_ctry
,o.orig_post ,null::text orig_prov
,o.dest_ctry ,null::text orig_post
,o.dest_prov ,null::text bill_ctry
,o.dest_post ,null::text bill_prov
,null::text bill_post
,null::text dest_ctry
,null::text dest_prov
,null::text dest_post
,o.part ,o.part
,o.ord_gldc ,null::text styc
,o.majg ,null::text colc
,o.ming ,null::text colgrp
,o.majs ,null::text coltier
,o.mins ,null::text colstat
,o.gldc ,null::text sizc
,o.glec ,null::text pckg
,o.harm ,null::text kit
,o.clss ,null::text brnd
,o.brand ,null::text majg
,o.assc ,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.fs_line
,o.r_currency ,o.r_currency
,o.r_rate ,null::text r_rate
,o.c_currency ,o.c_currency
,o.c_rate ,null::text c_rate
,o.ddqtoi
,o.ddqtsi
,o.fgqshp
,o.diqtsh
,sum(o.fb_qty) fb_qty ,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) fb_cst_loc
,sum(o.fb_cst_loc_cur) fb_cst_loc_cur ,sum(o.fb_cst_loc_cur) fb_cst_loc_cur
,sum(o.fb_cst_loc_fut) fb_cst_loc_fut ,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.calc_status
,o.flag ,o.flag
,o.orderdate ,o.odate + interval '1 year' odate
,o.requestdate ,o.oseas + 1 rseas
,greatest(least(o.shipdate,gld.edat),gld.sdat) shipdate ,o.rdate + interval '1 year' rdate
,o.adj_orderdate ,o.rseas + 1 rseas
,o.adj_requestdate -----when null, greatest/least is just going to act like coalesce
,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) adj_shipdate ,greatest(least(o.sdate,gld.edat),gld.sdat) + interval '1 year' sdate
,'9p3' "version" ,ss.ssyr sseas
,'forecast' iter ,'actuals' "version"
,'actuals_plug' iter
FROM FROM
rlarp.osmf o rlarp.osm_dev o
LEFT OUTER JOIN gld ON LEFT OUTER JOIN gld ON
gld.fspr = o.fspr 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 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 fs_line = '41010'
AND calc_status <> 'CANCELED' AND calc_status <> 'CANCELED'
GROUP BY GROUP BY
o.plnt o.fspr
,o."ddord#" ,plnt
,o."dditm#"
,o."fgbol#"
,o."fgent#"
,o."diinv#"
,o."dilin#"
,o.promo ,o.promo
,o.return_reas
,o.terms ,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_cust
,o.bill_rep ,ship_cust
,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.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.fs_line
,o.r_currency ,o.r_currency
,o.r_rate
,o.c_currency ,o.c_currency
,o.c_rate
,o.ddqtoi
,o.ddqtsi
,o.fgqshp
,o.diqtsh
,o.calc_status ,o.calc_status
,o.flag ,o.flag
,o.orderdate ,o.odate
,o.requestdate ,o.oseas
,greatest(least(o.shipdate,gld.edat),gld.sdat) ,o.rdate
,o.adj_orderdate ,o.rseas
,o.adj_requestdate ,greatest(least(o.sdate,gld.edat),gld.sdat)
,greatest(least(o.adj_shipdate,gld.edat),gld.sdat) ,ss.ssyr
) )
,incr AS ( ,incr AS (
SELECT SELECT
o.plnt o."ddord#"
,o."ddord#" ,o."dditm#"
,o."dditm#" ,o."fgbol#"
,o."fgbol#" ,o."fgent#"
,o."fgent#" ,o."diinv#"
,o."diinv#" ,o."dilin#"
,o."dilin#" ,o.quoten
,o.promo ,o.quotel
,o.return_reas ,o.dcodat + interval '1 year' --incremented
,o.terms ,o.ddqdat + interval '1 year' --incremented
,o.custpo ,o.dcmdat
,o.dhincr ,o.fesdat
,o.diext ,o.dhidat + interval '1 year' --incremented
,o.ditdis ,o.fesind
,o.dcodat ,o.dhpost
,o.ddqdat ,gld.fspr --incremented
,o.dcmdat ,o.ddqtoi
,o.dhidat ,o.ddqtsi
,gld.fspr ,o.fgqshp
,o.remit_to ,o.diqtsh
,o.bill_class ,o.diext
,o.bill_cust ,o.ditdis
,o.bill_rep ,o.discj
,o.bill_terr ,o.dhincr
,o.ship_class ,o.plnt
,o.ship_cust ,o.promo
,o.ship_rep ,o.return_reas
,o.ship_terr ,o.terms
,o.quota_rep ,o.custpo
,o.account ,o.remit_to
,o.shipgrp ,o.bill_class
,o.geo ,o.bill_cust
,o.chan ,o.bill_rep
,o.orig_ctry ,o.bill_terr
,o.orig_prov ,o.ship_class
,o.orig_post ,o.ship_cust
,o.dest_ctry ,o.ship_rep
,o.dest_prov ,o.ship_terr
,o.dest_post ,o.dsm
,o.part ,o.account
,o.ord_gldc ,o.shipgrp
,o.majg ,o.geo
,o.ming ,o.chan
,o.majs ,o.chansub
,o.mins ,o.orig_ctry
,o.gldc ,o.orig_prov
,o.glec ,o.orig_post
,o.harm ,o.bill_ctry
,o.clss ,o.bill_prov
,o.brand ,o.bill_post
,o.assc ,o.dest_ctry
,o.fs_line ,o.dest_prov
,o.r_currency ,o.dest_post
,o.r_rate ,o.part
,o.c_currency ,o.styc
,o.c_rate ,o.colc
,o.ddqtoi ,o.colgrp
,o.ddqtsi ,o.coltier
,o.fgqshp ,o.colstat
,o.diqtsh ,o.sizc
,sum(o.fb_qty) fb_qty ,o.pckg
,sum(o.fb_cst_loc) fb_cst_loc ,o.kit
,sum(o.fb_cst_loc_cur) fb_cst_loc_cur ,o.brnd
,sum(o.fb_cst_loc_fut) fb_cst_loc_fut ,o.majg
,sum(o.fb_val_loc) fb_val_loc ,o.ming
,sum(o.fb_val_loc_pl) fb_val_loc_pl ,o.majs
,o.calc_status ,o.mins
,o.flag ,o.gldco
----these dates should already be snapped since the derive from the adjusted set ,o.gldc
,o.orderdate + interval '1 year' orderdate ,o.glec
,o.requestdate + interval '1 year' requestdate ,o.harm
,o.shipdate + interval '1 year' shipdate ,o.clss
,o.adj_orderdate + interval '1 year' adj_orderdate ,o.brand
,o.adj_requestdate + interval '1 year' adj_requestdate ,o.assc
,o.adj_shipdate + interval '1 year' adj_shipdate ,o.ddunit
,'b20' "version" ,o.unti
,'copy' iter ,o.lbs
FROM ,o.plt
cop o ,o.plcd
LEFT OUTER JOIN gld ON ,o.fs_line
(o.adj_shipdate + interval '1 year') BETWEEN gld.sdat AND gld.edat ,o.r_currency
WHERE ,o.r_rate
adj_orderdate BETWEEN '2018-06-01' AND '2019-05-31' ,o.c_currency
GROUP BY ,o.c_rate
o.plnt ,o.fb_qty
,o."ddord#" ,o.fb_val_loc
,o."dditm#" ,o.fb_val_loc_dis
,o."fgbol#" ,o.fb_val_loc_qt
,o."fgent#" ,o.fb_val_loc_pl
,o."diinv#" ,o.fb_val_loc_tar
,o."dilin#" ,o.fb_cst_loc
,o.promo ,o.fb_cst_loc_cur
,o.return_reas ,o.fb_cst_loc_fut
,o.terms ,o.calc_status
,o.custpo ,o.flag
,o.dhincr ,o.odate + interval '1 year' --incremented
,o.diext ,o.oseas + 1 --incremented
,o.ditdis ,o.rdate + interval '1 year' --incremented
,o.dcodat ,o.rseas + 1 --incremented
,o.ddqdat ,o.sdate + interval '1 year' --incremented
,o.dcmdat ,o.sseas + 1 --incremented
,o.dhidat ,'b21' "version"
,gld.fspr ,'baseline' iter
,o.remit_to FROM
,o.bill_class baseline o
,o.bill_cust LEFT OUTER JOIN gld ON
,o.bill_rep o.sdate + interval '1 year' BETWEEN gld.sdat and gld.edat
,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 INSERT INTO rlarp.osmf_dev
SELECT * FROM incr SELECT * FROM incr
UNION ALL UNION ALL
SELECT * FROM cop; SELECT * FROM baseline;
---identify short ships: causes disconnect with actual sales------------------------------------------------------------------- ---identify short ships: causes disconnect with actual sales-------------------------------------------------------------------
UPDATE rlarp.osmfs SET iter = 'short ship' WHERE calc_status = 'CLOSED' AND flag = 'REMAINDER'; UPDATE rlarp.osmfs SET iter = 'short ship' WHERE calc_status = 'CLOSED' AND flag = 'REMAINDER';

View File

@ -1,115 +1,126 @@
| column | osmp_dev | source | osm_stack_retain | ui | |column |alt_name |osmp_dev|osm_fcpool|osmp_source|osm_stack_retain|ui |revised_pool|
| -------------- | -------- | -------- | ---------------- | --- | |---------------|--------------|--------|----------|-----------|----------------|---|------------|
| ddord# | x | null | x | | |ddord# | |x | |null |x | | |
| dditm# | x | null | | | |dditm# | |x | |null | | | |
| fgbol# | x | null | | | |fgbol# | |x | |null | | | |
| fgent# | x | null | | | |fgent# | |x | |null | | | |
| diinv# | x | null | x | | |diinv# | |x | |null |x | | |
| dilin# | x | null | | | |dilin# | |x | |null | | | |
| quoten | x | null | x | | |quoten | |x | |null |x | | |
| quotel | x | null | | | |quotel | |x | |null | | | |
| dcodat | x | null | | | |dcodat | |x | |null | | | |
| ddqdat | x | null | | | |ddqdat | |x | |null | | | |
| dcmdat | x | null | | | |dcmdat | |x | |null | | | |
| fesdat | x | null | | | |fesdat | |x | |null | | | |
| dhidat | x | null | | | |dhidat | |x | |null | | | |
| fesind | x | null | | | |fesind | |x | |null | | | |
| dhpost | x | null | | | |dhpost | |x | |null | | | |
| fspr | x | forecast | | | |fspr | |x | |forecast | | |x |
| ddqtoi | x | forecast | | | |ddqtoi | |x | |forecast | | |x |
| ddqtsi | x | null | | | |ddqtsi | |x | |null | | | |
| fgqshp | x | null | | | |fgqshp | |x | |null | | | |
| diqtsh | x | null | | | |diqtsh | |x | |null | | | |
| diext | x | null | | | |diext | |x | |null | | | |
| ditdis | x | null | | | |ditdis | |x | |null | | | |
| discj | x | null | | | |discj | |x | |null | | | |
| dhincr | x | forecast | | | |dhincr | |x | |forecast | | |x |
| plnt | x | forecast | x | | |plnt | |x | |forecast |x | |x |
| promo | x | forecast | x | x | |promo | |x | |forecast |x |x |x |
| return_reas | x | null | | | |return_reas | |x | |null | | | |
| terms | x | forecast | | | |terms | |x | |forecast | | |x |
| custpo | x | null | | | |custpo | |x | |null | | | |
| remit_to | x | forecast | | | |remit_to | |x | |forecast | | |x |
| bill_class | x | cust | x | | |bill_class | |x | |cust |x | | |
| bill_cust | x | forecast | | x | |bill_cust | |x | |forecast | | |x |
| bill_rep | x | cust | | | |bill_cust_descr| | | |ui_only | |x |x |
| bill_terr | x | cust | | | |bill_rep | |x | |cust | | | |
| ship_class | x | cust | x | | |bill_terr | |x | |cust | | | |
| ship_cust | x | forecast | x | x | |ship_class | |x | |cust |x | | |
| ship_rep | x | cust | | | |ship_cust | |x | |forecast |x | |x |
| ship_terr | x | cust | | | |ship_cust_descr| | | |ui_only | |x |x |
| dsm | x | forecast | x | x | |ship_rep | |x | |cust | | | |
| account | x | cust | x | x | |ship_terr | |x | |cust | | | |
| shipgrp | x | cust | x | x | |dsm |quota_rep |x | |forecast |x |x |x |
| geo | x | cust | x | | |quota_rep_descr| | | |ui_only | |x |x |
| chan | x | cust | x | x | |account |billto_group |x | |cust |x |x |x |
| chansub | x | cust | x | x | |shipgrp |shipto_group |x | |cust |x |x |x |
| chanretail | | ui_only | | x | |geo | |x | |cust |x | | |
| orig_ctry | x | plnt | | | |chan | |x | |cust |x |x |x |
| orig_prov | x | plnt | | | |chansub |mod_chan |x | |cust |x |x |x |
| orig_post | x | plnt | | | |chanretail |mod_chansub | | |ui_only | |x |x |
| bill_ctry | x | cust | x | | |orig_ctry | |x | |plnt | | | |
| bill_prov | x | cust | x | | |orig_prov | |x | |plnt | | | |
| bill_post | x | cust | x | | |orig_post | |x | |plnt | | | |
| dest_ctry | x | cust | x | | |bill_ctry | |x | |cust |x | | |
| dest_prov | x | cust | x | | |bill_prov | |x | |cust |x | | |
| dest_post | x | cust | x | | |bill_post | |x | |cust |x | | |
| part | x | forecast | x | | |dest_ctry | |x | |cust |x | | |
| partd | | ui_only | | x | |dest_prov | |x | |cust |x | | |
| part_groupd | | ui_only | | x | |dest_post | |x | |cust |x | | |
| styc | x | itemm | x | | |part | |x | |forecast |x | |x |
| colc | x | itemm | x | | |part_descr | | | |ui_only | |x |x |
| colgrp | x | itemm | x | | |part_group | | | |ui_only | |x |x |
| coltier | x | itemm | x | | |styc | |x | |itemm |x | | |
| colstat | x | itemm | | | |colc |color |x | |itemm |x | | |
| sizc | x | itemm | x | | |colgrp | |x | |itemm |x | | |
| pckg | x | itemm | x | | |coltier | |x | |itemm |x | | |
| kit | x | itemm | x | | |colstat | |x | |itemm | | | |
| brnd | x | itemm | x | x | |sizc | |x | |itemm |x | | |
| majg | x | itemm | x | | |pckg | |x | |itemm |x | | |
| majgd | | ui_only | | x | |kit | |x | |itemm |x | | |
| ming | x | itemm | x | | |brnd |branding |x | |itemm |x |x |x |
| mingd | | ui_only | | x | |majg | |x | |itemm |x | | |
| majs | x | itemm | x | | |majgd |majg_descr | | |ui_only | |x |x |
| majsd | | ui_only | | x | |ming | |x | |itemm |x | | |
| mins | x | itemm | x | | |mingd |ming_descr | | |ui_only | |x |x |
| minsd | | ui_only | | x | |majs | |x | |itemm |x | | |
| gldco | x | itemm | | | |majsd |majs_descr | | |ui_only | |x |x |
| gldc | x | itemm | | | |mins | |x | |itemm |x | | |
| glec | x | itemm | x | | |minsd |mins_descr | | |ui_only | |x |x |
| segm | | ui_only | | x | |gldco |ord_gldc |x | |itemm | | | |
| harm | x | itemm | | | |gldc | |x | |itemm | | | |
| clss | x | itemm | x | | |glec | |x | |itemm |x | | |
| brand | x | itemm | | | |segm | | | |ui_only | |x |x |
| assc | x | itemm | | | |harm | |x | |itemm | | | |
| ddunit | x | itemm | | | |clss | |x | |itemm |x | | |
| unti | x | itemm | | | |brand | |x | |itemm | | | |
| lbs | x | itemm | x | | |assc | |x | |itemm | | | |
| plt | x | punit | x | | |ddunit | |x | |itemm | | | |
| plcd | x | iprcbhc | x | | |unti |units |x | |itemm | | | |
| fs_line | x | forecast | x | | |lbs | |x | |itemm |x | | |
| r_currency | x | forecast | x | | |plt | |x | |punit |x | | |
| r_rate | x | forecast | x | | |plcd | |x | |iprcbhc |x | | |
| c_currency | x | forecast | x | | |fs_line | |x | |forecast |x | |x |
| c_rate | x | forecast | x | | |r_currency | |x | |forecast |x | |x |
| fb_qty | x | forecast | x | x | |r_rate | |x | |forecast |x | |x |
| fb_val_loc | x | forecast | x | x | |c_currency | |x | |forecast |x | |x |
| value_usd | | ui_only | | x | |c_rate | |x | |forecast |x | |x |
| fb_val_loc_dis | x | null | | | |fb_qty | |x | |forecast |x |x |x |
| fb_val_loc_qt | x | null | x | | |fb_val_loc |value_loc |x | |forecast |x |x |x |
| fb_val_loc_pl | x | pricel | x | | |value_usd | | | |ui_only | |x |x |
| fb_val_loc_tar | x | target | x | | |fb_val_loc_dis | |x | |null | | | |
| fb_cst_loc | x | forecast | x | x | |fb_val_loc_qt | |x | |null |x | | |
| cost_loc | | ui_only | | x | |fb_val_loc_pl | |x | |pricel |x | | |
| fb_cst_loc_cur | x | icstx | x | | |fb_val_loc_tar | |x | |target |x | | |
| fb_cst_loc_fut | x | icstx | | | |fb_cst_loc |cost_loc |x | |forecast |x |x |x |
| calc_status | x | forecast | x | | |cost_usd | | | |ui_only | |x |x |
| flag | x | forecast | x | | |fb_cst_loc_cur | |x | |icstx |x | | |
| odate | x | forecast | x | x | |fb_cst_loc_fut | |x | |icstx | | | |
| oseas | x | forecast | x | x | |calc_status | |x | |forecast |x | |x |
| rdate | x | forecast | x | x | |flag | |x | |forecast |x | |x |
| rseas | x | forecast | x | x | |odate |orderdate |x | |forecast |x |x |x |
| sdate | x | forecast | x | x | |order_month | | | |ui_only | |x |x |
| sseas | x | forecast | x | x | |oseas |order_season |x | |forecast |x |x |x |
| version | x | forecast | | x | |rdate |requestdate |x | |forecast |x |x |x |
| iter | x | forecast | | 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 |