forecast_api/route_sql/new_basket.sql
2019-03-22 04:42:13 -04:00

797 lines
24 KiB
SQL

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
,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 (
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)
)
,SEG AS (
SELECT
x.GLEC
,x.SEGM
FROM
(
VALUES
('1CU','Retail'),
('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)
)
,MG AS (
SELECT
X.F1, X.MING, X.GRP
FROM
(
VALUES
('L','000','Branded'),
('L','B10','Branded'),
('L','B11','Branded'),
('L','B52','Branded'),
('L','C10','Branded'),
('L','D12','Branded'),
('L','M11','Branded'),
('L','P12','Branded'),
('L','P13','Branded'),
('L','S10','Branded'),
('L','Y10','Branded'),
('L','Y11','Branded'),
('L','Y12','Branded'),
('P','B10','Branded'),
('P','B11','Branded'),
('P','B52','Branded')
) AS X (F1, MING, GRP)
)
,REPC AS (
SELECT
LTRIM(RTRIM(C.A9)) RCODE
,LTRIM(RTRIM(C.A9)) || ' - ' || C.A30 REPP
,COALESCE(Q.DIR,'Other') DIRECTOR
FROM
LGDAT.CODE C
LEFT OUTER JOIN RLARP.QRH Q ON
Q.QR = LTRIM(RTRIM(C.A9))
WHERE
C.A2 = 'MM'
)
--MOLD DESCRIPTIONS
,MD AS (
SELECT
U.MOLD
,MAX(U.DESCR) DESCR
FROM
(
SELECT
SUBSTR(M.AVPART,1,8) MOLD
,MAX(M.AVDES1) DESCR
FROM
LGDAT.STKMM M
WHERE
LENGTH(M.AVPART) > 8
AND SUBSTR(M.AVGLED,1,1) <= '2'
GROUP BY
SUBSTR(M.AVPART,1,8)
UNION ALL
SELECT
SUBSTR(P.AWPART,1,8) MOLD
,MAX(P.AWDES1) DESCR
FROM
LGDAT.STKMP P
WHERE
LENGTH(P.AWPART) > 8
AND SUBSTR(P.AWGLED,1,1) <= '2'
GROUP BY
SUBSTR(P.AWPART,1,8)
) U
GROUP BY
U.MOLD
)
----------------------------------------------------sales major codes----------------------------------------------------------------------------------------------------------------------------------
,SJ AS (
SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') = ''
)
----------------------------------------------------sales minor codes----------------------------------------------------------------------------------------------------------------------------------
,SI AS (
SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') <> ''
)
,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
,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----------------------------
--where_clause
quota_rep_descr = '30033 - ROBERT NELSON'
AND mod_chan = 'DISTRIBUTOR'
AND shipto_group = 'KINNEY BONDED'
AND "version" = 'b20'
AND iter = 'copy'
--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 adj_orderdate <= adj_shipdate
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)---------------
,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
,sum(value_usd) value_usd
FROM
alldates
GROUP BY
to_char(orderdate,'Mon')
,seq
,promo
--,extract(day from orderdate)
--,requestdate-orderdate
--,shipdate - requestdate
)
,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
)
,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
FROM
mmix
)
--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
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
null::text plnt ---master data
,0::numeric(11,0) "ddord#"
,0::numeric(11,0) "dditm#"
,0::numeric(11,0) "fgbol#"
,0::numeric(11,0) "fgent#"
,0::numeric(9,0) "diinv#"
,0::numeric(3,0) "dilin#"
,mxm.promo --history
,null::text return_reas
,null::text terms
,''::text custpo
,'I' dhincr
,null::numeric diext
,null::numeric ditdis
,null::date dcodat
,null::date ddqdat
,null::date dcmdat
,null::date dhidat
,sd.fspr
,null::text remit_to
,null::text bill_class
,(regexp_match(jr.bill_cust_descr,'(.*?)(?= - |$)'))[1] bill_cust
,null:: text bill_rep
,null::text bill_terr
,null::text ship_class
,(regexp_match(jr.ship_cust_descr,'(.*?)(?= - |$)'))[1] ship_cust
,null::text ship_rep
,null::text ship_terr
,null::text quota_rep
,null::text account
,null::text shipgrp
,null::text geo
,null::text chan
,null::text orig_ctry
,null::text orig_prov
,null::text orig_post
,null::text dest_ctry
,null::text dest_prov
,null::text dest_post
,(regexp_match(jr.part_descr,'(.*?)(?= - |$)'))[1] part
,null::text ord_gldc
,null::text majg
,null::text ming
,null::text majs
,null::text mins
,null::text gldc
,null::text glec
,null::text harm
,null::text clss
,null::text brand
,null::text assc
,'41010'::text fs_line
,null::text r_currency
,null::numeric r_rate
,null::text c_currency
,null::numeric c_rate
,0::numeric(15,5) ddqtoi
,0::numeric(15,5) ddqtsi
,0::numeric(15,5) fgqshp
,0::numeric(15,5) diqtsh
,mxm.qty*mxm.momix*jr.mix fb_qty --history value
,0::numeric fb_cst_loc --history part mix
,0::numeric fb_cst_loc_cur
,0::numeric fb_cst_loc_fut
,mxm.amount*mxm.momix*jr.mix fb_val_loc --history value
,0::numeric fb_val_loc_pl
,null::text calc_status
,null::text flag
,make_date(mxm.yr + 2020,mxm.cal,mxm.odom) orderdate
,make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag requestdate
,make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag + slag shipdate
,make_date(mxm.yr + 2020,mxm.cal,mxm.odom) adj_orderdate
,make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag adj_requestdate
,make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag + slag adj_shipdate
,'replace_version' "version"
,'replace_source'||' new basket' iter
-----------------------ui columns--------------------------------
,'replace_iterdet' iterdet
,$$replace_iterdef$$::json iterdef
,od.ssyr order_season
,to_char(make_date(mxm.yr + 2020,mxm.cal,mxm.odom),'Mon') order_month
,sd.ssyr ship_season
,to_char(make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag + slag,'Mon') ship_month
,rd.ssyr request_season
,to_char(make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag,'Mon') request_month
,jr.part_descr part_descr
,null::text part_family
,null::text part_group
,null::text branding
,null::text color
,null::text segm
,jr.bill_cust_descr
,null::text billto_group
,jr.ship_cust_descr
,null::text shipto_group
,null::text majg_descr
,null::text ming_descr
,null::text majs_descr
,null::text mins_descr
,null::text mod_chan
,null::text mod_chansub
,null::text quota_rep_descr
,null::text director_descr
,null::numeric value_loc
,null::numeric value_usd
,null::numeric cost_loc
,null::numeric cost_usd
,null::numeric units
,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
make_date(mxm.yr + 2020,mxm.cal,mxm.odom) BETWEEN od.sdat AND od.edat
LEFT OUTER JOIN gld rd ON
make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag BETWEEN rd.sdat AND rd.edat
LEFT OUTER JOIN gld sd ON
make_date(mxm.yr + 2020,mxm.cal,mxm.odom) + rlag + slag BETWEEN sd.sdat AND sd.edat
)
--SELECT * FROM basemix
,final AS (
SELECT
COALESCE(m.avdplt,p.awdplt) plnt --master data
,b."ddord#"
,b."dditm#"
,b."fgbol#"
,b."fgent#"
,b."diinv#"
,b."dilin#"
,b.promo --history
,b.return_reas
,bc.bvterm terms --history cust mix
,b.custpo
,b.dhincr
,b.diext
,b.ditdis
,b.dcodat
,b.ddqdat
,b.dcmdat
,b.dhidat
,b.fspr
,bc.bvcomp remit_to --master data
,bc.bvclas bill_class --master data
,b.bill_cust --history cust mix
,bc.bvsalm bill_rep --master data
,bc.bvterr bill_terr --master data
,sc.bvclas ship_class --master data
,b.ship_cust --history cust mix
,sc.bvsalm ship_rep --master data
,sc.bvterr ship_terr --master data
--quota rep--------------------------------------------
,RTRIM(
COALESCE(
--retail items go to currep, or if null go to 90005
CASE WHEN COALESCE(avgled,awgled) IN ('1RE','1CU') THEN
CASE WHEN bc.bvctry = 'CAN' THEN
--Rachel Bowman
'50300'
ELSE
--retail chain got to Mark Wilkinson
CASE COALESCE(cg.cgrp,bc.bvname)
WHEN 'THE HOME DEPOT' THEN '90005'
WHEN 'DO IT BEST' THEN '90005'
WHEN 'ACE HARDWARE' THEN '90005'
WHEN 'ALDI' THEN '90005'
WHEN 'AMAZON.COM' THEN '90005'
WHEN 'GARDEN RIDGE CORP' THEN '90005'
--all other retail goes to Doran Marable
ELSE '50200'
END
END
ELSE
CASE WHEN COALESCE(avming,awming) = 'B52' THEN
'PW'
--gdir, ndir go to bill-to rep
ELSE
CASE WHEN bc.bvclas IN ('GDIR','NDIR') THEN
bc.bvsalm
ELSE
sc.bvsalm
END
END
END
,''
)
) quota_rep
,coalesce(cg.cgrp,bc.bvname) account
,coalesce(sg.cgrp,sc.bvname) shipgrp
,coalesce(t.geo,'UNDEFINED') geo
,coalesce(c.chan,'UNDEFINED') chan
,ad.qzcryc orig_ctry
,ad.qzprov orig_prov
,ad.qzpost orig_post
,sc.bvctry dest_ctry
,sc.bvprcd dest_prov
,sc.bvpost dest_post
,b.part --history part mix
,COALESCE(m.avglcd, p.awgldc) ord_gldc --master data
,COALESCE(m.avmajg,p.awmajg) majg --master data
,COALESCE(m.avming,p.awming) ming --master data
,COALESCE(m.avmajs,p.awmajs) majs --master data
,COALESCE(m.avmins,p.awmins) mins --master data
,COALESCE(m.avglcd,p.awgldc) gldc --master data
,COALESCE(m.avgled,p.awgled) glec --master data
,COALESCE(m.avharm,p.awharm) harm --master data
,COALESCE(m.avclss,p.awclss) clss --master data
,SUBSTR(COALESCE(m."avcpt#",p."awvpt#"),1,1) brand --master data
,COALESCE(m.avassc,p.awassc) assc --master data
,b.fs_line --master data
,bc.bvcurr r_currency --history cust mix
,rx.rate r_rate --master data
,copr.curr c_currency --master data
,cx.rate c_rate --master data
,b.ddqtoi
,b.ddqtsi
,b.fgqshp
,b.diqtsh
,b.fb_qty
,COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.fb_qty fb_cst_loc
,COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.fb_qty fb_cst_loc_cur
,COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.fb_qty fb_cst_loc_fut
,b.fb_val_loc
,b.fb_val_loc_pl
,b.calc_status
,b.flag
,b.orderdate
,b.requestdate
,b.shipdate
,b.adj_orderdate
,b.adj_requestdate
,b.adj_shipdate
,b."version"
,b.iter
-----------------------ui columns--------------------------------
,b.iterdet
,b.iterdef
,b.order_season
,b.order_month
,b.ship_season
,b.ship_month
,b.request_season
,b.request_month
,b.part_descr
,SUBSTR(b.part,1,3)||coalesce(' - '||F.DESCR,'') part_family
,SUBSTRING(b.part,1,8)||coalesce(' - '||MD.DESCR,'') part_group
,COALESCE(MG.GRP,'Unbranded') branding
,CASE WHEN substring(COALESCE(m.avgled, p.awgled),1,1) <= '2' THEN SUBSTRING(b.part,9,3) ELSE '' END color
,COALESCE(SEG.SEGM,'Other') segm
,b.bill_cust_descr
,coalesce(cg.cgrp,bc.bvname) billto_group
,b.ship_cust_descr
,coalesce(sg.cgrp,sc.bvname) shipto_group
,COALESCE(m.avmajg,p.awmajg)||COALESCE(' - '||BQDES,'') majg_descr
,COALESCE(m.avming,p.awming)||COALESCE(' - '||BRDES,'') ming_descr
,COALESCE(m.avmajs,p.awmajs)||COALESCE(' - '||SJ.BSDES1,'') majs_descr
,COALESCE(m.avmins,p.awmins)||COALESCE(' - '||SI.BSDES1,'') mins_descr
,CASE COALESCE(SEG.SEGM,'Other')
WHEN 'Retail' THEN c.RETAIL
ELSE coalesce(c.chan,'UNDEFINED')
END mod_chan
,CASE COALESCE(SEG.SEGM,'Other')
WHEN 'Retail' THEN c.RETAILSUB
ELSE ''
END mod_chansub
,repc.repp quota_rep_descr
,repc.director director_descr
,b.fb_val_loc value_loc
,b.fb_val_loc * rx.rate value_usd
,COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.fb_qty cost_loc
,COALESCE(im.cgstcs,ip.chstcs, ir.y0stcs)*b.fb_qty*cx.rate cost_usd
,b.fb_qty units
FROM
basemix b
LEFT OUTER JOIN LGDAT.STKMM M ON
M.AVPART = b.PART
LEFT OUTER JOIN LGDAT.STKMP P ON
P.AWPART = b.PART
LEFT OUTER JOIN lgdat.stka a ON
v6part = b.part
AND v6plnt = COALESCE(m.avdplt,p.awdplt)
LEFT OUTER JOIN SEG ON
SEG.GLEC = COALESCE(m.avgled,p.awgled)
--AND SEG.SEGM <> 'Other'
LEFT OUTER JOIN MG ON
MG.F1 = SUBSTR(b.PART,16,1)
AND MG.MING = COALESCE(m.avming,p.awming)
LEFT OUTER JOIN RLARP.FAMILY F ON
F.F3 = SUBSTR(b.PART,1,3)
LEFT OUTER JOIN MD ON
MD.MOLD = SUBSTR(b.PART,1,8)
LEFT OUTER JOIN LGDAT.CUST BC ON
BC.BVCUST = b.BILL_CUST
LEFT OUTER JOIN LGDAT.CUST SC ON
SC.BVCUST = b.BILL_CUST
LEFT OUTER JOIN RLARP.FFCHNL c ON
c.BILL = bc.bvclas
AND c.SHIP = sc.bvclas
LEFT OUTER JOIN rlarp.ffterr t ON
t.prov = sc.bvprcd AND
t.ctry = sc.bvctry
LEFT OUTER JOIN RLARP.FFCUST CG ON
CG.CUSTN = BC.BVCUST
LEFT OUTER JOIN RLARP.FFCUST SG ON
SG.CUSTN = SC.BVCUST
LEFT OUTER JOIN REPC ON
REPC.RCODE = RTRIM(
COALESCE(
--retail items go to currep, or if null go to 90005
CASE WHEN COALESCE(avgled,awgled) IN ('1RE','1CU') THEN
CASE WHEN bc.bvctry = 'CAN' THEN
--Rachel Bowman
'50300'
ELSE
--retail chain got to Mark Wilkinson
CASE COALESCE(cg.cgrp,bc.bvname)
WHEN 'THE HOME DEPOT' THEN '90005'
WHEN 'DO IT BEST' THEN '90005'
WHEN 'ACE HARDWARE' THEN '90005'
WHEN 'ALDI' THEN '90005'
WHEN 'AMAZON.COM' THEN '90005'
WHEN 'GARDEN RIDGE CORP' THEN '90005'
--all other retail goes to Doran Marable
ELSE '50200'
END
END
ELSE
CASE WHEN COALESCE(avming,awming) = 'B52' THEN
'PW'
--gdir, ndir go to bill-to rep
ELSE
CASE WHEN bc.bvclas IN ('GDIR','NDIR') THEN
bc.bvsalm
ELSE
sc.bvsalm
END
END
END
,''
)
)
LEFT OUTER JOIN SI ON
SI.BSMJCD = COALESCE(m.avmajs,p.awmajs)
AND SI.BSMNCD = COALESCE(m.avmins,p.awmins)
LEFT OUTER JOIN SJ ON
SJ.BSMJCD = COALESCE(m.avmajs,p.awmajs)
LEFT OUTER JOIN LGDAT.MAJG ON
BQGRP = COALESCE(m.avmajg,p.awmajg)
LEFT OUTER JOIN LGDAT.MMGP ON
BRMGRP = COALESCE(m.avming,p.awming)
AND BRGRP = COALESCE(m.avmajg,p.awmajg)
LEFT OUTER JOIN lgdat.icstm im ON
im.cgpart = b.part
AND im.cgplnt = a.v6plnt
LEFT OUTER JOIN lgdat.icstp ip ON
ip.chpart = b.part
AND ip.chplnt = a.v6plnt
LEFT OUTER JOIN lgdat.icstr ir ON
ir.y0part = b.part
AND ir.y0plnt = a.v6plnt
LEFT OUTER JOIN lgdat.plnt ON
yaplnt = a.v6plnt
LEFT OUTER JOIN copr ON
copr.comp = yacomp::text
LEFT OUTER JOIN rlarp.ffcret cx ON
cx.perd = '1910'
AND cx.rtyp = 'MA'
AND cx.fcur = copr.curr
AND cx.tcur = 'US'
LEFT OUTER JOIN rlarp.ffcret rx ON
rx.perd = '1910'
AND rx.rtyp = 'MA'
AND rx.fcur = bc.bvcurr
AND rx.tcur = 'US'
LEFT OUTER JOIN LGDAT.ADRS AD ON
AD.QZADR = plnt."yaadr#"
)
/*
,clone_part_meta AS (
SELECT
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.segm
,b.majg_descr
,b.ming_descr
,b.majs_descr
,b.mins_descr
,b.quota_rep
,sum(fb_val_loc * r_rate) agg
FROM
rlarp.osm_fcpool b
WHERE
-----------------scenario----------------------------
--where_clause
quota_rep_descr = '30033 - ROBERT NELSON'
AND mod_chan = 'DISTRIBUTOR'
AND shipto_group = 'KINNEY BONDED'
AND "version" = 'b20'
AND iter = 'copy'
--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 adj_orderdate <= adj_shipdate
GROUP BY
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.segm
,b.majg_descr
,b.ming_descr
,b.majs_descr
,b.mins_descr
,b.quota_rep
ORDER BY
agg desc
)
*/
, ins AS (
INSERT INTO rlarp.osm_fcpool (SELECT * FROM pricing UNION ALL SELECT * FROM volume) 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