forecast_api/route_meta/addmonth_vd.sql

507 lines
16 KiB
MySQL
Raw Normal View History

2019-03-04 09:06:09 -05:00
WITH
target AS (select 50000 incr)
2019-03-05 11:31:06 -05:00
,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'
)
,mseq AS (
2019-03-04 09:06:09 -05:00
SELECT * FROM
(
VALUES
('Jun',1,6,-1)
,('Jul',2,7,-1)
,('Aug',3,8,-1)
,('Sep',4,9,-1)
,('Oct',5,10,-1)
,('Nov',6,11,-1)
,('Dec',7,12,-1)
,('Jan',8,1,0)
,('Feb',9,2,0)
,('Mar',10,3,0)
,('Apr',11,4,0)
,('May',12,5,0)
) x(m,s,cal,yr)
2019-03-04 09:06:09 -05:00
)
,alldates AS (
SELECT
promo
,terms
,order_month
,mseq.s seq
,orderdate
,requestdate
,shipdate
,sum(value_usd) value_usd
FROM
rlarp.osm_fcpool
LEFT OUTER JOIN mseq ON
mseq.m = order_month
WHERE
-----------------scenario----------------------------
quota_rep_descr = '10032 - BRYAN HILL'
AND segm = 'Greenhouse'
AND mod_chan = 'DISTRIB DROP SHIP'
AND billto_group = 'BWI'
--AND order_month = 'May'
-----------------additional params-------------------
AND version = 'b20'
AND iter = 'copy'
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
GROUP BY
promo
,terms
,order_month
,mseq.s
,orderdate
,requestdate
,shipdate
HAVING
sum(value_usd) <> 0
)
--select * from alldates
,dom AS (
SELECT
extract(day FROM orderdate) DOM
,sum(value_usd) value_usd
FROM
alldates
GROUP BY
extract(day FROM orderdate)
)
---------------------may want ot look at a top-5 mix solution in the future facilitated by sum() over (order by sales desc)---------------
2019-03-04 09:06:09 -05:00
,mmix AS (
SELECT
to_char(orderdate,'Mon') _month
,seq
,promo
,sum(extract(day from orderdate)*value_usd) dom_wa
--,requestdate-orderdate rlag
,sum((requestdate-orderdate)*(value_usd)) rlag_wa
--,shipdate - requestdate slag
,sum((shipdate - requestdate)*(value_usd)) slag_wa
2019-03-04 09:06:09 -05:00
,sum(value_usd) value_usd
FROM
alldates
GROUP BY
to_char(orderdate,'Mon')
,seq
,promo
--,extract(day from orderdate)
--,requestdate-orderdate
--,shipdate - requestdate
2019-03-04 09:06:09 -05:00
)
,mmixp AS (
SELECT
_month
,seq
,promo
,round((dom_wa/value_usd)::numeric,0)::int odom
,round((rlag_wa/value_usd)::numeric,0)::int rlag
,round((slag_wa/value_usd)::numeric,0)::int slag
,value_usd/sum(value_usd) over (partition by _month) momix
--,value_usd/SUM(value_usd) over (PARTITION BY _month) vperc
2019-03-04 09:06:09 -05:00
FROM
mmix
)
--SELECT * FROM mmixp order by seq asc, vperc desc
2019-03-04 09:06:09 -05:00
,basemix AS (
SELECT
2019-03-04 09:06:09 -05:00
plnt ---master data
,0::numeric(11,0) "ddord#" --0
,0::numeric(11,0) "dditm#" --0
,0::numeric(11,0) "fgbol#" --0
,0::numeric(11,0) "fgent#" --0
,0::numeric(9,0) "diinv#" --0
,0::numeric(3,0) "dilin#" --0
2019-03-04 09:06:09 -05:00
,null::text promo --history date mix
,null::text return_reas --0
,terms
,''::text custpo --0
2019-03-04 09:06:09 -05:00
,'I' dhincr --0
,sum(diext) diext
,sum(ditdis) ditdis
,null::date dcodat --calculated date mix
,null::date ddqdat --calculated date mix
,null::date dcmdat --calculated date mix
,null::date dhidat --calculated date mix
,null::text fspr --calculated date mix
,remit_to --master data
,bill_class --master data
,bill_cust --history cust mix
,bill_rep --master data
,bill_terr --master data
,ship_class --master data
,ship_cust --history cust mix
,ship_rep --master data
,ship_terr --master data
,quota_rep --master data
,account --master data
,shipgrp --master data
,geo --master data
,chan --master data
,orig_ctry --master data
,orig_prov --master data
,orig_post --master data
,dest_ctry --master data
,dest_prov --master data
,dest_post --master data
,part --history part mix
,ord_gldc --master data
,majg --master data
,ming --master data
,majs --master data
,mins --master data
,gldc --master data
,glec --master data
,harm --master data
,clss --master data
,brand --master data
,assc --master data
,fs_line --master data
,r_currency --history cust mix
,r_rate --master data
,c_currency --master data
,c_rate --master data
,0::numeric(15,5) ddqtoi --0
,0::numeric(15,5) ddqtsi --0
,0::numeric(15,5) fgqshp --0
,0::numeric(15,5) diqtsh --0
,sum(coalesce(fb_qty,0)) fb_qty --history value
,sum(coalesce(fb_cst_loc,0)) fb_cst_loc --history part mix
,sum(coalesce(fb_cst_loc_cur,0)) fb_cst_loc_cur --master data
,sum(coalesce(fb_cst_loc_fut,0)) fb_cst_loc_fut --master data
,sum(coalesce(fb_val_loc,0)) fb_val_loc --history value
,sum(coalesce(fb_val_loc_pl,0)) fb_val_loc_pl --0
,calc_status --0
,flag --0
,null::date orderdate --history date mix
,null::date requestdate --history date mix
,null::date shipdate --history date mix
,null::date adj_orderdate --history
,null::date adj_requestdate --history
,null::date adj_shipdate --history
,'b20' "version" --calculated
,'adjustment' iter --calculated
---------------ui columns-------------------------
2019-03-05 11:31:06 -05:00
,null::numeric order_season
,null::text order_month
,null::numeric ship_season
,null::text ship_month
,null::numeric request_season
,null::text request_month
,part_descr
,part_family
,part_group
,branding
,color
,segm
,bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,majg_descr
,ming_descr
,majs_descr
,mins_descr
,mod_chan
,mod_chansub
,quota_rep_descr
,director_descr
,null value_loc
,null value_usd
,null cost_loc
,null cost_usd
,null units
2019-03-04 09:06:09 -05:00
FROM
rlarp.osm_fcpool
WHERE
-----------------scenario----------------------------
quota_rep_descr = '10032 - BRYAN HILL'
AND segm = 'Greenhouse'
AND mod_chan = 'DISTRIB DROP SHIP'
AND billto_group = 'BWI'
--AND order_month = 'May'
-----------------additional params-------------------
AND version = 'b20'
AND iter = 'copy'
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
GROUP BY
plnt ---master data
,terms
,remit_to --master data
,bill_class --master data
,bill_cust --history cust mix
,bill_rep --master data
,bill_terr --master data
,ship_class --master data
,ship_cust --history cust mix
,ship_rep --master data
,ship_terr --master data
,quota_rep --master data
,account --master data
,shipgrp --master data
,geo --master data
,chan --master data
,orig_ctry --master data
,orig_prov --master data
,orig_post --master data
,dest_ctry --master data
,dest_prov --master data
,dest_post --master data
,part --history part mix
,ord_gldc --master data
,majg --master data
,ming --master data
,majs --master data
,mins --master data
,gldc --master data
,glec --master data
,harm --master data
,clss --master data
,brand --master data
,assc --master data
,fs_line --master data
,r_currency --history cust mix
,r_rate --master data
,c_currency --master data
,c_rate --master data
,calc_status
,flag
,part_descr
,part_family
,part_group
,branding
,color
,segm
,bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,majg_descr
,ming_descr
,majs_descr
,mins_descr
,mod_chan
,mod_chansub
,quota_rep_descr
,director_descr
2019-03-04 09:06:09 -05:00
)
,scale AS (
SELECT
(SELECT incr::numeric FROM target) incr
,(SELECT sum(fb_val_loc *r_rate) FROM basemix) base
,(SELECT incr::numeric FROM target)/(SELECT sum(fb_val_loc *r_rate) FROM basemix) factor
)
,final AS (
2019-03-04 09:06:09 -05:00
SELECT
b.plnt --master data
,b."ddord#" --0
,b."dditm#" --0
,b."fgbol#" --0
,b."fgent#" --0
,b."diinv#" --0
,b."dilin#" --0
,b.promo --history date mix
,b.return_reas --0
,b.terms --history cust mix
,b.custpo --0
,b.dhincr --0
,b.diext --0
,b.ditdis --0
,b.dcodat --calculated date mix
,b.ddqdat --calculated date mix
,b.dcmdat --calculated date mix
,b.dhidat --calculated date mix
,b.fspr --calculated date mix
,b.remit_to --master data
,b.bill_class --master data
,b.bill_cust --history cust mix
,b.bill_rep --master data
,b.bill_terr --master data
,b.ship_class --master data
,b.ship_cust --history cust mix
,b.ship_rep --master data
,b.ship_terr --master data
,b.quota_rep --master data
,b.account --master data
,b.shipgrp --master data
,b.geo --master data
,b.chan --master data
,b.orig_ctry --master data
,b.orig_prov --master data
,b.orig_post --master data
,b.dest_ctry --master data
,b.dest_prov --master data
,b.dest_post --master data
,b.part --history part mix
,b.ord_gldc --master data
,b.majg --master data
,b.ming --master data
,b.majs --master data
,b.mins --master data
,b.gldc --master data
,b.glec --master data
,b.harm --master data
,b.clss --master data
,b.brand --master data
,b.assc --master data
,b.fs_line --master data
,b.r_currency --history cust mix
,b.r_rate --master data
,b.c_currency --master data
,b.c_rate --master data
,b.ddqtoi --0
,b.ddqtsi --0
,b.fgqshp --0
,b.diqtsh --0
,b.fb_qty*s.factor*m.momix fb_qty
,b.fb_cst_loc*s.factor*m.momix fb_cst_loc
,b.fb_cst_loc_cur*s.factor*m.momix fb_cst_loc_cur
,b.fb_cst_loc_fut*s.factor*m.momix fb_cst_loc_fut
,b.fb_val_loc*s.factor*m.momix fb_val_loc
,b.fb_val_loc_pl*s.factor*m.momix fb_val_loc_pl
2019-03-04 09:06:09 -05:00
,b.calc_status --0
,b.flag --0
,make_date(mseq.yr + 2020,mseq.cal,m.odom) orderdate
,make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag requestdate
,make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag + slag shipdate
,make_date(mseq.yr + 2020,mseq.cal,m.odom) adj_orderdate
,make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag adj_requestdate
,make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag + slag adj_shipdate
2019-03-04 09:06:09 -05:00
,b.version --calculated
,b.iter --calculated
-----------------------ui columns--------------------------------
2019-03-05 11:31:06 -05:00
,'adjust volume' iterdet
,null::jsonb iterdef
,od.ssyr order_season
,to_char(make_date(mseq.yr + 2020,mseq.cal,m.odom),'Mon') order_month
,sd.ssyr ship_season
,to_char(make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag + slag,'Mon') ship_month
,rd.ssyr request_season
,to_char(make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag,'Mon') request_month
,b.part_descr
,b.part_family
,b.part_group
,b.branding
,b.color
,b.segm
,b.bill_cust_descr
,b.billto_group
,b.ship_cust_descr
,b.shipto_group
,b.majg_descr
,b.ming_descr
,b.majs_descr
,b.mins_descr
,b.mod_chan
,b.mod_chansub
,b.quota_rep_descr
,b.director_descr
2019-03-06 05:54:30 -05:00
,(b.fb_val_loc*s.factor*m.momix)::numeric value_loc
,(b.fb_val_loc*s.factor*m.momix*r_rate)::numeric value_usd
,(b.fb_cst_loc*s.factor*m.momix)::numeric cost_loc
,(b.fb_cst_loc*s.factor*m.momix*c_rate)::numeric cost_usd
,(b.fb_qty*s.factor*m.momix)::numeric units
FROM
2019-03-04 09:06:09 -05:00
basemix b
CROSS JOIN scale s
CROSS JOIN mmixp m
LEFT OUTER JOIN mseq ON
mseq.m = m._month
2019-03-05 11:31:06 -05:00
LEFT OUTER JOIN gld od ON
make_date(mseq.yr + 2020,mseq.cal,m.odom) BETWEEN od.sdat AND od.edat
LEFT OUTER JOIN gld rd ON
make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag BETWEEN rd.sdat AND rd.edat
LEFT OUTER JOIN gld sd ON
make_date(mseq.yr + 2020,mseq.cal,m.odom) + rlag + slag BETWEEN sd.sdat AND sd.edat
WHERE
m._month = 'Jul'
2019-03-05 10:52:35 -05:00
)
2019-03-06 05:54:30 -05:00
, ins AS (
INSERT INTO rlarp.osm_fcpool SELECT * FROM final RETURNING *
)
SELECT
bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,quota_rep_descr
,director_descr
,segm
,mod_chan
,mod_chansub
,majg_descr
,ming_descr
,majs_descr
,mins_descr
,brand
,part_family
,part_group
,branding
,color
,part_descr
,order_season
,order_month
,ship_season
,ship_month
,request_season
,request_month
,promo
,version
,iter
,sum(value_loc) value_loc
,sum(value_usd) value_usd
,sum(cost_loc) cost_loc
,sum(cost_usd) cost_usd
,sum(units) units
FROM
ins
GROUP BY
bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,quota_rep_descr
,director_descr
,segm
,mod_chan
,mod_chansub
,majg_descr
,ming_descr
,majs_descr
,mins_descr
,brand
,part_family
,part_group
,branding
,color
,part_descr
,order_season
,order_month
,ship_season
,ship_month
,request_season
,request_month
,promo
,version
,iter