forecast_api/route_sql/scale_pd.sql
2019-04-03 03:00:38 -04:00

400 lines
13 KiB
SQL

WITH
target AS (select target_increment incr)
,basemix AS (
SELECT
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
,null::text promo --history date mix
,null::text return_reas --0
,terms
,''::text custpo --0
,'I' dhincr --0
,null::numeric diext
,null::numeric 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
,orderdate --history date mix
,requestdate --history date mix
,shipdate --history date mix
,adj_orderdate --history
,adj_requestdate --history
,adj_shipdate --history
,'b20' "version" --calculated
,'adjustment' iter --calculated
---------------ui columns-------------------------
,order_season
,order_month
,ship_season
,ship_month
,request_season
,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
FROM
rlarp.osm_fcpool
WHERE
-----------------scenario----------------------------
where_clause
-----------------additional params-------------------
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
AND adj_orderdate <= adj_shipdate
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 --0
,flag --0
,orderdate --history date mix
,requestdate --history date mix
,shipdate --history date mix
,adj_orderdate --history
,adj_requestdate --history
,adj_shipdate --history
---------------ui columns-------------------------
,order_season
,order_month
,ship_season
,ship_month
,request_season
,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
)
,scale AS (
SELECT
(SELECT incr::numeric FROM target) incr
,(SELECT sum(fb_val_loc * r_rate) FROM basemix) base
,CASE WHEN (SELECT sum(fb_val_loc * r_rate) FROM basemix) = 0 THEN
0
ELSE
((SELECT incr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM basemix))/(SELECT sum(fb_val_loc * r_rate) FROM basemix)
END factor
,CASE WHEN (SELECT sum(fb_val_loc * r_rate) FROM basemix) = 0 THEN
CASE WHEN ((SELECT incr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM basemix)) <> 0 THEN
--if the base value is -0- but the target value hasn't been achieved, derive a price to apply
((SELECT incr::numeric FROM target) - (SELECT sum(fb_val_loc * r_rate) FROM basemix))/(SELECT sum(fb_qty) FROM basemix)
ELSE
0
END
ELSE
0
END mod_price
)
,final AS (
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
,0 fb_qty
,0 fb_cst_loc
,0 fb_cst_loc_cur
,0 fb_cst_loc_fut
,b.fb_val_loc*s.factor fb_val_loc
,b.fb_val_loc_pl*s.factor fb_val_loc_pl
,b.calc_status --0
,b.flag --0
,b.orderdate
,b.requestdate
,b.shipdate
,b.adj_orderdate
,b.adj_requestdate
,b.adj_shipdate
,'replace_version' "version" --calculated
,'replace_source'||' price' iter --calculated
-----------------------ui columns--------------------------------
,'replace_iterdet' iterdet
,$$replace_iterdef$$::jsonb iterdef
,b.order_season
,b.order_month
,b.ship_season
,b.ship_month
,b.request_season
,b.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
,(CASE WHEN s.factor = 0 THEN b.fb_qty * s.mod_price/b.r_rate ELSE b.fb_val_loc*s.factor END)::numeric value_loc
,(CASE WHEN s.factor = 0 THEN b.fb_qty * s.mod_price ELSE b.fb_val_loc*s.factor END)::numeric value_usd
,0 cost_loc
,0 cost_usd
,0 units
FROM
basemix b
CROSS JOIN scale s
WHERE
s.factor <> 0 or s.mod_price <> 0
)
--select sum(value_usd), count(*) from final
, ins AS (
INSERT INTO rlarp.osm_fcpool SELECT * FROM final RETURNING *
)
,insagg AS (
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
)
SELECT json_agg(row_to_json(insagg)) x from insagg