523 lines
15 KiB
SQL
523 lines
15 KiB
SQL
WITH
|
|
/*
|
|
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
|
|
sum(units) tot
|
|
,sum(units) FILTER (WHERE iter = 'copy') base
|
|
,COALESCE(sum(units) FILTER (WHERE module = 'new basket'),0) newpart
|
|
,sum(value_loc *r_rate) totsales
|
|
,sum(value_loc *r_rate) FILTER (WHERE iter = 'copy') basesales
|
|
,COALESCE(sum(value_loc *r_rate) FILTER (WHERE module = 'new basket'),0) newpartsales
|
|
FROM
|
|
rlarp.osm_pool
|
|
WHERE
|
|
-----------------scenario----------------------------
|
|
where_clause
|
|
-----------------additional params-------------------
|
|
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
|
|
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
|
|
)
|
|
,GLD AS MATERIALIZED (
|
|
SELECT
|
|
N1COMP COMP
|
|
,N1CCYY FSYR
|
|
,KPMAXP PERDS
|
|
,N1FSPP PERD
|
|
,to_char(N1FSYP,'FM0000') FSPR
|
|
,N1SD01 SDAT
|
|
,N1ED01 EDAT
|
|
,daterange(n1sd01, n1ed01) drange
|
|
,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,'FM00') SSPR
|
|
FROM
|
|
LGDAT.GLDATREF
|
|
INNER JOIN LGDAT.GLDATE ON
|
|
KPCOMP = N1COMP AND
|
|
KPCCYY = N1CCYY
|
|
WHERE
|
|
N1COMP = 93
|
|
)
|
|
,mseq AS (
|
|
SELECT * FROM
|
|
(
|
|
VALUES
|
|
('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)
|
|
) x(m,s,cal,yr)
|
|
)
|
|
,alldates AS MATERIALIZED(
|
|
SELECT
|
|
promo
|
|
,terms
|
|
,order_month
|
|
,mseq.s seq
|
|
,order_date
|
|
,request_date
|
|
,ship_date
|
|
,sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) value_usd
|
|
FROM
|
|
rlarp.osm_pool
|
|
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 = 'copy'
|
|
WHEN 'scale new part' THEN module = 'new basket'
|
|
END
|
|
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
|
|
AND order_date <= ship_date
|
|
GROUP BY
|
|
promo
|
|
,terms
|
|
,order_month
|
|
,mseq.s
|
|
,order_date
|
|
,request_date
|
|
,ship_date
|
|
HAVING
|
|
sum(CASE (SELECT flagsales FROM flagv) WHEN 'no price'THEN 1.0 ELSE value_usd END) <> 0
|
|
)
|
|
--select * from alldates
|
|
,dom AS (
|
|
SELECT
|
|
extract(day FROM order_date) DOM
|
|
,sum(value_usd) value_usd
|
|
FROM
|
|
alldates
|
|
GROUP BY
|
|
extract(day FROM order_date)
|
|
)
|
|
---------------------may want ot look at a top-5 mix solution in the future facilitated by sum() over (order by sales desc)---------------
|
|
,mmix AS (
|
|
SELECT
|
|
to_char(order_date,'Mon') _month
|
|
,seq
|
|
,promo
|
|
,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
|
|
,sum(value_usd) value_usd
|
|
FROM
|
|
alldates
|
|
GROUP BY
|
|
to_char(order_date,'Mon')
|
|
,seq
|
|
,promo
|
|
--,extract(day from order_date)
|
|
--,request_date-order_date
|
|
--,ship_date - request_date
|
|
)
|
|
,targm AS (select s, m from mseq where m = 'target_month' )
|
|
,mmixp AS (
|
|
SELECT
|
|
_month
|
|
,seq
|
|
,promo
|
|
,greatest(least(round((dom_wa/value_usd)::numeric,0)::int,28),1) 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
|
|
FROM
|
|
mmix
|
|
)
|
|
,closest AS (
|
|
SELECT
|
|
_month, targm.s, m
|
|
FROM
|
|
mmixp
|
|
CROSS JOIN targm
|
|
ORDER BY
|
|
abs(seq - targm.s) ASC
|
|
LIMIT 1
|
|
)
|
|
---------------------the role of basemix here is to get non-dated info which is then dated in the next step---------------------
|
|
,basemix AS (
|
|
SELECT
|
|
--fspr in next step
|
|
o.plnt
|
|
--promo in next step
|
|
--terms in next step
|
|
,c.bvterm terms
|
|
,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
|
|
,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
|
|
,sum(coalesce(o.cost_loc,0)) cost_loc
|
|
,sum(coalesce(o.cost_usd,0)) cost_usd
|
|
,o.calc_status
|
|
,o.flag
|
|
FROM
|
|
rlarp.osm_pool o
|
|
LEFT OUTER JOIN lgdat.cust c ON
|
|
c.bvcust = rtrim(substr(o.bill_cust_descr,1,8))
|
|
WHERE
|
|
-----------------scenario----------------------------
|
|
where_clause
|
|
-----------------additional params-------------------
|
|
AND CASE (SELECT flag FROM flagv)
|
|
WHEN 'scale all' THEN true
|
|
WHEN 'scale copy' THEN iter = 'copy'
|
|
WHEN 'scale new part' THEN module = 'new basket'
|
|
END
|
|
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
|
|
AND order_date <= ship_date
|
|
GROUP BY
|
|
--fspr in next step
|
|
o.plnt
|
|
,c.bvterm
|
|
--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
|
|
,o.fs_line
|
|
,o.r_currency
|
|
,o.r_rate
|
|
,o.c_currency
|
|
,o.c_rate
|
|
,o.calc_status
|
|
,o.flag
|
|
)
|
|
,vscale AS (
|
|
SELECT
|
|
(SELECT vincr::numeric FROM target) incr
|
|
,(SELECT sum(units) FROM basemix) base
|
|
,(SELECT vincr::numeric FROM target)/(SELECT sum(units) FROM basemix) factor
|
|
)
|
|
--select * from SCALE
|
|
,log AS (
|
|
INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING *
|
|
)
|
|
,volume AS (
|
|
SELECT
|
|
sd.fspr
|
|
,b.plnt
|
|
,m.promo
|
|
,b.terms
|
|
,b.bill_cust_descr
|
|
,b.ship_cust_descr
|
|
,b.dsm
|
|
,b.quota_rep_descr
|
|
,b.director
|
|
,b.billto_group
|
|
,b.shipto_group
|
|
,b.chan
|
|
,b.chansub
|
|
,b.chan_retail
|
|
,b.part
|
|
,b.part_descr
|
|
,b.part_group
|
|
,b.branding
|
|
,b.majg_descr
|
|
,b.ming_descr
|
|
,b.majs_descr
|
|
,b.mins_descr
|
|
,b.segm
|
|
,b.substance
|
|
,b.fs_line
|
|
,b.r_currency
|
|
,b.r_rate
|
|
,b.c_currency
|
|
,b.c_rate
|
|
,b.units*s.factor*m.momix units
|
|
,b.value_loc*s.factor*m.momix value_loc
|
|
,b.value_usd*s.factor*m.momix value_usd
|
|
,b.cost_loc*s.factor*m.momix cost_loc
|
|
,b.cost_usd*s.factor*m.momix cost_usd
|
|
,b.calc_status
|
|
,b.flag
|
|
,make_date(mseq.yr + 2021,mseq.cal,m.odom) order_date
|
|
,od.sspr || ' - ' || to_char(make_date(mseq.yr + 2021,mseq.cal,m.odom),'Mon') order_month
|
|
,od.ssyr order_season
|
|
,make_date(mseq.yr + 2021,mseq.cal,m.odom) + rlag request_date
|
|
,rd.sspr || ' - ' ||to_char(make_date(mseq.yr + 2021,mseq.cal,m.odom) + rlag,'Mon') request_month
|
|
,rd.ssyr request_season
|
|
,make_date(mseq.yr + 2021,mseq.cal,m.odom) + rlag + slag ship_date
|
|
,sd.sspr || ' - ' || to_char(make_date(mseq.yr + 2021,mseq.cal,m.odom) + rlag + slag,'Mon') ship_month
|
|
,sd.ssyr ship_season
|
|
,'replace_version' "version"
|
|
,'replace_source'||' volume' iter
|
|
,log.id
|
|
,COALESCE(log.doc->>'tag','') "tag"
|
|
,log.doc->>'message' "comment"
|
|
,log.doc->>'type' module
|
|
FROM
|
|
basemix b
|
|
CROSS JOIN vscale s
|
|
CROSS JOIN mmixp m
|
|
CROSS JOIN closest
|
|
CROSS JOIN log
|
|
LEFT OUTER JOIN mseq ON
|
|
mseq.m = closest.m
|
|
LEFT OUTER JOIN gld od ON
|
|
make_date(mseq.yr + 2021,mseq.cal,m.odom) BETWEEN od.sdat AND od.edat
|
|
LEFT OUTER JOIN gld rd ON
|
|
make_date(mseq.yr + 2021,mseq.cal,m.odom) + rlag BETWEEN rd.sdat AND rd.edat
|
|
LEFT OUTER JOIN gld sd ON
|
|
make_date(mseq.yr + 2021,mseq.cal,m.odom) + rlag + slag BETWEEN sd.sdat AND sd.edat
|
|
WHERE
|
|
m._month = (SELECT _month FROM closest)
|
|
)
|
|
,pscale AS (
|
|
SELECT
|
|
(SELECT pincr::numeric FROM target) incr
|
|
,(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
|
|
,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
|
|
((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
|
|
)
|
|
,price AS (
|
|
SELECT
|
|
b.fspr
|
|
,b.plnt
|
|
,b.promo
|
|
,b.terms
|
|
,b.bill_cust_descr
|
|
,b.ship_cust_descr
|
|
,b.dsm
|
|
,b.quota_rep_descr
|
|
,b.director
|
|
,b.billto_group
|
|
,b.shipto_group
|
|
,b.chan
|
|
,b.chansub
|
|
,b.chan_retail
|
|
,b.part
|
|
,b.part_descr
|
|
,b.part_group
|
|
,b.branding
|
|
,b.majg_descr
|
|
,b.ming_descr
|
|
,b.majs_descr
|
|
,b.mins_descr
|
|
,b.segm
|
|
,b.substance
|
|
,b.fs_line
|
|
,b.r_currency
|
|
,b.r_rate
|
|
,b.c_currency
|
|
,b.c_rate
|
|
,0::numeric units
|
|
,(CASE WHEN p.factor = 0 THEN b.units * p.mod_price/b.r_rate ELSE b.value_loc*p.factor END)::numeric value_loc
|
|
,(CASE WHEN p.factor = 0 THEN b.units * p.mod_price ELSE b.value_usd*p.factor END)::numeric value_usd
|
|
,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
|
|
,'replace_version' "version"
|
|
,'replace_source'||' price' iter
|
|
,log.id
|
|
,COALESCE(log.doc->>'tag','') "tag"
|
|
,log.doc->>'message' "comment"
|
|
,log.doc->>'type' module
|
|
FROM
|
|
volume b
|
|
CROSS JOIN pscale p
|
|
CROSS JOIN log
|
|
WHERE
|
|
p.factor <> 0 or p.mod_price <> 0
|
|
)
|
|
, ins AS (
|
|
INSERT INTO rlarp.osm_pool (SELECT * FROM price UNION ALL SELECT * FROM volume) RETURNING *
|
|
)
|
|
,insagg AS (
|
|
SELECT
|
|
---------customer info-----------------
|
|
bill_cust_descr
|
|
,billto_group
|
|
,ship_cust_descr
|
|
,shipto_group
|
|
,quota_rep_descr
|
|
,director
|
|
,segm
|
|
,substance
|
|
,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
|
|
,tag
|
|
,comment
|
|
--------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
|
|
,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
|
|
,tag
|
|
,comment
|
|
)
|
|
SELECT json_agg(row_to_json(insagg)) x from insagg |