forecast_api/route_sql/new_basket.sql

480 lines
15 KiB
SQL

-- Connection: usmidsap01.ubm
WITH
/*
the volume must be expressed in terms of units, since that is what it will be scaling
*/
target AS (select $$replace_request$$::json def)
--select * from newm
,GLD AS (
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
,to_char(CASE WHEN EXTRACT(MONTH FROM N1ED01) >= 6 THEN EXTRACT(MONTH FROM N1ED01) -5 ELSE EXTRACT(MONTH FROM N1ED01) +7 END,'FM00') || ' - '|| TO_CHAR(n1ed01,'FMMon') SORTMO
FROM
LGDAT.GLDATREF
INNER JOIN LGDAT.GLDATE ON
KPCOMP = N1COMP AND
KPCCYY = N1CCYY
WHERE
N1COMP = 93
--AND DIGITS(N1FSYP) = '1901'
)
,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)
)
,seg AS (
SELECT
x.GLEC glec
,x.SEGM segm
FROM
(
VALUES
('1SU','Sustainable'),
('1CU','Sustainable'),
('1GR','Greenhouse'),
('1NU','Nursery'),
('1RE','Retail'),
('2WI','Greenhouse'),
('3BM','Other'),
('3CO','Other'),
('3PE','Other'),
('3PP','Other'),
('4CO','Other'),
('4RA','Other'),
('9MI','Other'),
('9SA','Other'),
('9TO','Other')
) X(GLEC, SEGM)
)
,copr AS (
SELECT
LTRIM(RTRIM(A9)) AS COMP,
A30 AS DESCR,
SUBSTR(C.A249,242,2) CURR,
SUBSTR(C.A249,32,4) AS GL,
SUBSTR(C.A249,190,4) AS AR,
SUBSTR(C.A249,182,4) AS AP,
SUBSTR(C.A249,198,4) AS FA,
SUBSTR(C.A249,238,4) AS IC ,
SUBSTR(D.A249,9,5) CONS_FUNC
FROM
LGDAT.CODE
LEFT OUTER JOIN LGDAT.NAME C ON
'C0000'||LTRIM(RTRIM(A9)) = C.A7
LEFT OUTER JOIN LGDAT.NAME D ON
'D0000'||LTRIM(RTRIM(A9)) = D.A7
WHERE
A2 = 'AA' OR A2 IS NULL
)
,alldates AS (
SELECT
promo
,terms
,r_currency
,order_month
,mseq.s seq
,order_date
,request_date
,ship_date
,sum(value_usd) value_usd
FROM
rlarp.osm_pool
LEFT OUTER JOIN mseq ON
mseq.m = order_month
WHERE
-----------------scenario----------------------------
where_clause
--probably dont want to include adjustments that have blown away volume and good sources of dating info
-----------------additional params-------------------
AND calc_status||flag <> 'CLOSEDREMAINDER' --exclude short ships when building order adjustments
AND order_date <= ship_date
GROUP BY
promo
,terms
,r_currency
,order_month
,mseq.s
,order_date
,request_date
,ship_date
HAVING
sum(value_usd) <> 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)
)
--select * from dom
---------------------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
,terms
,(SELECT r_currency FROM alldates GROUP BY r_currency ORDER BY SUM(value_usd) DESC LIMIT 1) r_currency
--should terms be included here?
,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
,terms
--,extract(day from order_date)
--,request_date-order_date
--,ship_date - request_date
)
--select * from mmix
,targm AS (
SELECT
je.key as month
,r.amount
,r.qty
,s
,cal
,yr
FROM
target
JOIN LATERAL json_each(def->'months') je ON true
JOIN LATERAL json_to_record(je.value) as r (amount numeric, qty numeric) ON TRUE
LEFT OUTER JOIN mseq ON
mseq.m = je.key
)
--select * from targm
,mmixp AS (
SELECT
_month
,seq
,promo
,terms
,r_currency
,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
)
--select * from mmixp
--month cross join mix
,mxm AS (
SELECT
t.month
,t.amount
,t.qty
,t.s
,t.cal
,t.yr
,x.momix
,x.odom
,x.rlag
,x.slag
,x.promo
,x.terms
,x.r_currency
FROM
targm t
LEFT OUTER JOIN mmixp x ON
x._month = (
SELECT
_month
FROM
mmixp
ORDER BY
abs(seq - t.s) ASC
LIMIT 1
)
)
--SELECT * FROM mxm
--this basemix is probably join going to be part-bill-ship with all master data joined later since it is not known if any original is salvaged
,basemix AS (
SELECT
sd.fspr
,mxm.promo
,mxm.terms
,mxm.r_currency
,jr.bill_cust_descr
,jr.ship_cust_descr
,rtrim((regexp_match(jr.part_descr,'(.*?)(?= - |$)'))[1]) part
,jr.part_descr
,substring(jr.part_descr,1,8) part_group
,mxm.qty*mxm.momix*jr.mix units
,mxm.amount*mxm.momix*jr.mix value_usd --assume that target dollars are USD
,make_date(mxm.yr + 2024,mxm.cal,mxm.odom) order_date
,od.sortmo order_month
,od.ssyr order_season
,make_date(mxm.yr + 2024,mxm.cal,mxm.odom) + rlag request_date
,rd.sortmo request_month
,rd.ssyr request_season
,make_date(mxm.yr + 2024,mxm.cal,mxm.odom) + rlag + slag ship_date
,sd.sortmo ship_month
,sd.ssyr ship_season
,jr.mix
FROM
target
JOIN LATERAL json_array_elements(def->'basket') as ae(e) ON true
JOIN LATERAL json_to_record(ae.e) as jr(part_descr text, bill_cust_descr text, ship_cust_descr text, mix numeric) ON true
CROSS JOIN mxm
LEFT OUTER JOIN gld od ON
od.drange @> make_date(mxm.yr + 2024,mxm.cal,mxm.odom)
LEFT OUTER JOIN gld rd ON
rd.drange @> (make_date(mxm.yr + 2024,mxm.cal,mxm.odom) + rlag)
LEFT OUTER JOIN gld sd ON
sd.drange @> (make_date(mxm.yr + 2024,mxm.cal,mxm.odom) + rlag + slag)
)
--SELECT * FROM basemix
,log AS (
INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING *
)
,final AS (
SELECT
b.fspr
,i.dplt plnt
,b.promo
,COALESCE(b.terms,bc.bvterm) terms
,b.bill_cust_descr
,b.ship_cust_descr
,(SELECT max(rcode) FROM rlarp.repc WHERE repp ~ (log.doc->'scenario'->>'quota_rep_descr')) dsm
,log.doc->'scenario'->>'quota_rep_descr' quota_rep_descr
,(SELECT max(director) FROM rlarp.repc WHERE repp ~ (log.doc->'scenario'->>'quota_rep_descr')) director
,COALESCE(CASE bc.BVADR6 WHEN '' THEN bc.BVNAME ELSE bc.BVADR6 END,b.bill_cust_descr) billto_group
,COALESCE(CASE sc.BVADR6 WHEN '' THEN sc.BVNAME ELSE sc.BVADR6 END,b.ship_cust_descr) shipto_group
,CASE SUBSTRING(bc.bvclas,2,3)
--if the bill to class is ditsributor, then it's either warehouse or drop
WHEN 'DIS' THEN
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
CASE SUBSTRING(sc.bvclas,2,3)
WHEN 'DIS' THEN 'WHS'
ELSE 'DRP'
END
--CASE WHEN RTRIM(SUBSTRING(LTRIM(SC.BVADR7)||SC.BVNAME,1,30)) = RTRIM(SUBSTRING(LTRIM(BC.BVADR7)||BC.BVNAME,1,30)) THEN 'DIS' ELSE 'DRP' END
--everything else does not involve a distributor and is considered direct
ELSE 'DIR'
END chan
,CASE SUBSTRING(bc.bvclas,2,3)
WHEN 'DIS' THEN
--if the ship-to is a different name than the bill-to then it's drop, otherwise it's warehouse
CASE SUBSTRING(sc.bvclas,2,3)
WHEN 'DIS' THEN 'WHS'
ELSE CASE SUBSTRING(sc.bvclas,1,1) WHEN 'R' THEN 'RDP' ELSE 'DRP' END
END
WHEN 'MAS' THEN 'RMN'
WHEN 'NAT' THEN 'RMN'
ELSE CASE SUBSTRING(sc.bvclas,1,1) WHEN 'R' THEN 'RDI' ELSE 'DIR' END
END chansub
,null::text chan_retail
,b.part
,b.part_descr
,b.part_group
,i.branding
,i.majg||' - '||i.majgd majg_descr
,i.ming||' - '||i.mingd ming_descr
,i.majs||' - '||i.majsd majs_descr
,i.mins||' - '||i.minsd mins_descr
,seg.segm
,CASE WHEN i.majg = '610' THEN 'Fiber' ELSE 'Plastic' END substance
,'41010' fs_line --master data
,b.r_currency --history cust mix
,rx.rate r_rate --master data
,copr.curr c_currency --master data
,cx.rate c_rate --master data
,round(b.units ,2) units
,round((b.value_usd / COALESCE(rx.rate,1))::numeric ,2) value_loc --b.value is denominated in USD, need to apply currency to get to local, assume 1 if using a fake customer
,round(b.value_usd ,2) value_usd --b.value is already denominated in usd
,round((COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.units)::numeric ,2) cost_loc
,round((COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.units*cx.rate)::numeric,2) cost_usd
,'CLOSED' calc_status
,'SHIPMENT' 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'||' volume' iter
,log.id
,COALESCE(log.doc->>'tag','') "tag"
,log.doc->>'message' "comment"
,log.doc->>'type' module
,round(b.units * i.nwht * CASE i.nwun WHEN 'KG' THEN 2.2046 ELSE 1 END, 2) pounds
FROM
basemix b
CROSS JOIN log
LEFT OUTER JOIN "CMS.CUSLG".itemm i ON
i.item = b.part
LEFT OUTER JOIN SEG ON
SEG.GLEC = i.glec
--AND SEG.SEGM <> 'Other'
LEFT OUTER JOIN LGDAT.CUST BC ON
BC.BVCUST = rtrim(substring(b.bill_cust_descr,1,8))
LEFT OUTER JOIN LGDAT.CUST SC ON
SC.BVCUST = rtrim(substring(b.ship_cust_descr,1,8))
LEFT OUTER JOIN rlarp.repc r ON
r.rcode = CASE WHEN i.ming = 'B52' THEN 'PW' ELSE
--if the gl expense code is 1RE use the retail rep assigned to the bill-to customer if available
CASE WHEN COALESCE(seg.segm,'') = 'Retail' AND COALESCE((SELECT currep FROM lgpgm.usrcust where cucust = bc.bvcust),'') <> ''
THEN
(SELECT currep FROM lgpgm.usrcust where cucust = bc.bvcust)
--default logic
ELSE
CASE SUBSTR(bc.bvclas,2,3)
WHEN 'DIS' THEN sc.bvsalm
ELSE bc.bvsalm
END
END
END
LEFT OUTER JOIN lgdat.icstm im ON
im.cgpart = b.part
AND im.cgplnt = i.dplt
LEFT OUTER JOIN lgdat.icstp ip ON
ip.chpart = b.part
AND ip.chplnt = i.dplt
LEFT OUTER JOIN lgdat.icstr ir ON
ir.y0part = b.part
AND ir.y0plnt = i.dplt
LEFT OUTER JOIN lgdat.plnt ON
yaplnt = i.dplt
LEFT OUTER JOIN copr ON
copr.comp = yacomp::text
LEFT OUTER JOIN rlarp.ffcret cx ON
cx.perd = '2310'
AND cx.rtyp = 'MA'
AND cx.fcur = copr.curr
AND cx.tcur = 'US'
LEFT OUTER JOIN rlarp.ffcret rx ON
rx.perd = '2310'
AND rx.rtyp = 'MA'
AND rx.fcur = COALESCE(bc.bvcurr,b.r_currency)
AND rx.tcur = 'US'
)
, ins AS (
INSERT INTO rlarp.osm_pool SELECT * FROM final 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
,sum(pounds) pounds
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