forecast_api/route_sql/addmonth_vupd.sql

524 lines
15 KiB
MySQL
Raw Permalink Normal View History

WITH
2019-03-12 17:45:35 -04:00
/*
the volume must be expressed in terms of units, since that is what it will be scaling
*/
target AS (select target_volume vincr, target_price pincr)
,testv AS (
SELECT
2020-02-15 01:03:45 -05:00
sum(units) tot
,sum(units) FILTER (WHERE iter IN ('copy','plan','diff')) base
2020-02-15 01:03:45 -05:00
,COALESCE(sum(units) FILTER (WHERE module = 'new basket'),0) newpart
,sum(value_loc *r_rate) totsales
,sum(value_loc *r_rate) FILTER (WHERE iter IN ('plan','diff','copy')) basesales
2020-02-15 01:03:45 -05:00
,COALESCE(sum(value_loc *r_rate) FILTER (WHERE module = 'new basket'),0) newpartsales
FROM
2020-02-15 01:03:45 -05:00
rlarp.osm_pool
WHERE
-----------------scenario----------------------------
where_clause
-----------------additional params-------------------
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
2020-02-15 01:03:45 -05:00
AND order_date <= ship_date
)
,flagv AS (
SELECT
tot
,base
,newpart
,CASE WHEN tot = 0 THEN
CASE WHEN base = 0 THEN
CASE WHEN newpart = 0 THEN
'unclean data. tested -> does not exist'
ELSE
'scale new part'
END
ELSE
'scale copy'
END
ELSE
'scale all'
END flag
,CASE WHEN totsales = 0 THEN
CASE WHEN basesales = 0 THEN
CASE WHEN newpartsales = 0 THEN
'no price'
ELSE
'scale new part'
END
ELSE
'scale copy'
END
ELSE
'scale all'
END flagsales
FROM
testv
)
2020-02-15 01:03:45 -05:00
,GLD AS MATERIALIZED (
SELECT
2019-03-12 17:45:35 -04:00
N1COMP COMP
,N1CCYY FSYR
,KPMAXP PERDS
,N1FSPP PERD
,to_char(N1FSYP,'FM0000') FSPR
,N1SD01 SDAT
,N1ED01 EDAT
,daterange(n1sd01, n1ed01,'[]') drange
2019-03-12 17:45:35 -04:00
,to_char(N1ED01,'yymm') CAPR
,N1ED01 - N1SD01 +1 NDAYS
2019-03-12 17:45:35 -04:00
,CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(YEAR FROM N1ED01) + 1 ELSE EXTRACT(YEAR FROM N1ED01) END SSYR
2020-02-16 22:23:38 -05:00
,to_char(CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(MONTH FROM N1ED01) -5 ELSE EXTRACT(MONTH FROM N1ED01) +7 END,'FM00') SSPR
FROM
LGDAT.GLDATREF
INNER JOIN LGDAT.GLDATE ON
KPCOMP = N1COMP AND
2019-03-12 17:45:35 -04:00
KPCCYY = N1CCYY
WHERE
N1COMP = 93
)
,mseq AS (
SELECT * FROM
2019-03-12 17:45:35 -04:00
(
VALUES
2020-02-15 01:03:45 -05:00
('01 - Jun',1,6,-1)
,('02 - Jul',2,7,-1)
,('03 - Aug',3,8,-1)
,('04 - Sep',4,9,-1)
,('05 - Oct',5,10,-1)
,('06 - Nov',6,11,-1)
,('07 - Dec',7,12,-1)
,('08 - Jan',8,1,0)
,('09 - Feb',9,2,0)
,('10 - Mar',10,3,0)
,('11 - Apr',11,4,0)
,('12 - May',12,5,0)
2019-03-12 17:45:35 -04:00
) x(m,s,cal,yr)
)
2020-02-15 01:03:45 -05:00
,alldates AS MATERIALIZED(
SELECT
2019-03-12 17:45:35 -04:00
promo
,terms
,order_month
,mseq.s seq
2020-02-15 01:03:45 -05:00
,order_date
,request_date
,ship_date
,sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) value_usd
2019-03-12 17:45:35 -04:00
FROM
2020-02-15 01:03:45 -05:00
rlarp.osm_pool
2019-03-12 17:45:35 -04:00
LEFT OUTER JOIN mseq ON
mseq.m = order_month
WHERE
-----------------scenario----------------------------
where_clause
-----------------additional params-------------------
AND CASE (SELECT flag FROM flagv)
WHEN 'scale all' THEN true
WHEN 'scale copy' THEN iter IN ('plan','diff','copy')
2020-02-15 01:03:45 -05:00
WHEN 'scale new part' THEN module = 'new basket'
END
2019-03-12 17:45:35 -04:00
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
2020-02-15 01:03:45 -05:00
AND order_date <= ship_date
2019-03-12 17:45:35 -04:00
GROUP BY
promo
,terms
,order_month
,mseq.s
2020-02-15 01:03:45 -05:00
,order_date
,request_date
,ship_date
2019-03-12 17:45:35 -04:00
HAVING
sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) <> 0
2019-03-12 17:45:35 -04:00
)
--select * from alldates
,dom AS (
SELECT
2020-02-15 01:03:45 -05:00
extract(day FROM order_date) DOM
2019-03-12 17:45:35 -04:00
,sum(value_usd) value_usd
FROM
alldates
GROUP BY
2020-02-15 01:03:45 -05:00
extract(day FROM order_date)
2019-03-12 17:45:35 -04:00
)
---------------------may want ot look at a top-5 mix solution in the future facilitated by sum() over (order by sales desc)---------------
,mmix AS (
SELECT
2020-02-15 01:03:45 -05:00
to_char(order_date,'Mon') _month
2019-03-12 17:45:35 -04:00
,seq
,promo
2020-02-15 01:03:45 -05:00
,sum(extract(day from order_date)*value_usd) dom_wa
--,request_date-order_date rlag
,sum((request_date-order_date)*(value_usd)) rlag_wa
--,ship_date - request_date slag
,sum((ship_date - request_date)*(value_usd)) slag_wa
2019-03-12 17:45:35 -04:00
,sum(value_usd) value_usd
FROM
alldates
GROUP BY
2020-02-15 01:03:45 -05:00
to_char(order_date,'Mon')
2019-03-12 17:45:35 -04:00
,seq
,promo
2020-02-15 01:03:45 -05:00
--,extract(day from order_date)
--,request_date-order_date
--,ship_date - request_date
2019-03-12 17:45:35 -04:00
)
,targm AS (select s, m from mseq where m = 'target_month' )
,mmixp AS (
SELECT
_month
,seq
,promo
2019-04-16 09:26:39 -04:00
,greatest(least(round((dom_wa/value_usd)::numeric,0)::int,28),1) odom
2019-03-12 17:45:35 -04:00
,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
FROM
mmix
)
,closest AS (
SELECT
2019-03-12 17:45:35 -04:00
_month, targm.s, m
FROM
mmixp
2019-03-12 17:45:35 -04:00
CROSS JOIN targm
ORDER BY
abs(seq - targm.s) ASC
2019-03-12 17:45:35 -04:00
LIMIT 1
)
2020-02-15 01:03:45 -05:00
---------------------the role of basemix here is to get non-dated info which is then dated in the next step---------------------
2019-03-12 17:45:35 -04:00
,basemix AS (
SELECT
2020-02-15 01:03:45 -05:00
--fspr in next step
o.plnt
--promo in next step
--terms in next step
2020-02-15 02:55:33 -05:00
,c.bvterm terms
2020-02-15 01:03:45 -05:00
,o.bill_cust_descr
,o.ship_cust_descr
,o.dsm
,o.quota_rep_descr
,o.director
,o.billto_group
,o.shipto_group
,o.chan
,o.chansub
,o.chan_retail
,o.part
,o.part_descr
,o.part_group
,o.branding
,o.majg_descr
,o.ming_descr
,o.majs_descr
,o.mins_descr
,o.segm
,o.substance
2020-02-15 01:03:45 -05:00
,o.fs_line
,o.r_currency
,o.r_rate
,o.c_currency
,o.c_rate
,sum(coalesce(o.units,0)) units
,sum(coalesce(o.value_loc,0)) value_loc
,sum(coalesce(o.value_usd,0)) value_usd
2020-02-15 02:55:33 -05:00
,sum(coalesce(o.cost_loc,0)) cost_loc
,sum(coalesce(o.cost_usd,0)) cost_usd
2020-02-15 01:03:45 -05:00
,o.calc_status
,o.flag
2019-03-12 17:45:35 -04:00
FROM
2020-02-15 01:03:45 -05:00
rlarp.osm_pool o
2020-02-15 02:55:33 -05:00
LEFT OUTER JOIN lgdat.cust c ON
c.bvcust = rtrim(substr(o.bill_cust_descr,1,8))
2019-03-12 17:45:35 -04:00
WHERE
-----------------scenario----------------------------
where_clause
-----------------additional params-------------------
AND CASE (SELECT flag FROM flagv)
WHEN 'scale all' THEN true
WHEN 'scale copy' THEN iter IN ('plan','diff','copy')
2020-02-15 01:03:45 -05:00
WHEN 'scale new part' THEN module = 'new basket'
END
2019-03-12 17:45:35 -04:00
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
2020-02-15 01:03:45 -05:00
AND order_date <= ship_date
2019-03-12 17:45:35 -04:00
GROUP BY
2020-02-15 01:03:45 -05:00
--fspr in next step
o.plnt
2020-02-15 02:55:33 -05:00
,c.bvterm
2020-02-15 01:03:45 -05:00
--promo in next step
--terms in next step
,o.bill_cust_descr
,o.ship_cust_descr
,o.dsm
,o.quota_rep_descr
,o.director
,o.billto_group
,o.shipto_group
,o.chan
,o.chansub
,o.chan_retail
,o.part
,o.part_descr
,o.part_group
,o.branding
,o.majg_descr
,o.ming_descr
,o.majs_descr
,o.mins_descr
,o.segm
,o.substance
2020-02-15 01:03:45 -05:00
,o.fs_line
,o.r_currency
,o.r_rate
,o.c_currency
,o.c_rate
,o.calc_status
,o.flag
2019-03-12 17:45:35 -04:00
)
,vscale AS (
SELECT
(SELECT vincr::numeric FROM target) incr
2020-02-15 01:03:45 -05:00
,(SELECT sum(units) FROM basemix) base
,(SELECT vincr::numeric FROM target)/(SELECT sum(units) FROM basemix) factor
2019-03-12 17:45:35 -04:00
)
--select * from SCALE
2020-02-15 01:03:45 -05:00
,log AS (
INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING *
)
2019-03-12 17:45:35 -04:00
,volume AS (
SELECT
2020-02-15 01:03:45 -05:00
sd.fspr
,b.plnt
,m.promo
,b.terms
2019-03-12 17:45:35 -04:00
,b.bill_cust_descr
,b.ship_cust_descr
2020-02-15 01:03:45 -05:00
,b.dsm
,b.quota_rep_descr
,b.director
,b.billto_group
2019-03-12 17:45:35 -04:00
,b.shipto_group
2020-02-15 01:03:45 -05:00
,b.chan
,b.chansub
,b.chan_retail
,b.part
,b.part_descr
,b.part_group
,b.branding
2019-03-12 17:45:35 -04:00
,b.majg_descr
,b.ming_descr
,b.majs_descr
,b.mins_descr
2020-02-15 01:03:45 -05:00
,b.segm
,b.substance
2020-02-15 01:03:45 -05:00
,b.fs_line
,b.r_currency
,b.r_rate
,b.c_currency
,b.c_rate
,round(b.units*s.factor*m.momix ,2) units
,round(b.value_loc*s.factor*m.momix,2) value_loc
,round(b.value_usd*s.factor*m.momix,2) value_usd
,round(b.cost_loc*s.factor*m.momix ,2) cost_loc
,round(b.cost_usd*s.factor*m.momix ,2) cost_usd
2020-02-15 01:03:45 -05:00
,b.calc_status
,b.flag
,make_date(mseq.yr + 2024,mseq.cal,m.odom) order_date
,od.sspr || ' - ' || to_char(make_date(mseq.yr + 2024,mseq.cal,m.odom),'Mon') order_month
2020-02-15 01:03:45 -05:00
,od.ssyr order_season
,make_date(mseq.yr + 2024,mseq.cal,m.odom) + rlag request_date
,rd.sspr || ' - ' ||to_char(make_date(mseq.yr + 2024,mseq.cal,m.odom) + rlag,'Mon') request_month
2020-02-15 01:03:45 -05:00
,rd.ssyr request_season
,make_date(mseq.yr + 2024,mseq.cal,m.odom) + rlag + slag ship_date
,sd.sspr || ' - ' || to_char(make_date(mseq.yr + 2024,mseq.cal,m.odom) + rlag + slag,'Mon') ship_month
,sd.ssyr ship_season
2020-02-15 01:03:45 -05:00
,'replace_version' "version"
,'replace_source'||' volume' iter
,log.id
2020-02-18 14:47:46 -05:00
,COALESCE(log.doc->>'tag','') "tag"
2020-02-18 15:35:56 -05:00
,log.doc->>'message' "comment"
,log.doc->>'type' module
2019-03-12 17:45:35 -04:00
FROM
basemix b
CROSS JOIN vscale s
CROSS JOIN mmixp m
CROSS JOIN closest
2020-02-15 02:55:33 -05:00
CROSS JOIN log
2019-03-12 17:45:35 -04:00
LEFT OUTER JOIN mseq ON
mseq.m = closest.m
LEFT OUTER JOIN gld od ON
make_date(mseq.yr + 2024,mseq.cal,m.odom) BETWEEN od.sdat AND od.edat
2019-03-12 17:45:35 -04:00
LEFT OUTER JOIN gld rd ON
make_date(mseq.yr + 2024,mseq.cal,m.odom) + rlag BETWEEN rd.sdat AND rd.edat
2019-03-12 17:45:35 -04:00
LEFT OUTER JOIN gld sd ON
make_date(mseq.yr + 2024,mseq.cal,m.odom) + rlag + slag BETWEEN sd.sdat AND sd.edat
2019-03-12 17:45:35 -04:00
WHERE
m._month = (SELECT _month FROM closest)
)
,pscale AS (
SELECT
(SELECT pincr::numeric FROM target) incr
2020-02-15 01:03:45 -05:00
,(SELECT sum(value_loc * r_rate) FROM volume) base
,CASE WHEN (SELECT sum(value_loc * r_rate) FROM volume) = 0 THEN
0
ELSE
((SELECT pincr::numeric FROM target) - (SELECT sum(value_loc * r_rate) FROM volume))/(SELECT sum(value_loc * r_rate) FROM volume)
END factor
2020-02-15 01:03:45 -05:00
,CASE WHEN (SELECT sum(value_loc * r_rate) FROM volume) = 0 THEN
CASE WHEN ((SELECT pincr::numeric FROM target) - (SELECT sum(value_loc * r_rate) FROM volume)) <> 0 THEN
--if the base value is -0- but the target value hasn't been achieved, derive a price to apply
2020-02-15 01:03:45 -05:00
((SELECT pincr::numeric FROM target) - (SELECT sum(value_loc * r_rate) FROM volume))/(SELECT sum(units) FROM volume)
ELSE
0
END
ELSE
0
END mod_price
2019-03-12 17:45:35 -04:00
)
,price AS (
SELECT
2020-02-15 02:55:33 -05:00
b.fspr
2020-02-15 01:03:45 -05:00
,b.plnt
2020-02-15 02:55:33 -05:00
,b.promo
2020-02-15 01:03:45 -05:00
,b.terms
2019-03-12 17:45:35 -04:00
,b.bill_cust_descr
,b.ship_cust_descr
2020-02-15 01:03:45 -05:00
,b.dsm
,b.quota_rep_descr
,b.director
,b.billto_group
2019-03-12 17:45:35 -04:00
,b.shipto_group
2020-02-15 01:03:45 -05:00
,b.chan
,b.chansub
,b.chan_retail
,b.part
,b.part_descr
,b.part_group
,b.branding
2019-03-12 17:45:35 -04:00
,b.majg_descr
,b.ming_descr
,b.majs_descr
,b.mins_descr
2020-02-15 01:03:45 -05:00
,b.segm
,b.substance
2020-02-15 01:03:45 -05:00
,b.fs_line
,b.r_currency
,b.r_rate
,b.c_currency
,b.c_rate
,0::numeric units
,round((CASE WHEN p.factor = 0 THEN b.units * p.mod_price/b.r_rate ELSE b.value_loc*p.factor END)::numeric,2) value_loc
,round((CASE WHEN p.factor = 0 THEN b.units * p.mod_price ELSE b.value_usd*p.factor END)::numeric ,2) value_usd
2020-02-15 01:03:45 -05:00
,0::numeric cost_loc
,0::numeric cost_usd
,b.calc_status
,b.flag
,b.order_date
,b.order_month
,b.order_season
,b.request_date
,b.request_month
,b.request_season
,b.ship_date
,b.ship_month
,b.ship_season
2020-02-15 01:03:45 -05:00
,'replace_version' "version"
2020-02-18 17:10:49 -05:00
,'replace_source'||' price' iter
2020-02-15 01:03:45 -05:00
,log.id
2020-02-18 14:47:46 -05:00
,COALESCE(log.doc->>'tag','') "tag"
2020-02-18 15:35:56 -05:00
,log.doc->>'message' "comment"
,log.doc->>'type' module
2019-03-12 17:45:35 -04:00
FROM
volume b
CROSS JOIN pscale p
2020-02-15 02:55:33 -05:00
CROSS JOIN log
WHERE
p.factor <> 0 or p.mod_price <> 0
2019-03-12 17:45:35 -04:00
)
, ins AS (
2020-02-15 01:03:45 -05:00
INSERT INTO rlarp.osm_pool (SELECT * FROM price UNION ALL SELECT * FROM volume) RETURNING *
2019-03-12 17:45:35 -04:00
)
,insagg AS (
2020-02-15 01:03:45 -05:00
SELECT
---------customer info-----------------
bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,quota_rep_descr
,director
,segm
,substance
2020-02-15 01:03:45 -05:00
,chan
,chansub
---------product info------------------
,majg_descr
,ming_descr
,majs_descr
,mins_descr
--,brand
--,part_family
,part_group
,branding
--,color
,part_descr
---------dates-------------------------
,order_season
,order_month
,ship_season
,ship_month
,request_season
,request_month
,promo
,version
,iter
,logid
2020-02-18 14:47:46 -05:00
,tag
2020-02-18 15:35:56 -05:00
,comment
2020-02-15 01:03:45 -05:00
--------values-------------------------
,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
---------customer info-----------------
bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,quota_rep_descr
,director
,segm
,substance
2020-02-15 01:03:45 -05:00
,chan
,chansub
---------product info------------------
,majg_descr
,ming_descr
,majs_descr
,mins_descr
--,brand
--,part_family
,part_group
,branding
--,color
,part_descr
---------dates-------------------------
,order_season
,order_month
,ship_season
,ship_month
,request_season
,request_month
,promo
,version
,iter
,logid
2020-02-18 14:47:46 -05:00
,tag
2020-02-18 15:35:56 -05:00
,comment
2019-03-12 17:45:35 -04:00
)
2021-04-05 15:22:20 -04:00
SELECT json_agg(row_to_json(insagg)) x from insagg