forecast_api/build/build_pool.sql

518 lines
15 KiB
PL/PgSQL

BEGIN;
DROP TABLE rlarp.osm_fcpool;
--EXPLAIN
--\timing
CREATE TABLE rlarp.osm_fcpool AS (
WITH
---------------------------------------last actual date------------------------------------------------------------------------------------------------------------------------------------------------
SALES_CUTOFF AS (
SELECT MAX(FSPR) MAX_FSPR FROM RLARP.OSM
)
,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
--if the period date is less than the first forecasted order it is actual from perspective of the plan
,CASE WHEN MAX_FSPR = to_char(N1FSYP,'FM0000') THEN 'C' ELSE CASE WHEN SALES_CUTOFF.MAX_FSPR > to_char(N1FSYP,'FM0000') THEN 'P' ELSE 'F' END END CM
,CASE
WHEN MAX_FSPR = to_char(N1FSYP,'FM0000') THEN
'C'
ELSE
CASE
WHEN SALES_CUTOFF.MAX_FSPR > to_char(N1FSYP,'FM0000') THEN
CASE
WHEN SUBSTR(SALES_CUTOFF.MAX_FSPR,1,2) > SUBSTR(to_char(N1FSYP,'FM0000'),1,2) THEN
'P'
ELSE
'C'
END
ELSE
'F'
END
END CY
FROM
LGDAT.GLDATREF
INNER JOIN LGDAT.GLDATE ON
KPCOMP = N1COMP AND
KPCCYY = N1CCYY
CROSS JOIN SALES_CUTOFF
WHERE
N1COMP = 93
--AND DIGITS(N1FSYP) = '1901'
)
--SELECT * FROM gld
--CREATE INDEX SE_DAT ON gld (sdat, edat);
--SELECT daterange(MIN(SDAT),CURRENT_DATE,'[]') INTO _ytd FROM GLD WHERE CY = 'C';
--SELECT ssyr INTO _y FROM gld WHERE current_date <@ daterange(sdat,edat);
--CREATE TEMP TABLE rslt AS
--RETURN QUERY
---------------------------------------segments--------------------------------------------------------------------------------------------------------------------------------------------------------
,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)
)
---------------------------------------branding flag---------------------------------------------------------------------------------------------------------------------------------------------------
,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)
)
---------------------------------------directors-------------------------------------------------------------------------------------------------------------------------------------------------------
,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,'') <> ''
)
----------------------------------------------------date ranges per season------------------------------------------------------------------------------------------------------------------------------
,seas AS(
SELECT
ssyr
,daterange(MIN(sdat),MAX(edat),'[]') dr
,current_date <@ daterange(MIN(sdat),MAX(edat),'[]') cy
FROM
gld
GROUP BY
ssyr
ORDER BY
ssyr DESC
)
,intv AS (
SELECT current_date - lower(dr) dy from seas where cy = true
)
,std AS (
SELECT
s.ssyr
,s.dr
,s.cy
,daterange(lower(dr),dy + LOWER(dr),'[]') ytd
FROM
seas s
CROSS JOIN intv
)
--select * from std
---------------------------------------union actual and forecast---------------------------------------------------------------------------------------------------------------------------------------
,UN AS (
--plan
SELECT
osm.plnt
,osm."ddord#"
,osm."dditm#"
,osm."fgbol#"
,osm."fgent#"
,osm."diinv#"
,osm."dilin#"
,osm.promo
,osm.return_reas
,osm.terms
,osm.custpo
,osm.dhincr
,osm.diext
,osm.ditdis
,osm.dcodat
,osm.ddqdat
,osm.dcmdat
,osm.dhidat
,osm.fspr
,osm.remit_to
,osm.bill_class
,osm.bill_cust
,osm.bill_rep
,osm.bill_terr
,osm.ship_class
,osm.ship_cust
,osm.ship_rep
,osm.ship_terr
,osm.quota_rep
,osm.account
,osm.shipgrp
,osm.geo
,osm.chan
,osm.orig_ctry
,osm.orig_prov
,osm.orig_post
,osm.dest_ctry
,osm.dest_prov
,osm.dest_post
,osm.part
,osm.ord_gldc
,osm.majg
,osm.ming
,osm.majs
,osm.mins
,osm.gldc
,osm.glec
,osm.harm
,osm.clss
,osm.brand
,osm.assc
,osm.fs_line
,osm.r_currency
,osm.r_rate
,osm.c_currency
,osm.c_rate
,osm.ddqtoi
,osm.ddqtsi
,osm.fgqshp
,osm.diqtsh
,osm.fb_qty
,osm.fb_cst_loc
,osm.fb_cst_loc_cur
,osm.fb_cst_loc_fut
,osm.fb_val_loc
,osm.fb_val_loc_pl
,osm.calc_status
,osm.flag
,osm.orderdate
,osm.requestdate
,greatest(least(osm.shipdate,sd.edat),sd.sdat) shipdate
,osm.adj_orderdate
,osm.adj_requestdate
,osm.adj_shipdate
,osm."version"
,osm.iter
----------------presentation columns----------------------------------------------
,null::text iterdet
,null::jsonb iterdef
,OD.SSYR order_season
,to_char(osm.adj_orderdate,'Mon') order_month
,SD.SSYR ship_season
,to_char(osm.adj_shipdate,'Mon') ship_month
,RD.SSYR request_season
,to_char(osm.adj_requestdate,'Mon') request_month
,osm.PART ||COALESCE(' - '|| RTRIM(COALESCE(AVDES1, AWDES1)),'') part_descr
,F.F3||COALESCE(' - '||F.DESCR,'') part_family
,SUBSTRING(PART,1,8)||COALESCE(' - '||MD.DESCR,'') part_group
,COALESCE(MG.GRP,'Unbranded') branding
,CASE WHEN substring(osm.glec,1,1) <= '2' THEN SUBSTRING(osm.part,9,3) ELSE '' END color
,COALESCE(SEG.SEGM,'Other') segm
,osm.bill_cust || COALESCE(' - '|| RTRIM(BC.BVNAME),'') bill_cust_descr
,osm.account billto_group
,osm.ship_cust || COALESCE(' - '|| RTRIM(SC.BVNAME),'') ship_cust_descr
,osm.shipgrp shipto_group
,osm.MAJG||COALESCE(' - '||BQDES,'') majg_descr
,osm.MING||COALESCE(' - '||BRDES,'') ming_descr
,osm.MAJS||COALESCE(' - '||SJ.BSDES1,'') majs_descr
,osm.MINS||COALESCE(' - '||SI.BSDES1,'') mins_descr
,CASE COALESCE(SEG.SEGM,'Other')
WHEN 'Retail' THEN coalesce(L.RETAIL)
ELSE osm.CHAN
END mod_chan
,CASE COALESCE(SEG.SEGM,'Other')
WHEN 'Retail' THEN coalesce(L.RETAILSUB)
ELSE ''
END mod_chansub
,COALESCE(REPC.REPP,osm.QUOTA_REP) quota_rep_descr
,COALESCE(REPC.DIRECTOR,osm.QUOTA_REP) director_descr
,fb_val_loc value_loc
,fb_val_loc * r_rate value_usd
,fb_cst_loc cost_loc
,fb_cst_loc * c_rate cost_usd
,fb_qty units
FROM
rlarp.osmfs osm
LEFT OUTER JOIN GLD SD ON
osm.FSPR = sd.FSPR
LEFT OUTER JOIN GLD OD ON
osm.ADJ_ORDERDATE BETWEEN od.SDAT AND od.EDAT
LEFT OUTER JOIN GLD RD ON
osm.ADJ_REQUESTDATE BETWEEN RD.SDAT AND RD.EDAT
LEFT OUTER JOIN SEG ON
SEG.GLEC = osm.GLEC
--AND SEG.SEGM <> 'Other'
LEFT OUTER JOIN MG ON
MG.F1 = SUBSTR(osm.PART,16,1)
AND MG.MING = osm.MING
LEFT OUTER JOIN RLARP.FAMILY F ON
F.F3 = SUBSTR(osm.PART,1,3)
LEFT OUTER JOIN LGDAT.STKMM M ON
M.AVPART = osm.PART
LEFT OUTER JOIN LGDAT.STKMP P ON
P.AWPART = osm.PART
LEFT OUTER JOIN MD ON
MD.MOLD = SUBSTR(osm.PART,1,8)
LEFT OUTER JOIN RLARP.FFCHNL L ON
L.BILL = osm.BILL_CLASS
AND L.SHIP = osm.SHIP_CLASS
LEFT OUTER JOIN LGDAT.CUST BC ON
BC.BVCUST = osm.BILL_CUST
LEFT OUTER JOIN LGDAT.CUST SC ON
SC.BVCUST = osm.SHIP_CUST
LEFT OUTER JOIN REPC ON
REPC.RCODE = osm.QUOTA_REP
LEFT OUTER JOIN SI ON
SI.BSMJCD = osm.MAJS
AND SI.BSMNCD = osm.MINS
LEFT OUTER JOIN SJ ON
SJ.BSMJCD = osm.MAJS
LEFT OUTER JOIN LGDAT.MAJG ON
BQGRP = osm.MAJG
LEFT OUTER JOIN LGDAT.MMGP ON
BRMGRP = osm.MING
AND BRGRP = osm.MAJG
WHERE
osm.FS_LINE = '41010'
AND osm.CALC_STATUS <> 'CANCELED'
AND SUBSTR(osm.GLEC,1,1) <= '2'
/*
UNION ALL
SELECT
osm.plnt
,osm."ddord#"
,osm."dditm#"
,osm."fgbol#"
,osm."fgent#"
,osm."diinv#"
,osm."dilin#"
,osm.promo
,osm.return_reas
,osm.terms
,osm.custpo
,osm.dhincr
,osm.diext
,osm.ditdis
,osm.dcodat
,osm.ddqdat
,osm.dcmdat
,osm.dhidat
,osm.fspr
,osm.remit_to
,osm.bill_class
,osm.bill_cust
,osm.bill_rep
,osm.bill_terr
,osm.ship_class
,osm.ship_cust
,osm.ship_rep
,osm.ship_terr
,osm.quota_rep
,osm.account
,osm.shipgrp
,osm.geo
,osm.chan
,osm.orig_ctry
,osm.orig_prov
,osm.orig_post
,osm.dest_ctry
,osm.dest_prov
,osm.dest_post
,osm.part
,osm.ord_gldc
,osm.majg
,osm.ming
,osm.majs
,osm.mins
,osm.gldc
,osm.glec
,osm.harm
,osm.clss
,osm.brand
,osm.assc
,osm.fs_line
,osm.r_currency
,osm.r_rate
,osm.c_currency
,osm.c_rate
,osm.ddqtoi
,osm.ddqtsi
,osm.fgqshp
,osm.diqtsh
,osm.fb_qty
,osm.fb_cst_loc
,osm.fb_cst_loc_cur
,osm.fb_cst_loc_fut
,osm.fb_val_loc
,osm.fb_val_loc_pl
,osm.calc_status
,osm.flag
,osm.orderdate
,osm.requestdate
,greatest(least(osm.shipdate,sd.edat),sd.sdat) shipdate
,osm.adj_orderdate
,osm.adj_requestdate
,osm.adj_shipdate
,osm."version"
,osm.iter
----------------presentation columns----------------------------------------------
,null::text iterdet
,null::jsonb iterdef
,OD.SSYR order_season
,to_char(osm.adj_orderdate,'Mon') order_month
,SD.SSYR ship_season
,to_char(osm.adj_shipdate,'Mon') ship_month
,RD.SSYR request_season
,to_char(osm.adj_requestdate,'Mon') request_month
,PART ||' - '|| RTRIM(COALESCE(AVDES1, AWDES1)) part_descr
,F.F3||' - '||F.DESCR part_family
,SUBSTRING(PART,1,8)||' - '||MD.DESCR part_group
,COALESCE(MG.GRP,'Unbranded') branding
,CASE WHEN substring(osm.glec,1,1) <= '2' THEN SUBSTRING(osm.part,9,3) ELSE '' END color
,COALESCE(SEG.SEGM,'Other') segm
,osm.bill_cust ||' - '|| RTRIM(BC.BVNAME) bill_cust_descr
,osm.account billto_group
,osm.ship_cust ||' - '|| RTRIM(SC.BVNAME) ship_cust_descr
,osm.shipgrp shipto_group
,osm.MAJG||COALESCE(' - '||BQDES,'') majg_descr
,osm.MING||COALESCE(' - '||BRDES,'') ming_descr
,osm.MAJS||COALESCE(' - '||SJ.BSDES1,'') majs_descr
,osm.MINS||COALESCE(' - '||SI.BSDES1,'') mins_descr
,CASE COALESCE(SEG.SEGM,'Other')
WHEN 'Retail' THEN coalesce(L.RETAIL,'')
ELSE osm.CHAN
END mod_chan
,CASE COALESCE(SEG.SEGM,'Other')
WHEN 'Retail' THEN coalesce(L.RETAILSUB,'')
ELSE ''
END mod_chansub
,COALESCE(REPC.REPP,osm.QUOTA_REP) quota_rep_descr
,COALESCE(REPC.DIRECTOR,osm.QUOTA_REP) director_descr
,osm.fb_val_loc::numeric value_loc
,(osm.fb_val_loc * osm.r_rate)::numeric value_usd
,osm.fb_cst_loc::numeric cost_loc
,(osm.fb_cst_loc * osm.c_rate)::numeric cost_usd
,osm.fb_qty::numeric units
FROM
rlarp.osmfs osm
LEFT OUTER JOIN GLD SD ON
osm.FSPR = sd.FSPR
LEFT OUTER JOIN GLD OD ON
osm.ADJ_ORDERDATE BETWEEN od.SDAT AND od.EDAT
LEFT OUTER JOIN GLD RD ON
osm.ADJ_REQUESTDATE BETWEEN RD.SDAT AND RD.EDAT
LEFT OUTER JOIN SEG ON
SEG.GLEC = osm.GLEC
--AND SEG.SEGM <> 'Other'
LEFT OUTER JOIN MG ON
MG.F1 = SUBSTR(osm.PART,16,1)
AND MG.MING = osm.MING
LEFT OUTER JOIN RLARP.FAMILY F ON
F.F3 = SUBSTR(osm.PART,1,3)
LEFT OUTER JOIN LGDAT.STKMM M ON
M.AVPART = osm.PART
LEFT OUTER JOIN LGDAT.STKMP P ON
P.AWPART = osm.PART
LEFT OUTER JOIN MD ON
MD.MOLD = SUBSTR(osm.PART,1,8)
LEFT OUTER JOIN RLARP.FFCHNL L ON
L.BILL = osm.BILL_CLASS
AND L.SHIP = osm.SHIP_CLASS
LEFT OUTER JOIN LGDAT.CUST BC ON
BC.BVCUST = osm.BILL_CUST
LEFT OUTER JOIN LGDAT.CUST SC ON
SC.BVCUST = osm.SHIP_CUST
LEFT OUTER JOIN REPC ON
REPC.RCODE = osm.QUOTA_REP
LEFT OUTER JOIN SI ON
SI.BSMJCD = osm.MAJS
AND SI.BSMNCD = osm.MINS
LEFT OUTER JOIN SJ ON
SJ.BSMJCD = osm.MAJS
LEFT OUTER JOIN LGDAT.MAJG ON
BQGRP = osm.MAJG
LEFT OUTER JOIN LGDAT.MMGP ON
BRMGRP = osm.MING
AND BRGRP = osm.MAJG
WHERE
osm.fs_line = '41010'
AND osm.calc_status <> 'CANCELED'
AND SUBSTRING(osm.glec,1,1) <= '2'
AND osm.version = 'ACTUALS'
AND osm.adj_orderdate BETWEEN '2017-06-01' AND '2018-05-31'
*/
)
SELECT * FROM UN
);
COMMIT;