target osfm_dev as forecast staging area, no need to preserve; set fspr; stage pool instead of direct insert for debug
This commit is contained in:
parent
0a96759945
commit
b4e2ca7919
180
build/build_pool.sql
Normal file
180
build/build_pool.sql
Normal file
@ -0,0 +1,180 @@
|
||||
BEGIN;
|
||||
|
||||
DROP TABLE IF EXISTS rlarp.osm_pool_stage;
|
||||
|
||||
CREATE TABLE rlarp.osm_pool_stage AS (
|
||||
WITH
|
||||
repc AS (
|
||||
SELECT
|
||||
LTRIM(RTRIM(C.A9)) RCODE
|
||||
,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'
|
||||
)
|
||||
,SEG AS (
|
||||
SELECT
|
||||
GLEC
|
||||
,SEGM
|
||||
FROM
|
||||
(
|
||||
VALUES
|
||||
('1CU','Sustainable'),
|
||||
('1SU','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)
|
||||
)
|
||||
----------------------------------------------------sales major codes----------------------------------------------------------------------------------------------------------------------------------
|
||||
,SJ AS (
|
||||
SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') = ''
|
||||
)
|
||||
----------------------------------------------------sales minor codes----------------------------------------------------------------------------------------------------------------------------------
|
||||
,SI AS (
|
||||
SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') <> ''
|
||||
)
|
||||
,logload AS (
|
||||
INSERT INTO rlarp.osm_log (doc) SELECT jsonb_build_object('user',current_user,'tag','merge actuals','type','build_pool','stamp',current_timestamp,'source','top level','message','don''t undo') RETURNING *
|
||||
)
|
||||
SELECT
|
||||
fspr
|
||||
,plnt
|
||||
,promo
|
||||
,terms
|
||||
,bill_cust||' - '||bc.bvname bill_cust_descr
|
||||
,ship_cust||' - '||sc.bvname ship_cust_descr
|
||||
,dsm
|
||||
,coalesce(repc.repp,dsm) quota_rep_descr
|
||||
,repc.director
|
||||
,account billto_group
|
||||
,shipgrp shipto_group
|
||||
,chan
|
||||
,chansub
|
||||
,CASE seg.segm
|
||||
--for 1RE coded product
|
||||
WHEN 'Retail' THEN
|
||||
CASE o.bill_class
|
||||
WHEN 'RONL' THEN 'Online'
|
||||
WHEN 'RNAT' THEN 'National'
|
||||
WHEN 'RMAS' THEN 'National'
|
||||
ELSE
|
||||
------ ship-to class ---------------------
|
||||
CASE o.chan
|
||||
WHEN 'GDIS' THEN 'Distribution'
|
||||
WHEN 'NDIS' THEN 'Distribution'
|
||||
WHEN 'RDIS' THEN 'Distribution'
|
||||
WHEN 'GDRP' THEN 'Grower'
|
||||
WHEN 'NDRP' THEN 'Grower'
|
||||
WHEN 'RDRP' THEN 'Distribution'
|
||||
WHEN 'GDIR' THEN 'Grower'
|
||||
WHEN 'NDIR' THEN 'Grower'
|
||||
-------this will probably need reviewed--------
|
||||
WHEN 'RDIR' THEN 'Distribution'
|
||||
WHEN 'NDIR' THEN 'Grower'
|
||||
WHEN 'GDIR' THEN 'Grower'
|
||||
ELSE 'Distribution'
|
||||
END
|
||||
END
|
||||
--for 1SU 1CU coded product
|
||||
WHEN 'Sustainable' THEN
|
||||
CASE SUBSTRING(o.coltier,1,1)
|
||||
--anything with a bio color tier is bio on the channel
|
||||
WHEN 'R' THEN 'Bio'
|
||||
ELSE
|
||||
CASE o.glec
|
||||
--any 1SU that is not bio is fiber
|
||||
WHEN '1SU' THEN 'Fiber'
|
||||
--any 1CU that is not bio is commercial
|
||||
WHEN '1CU' THEN 'Commercial'
|
||||
ELSE o.chan
|
||||
END
|
||||
END
|
||||
ELSE o.chan
|
||||
END chan_retail
|
||||
,part
|
||||
,part||coalesce(' - '||i.descr,'') part_descr
|
||||
,stlcd part_group
|
||||
,brnd branding
|
||||
,o.majg||' - '||i.majgd majg_descr
|
||||
,o.ming||' - '||i.mingd ming_descr
|
||||
,o.majs||' - '||i.majsd majs_descr
|
||||
,o.mins||' - '||i.minsd mins_descr
|
||||
,seg.segm
|
||||
,CASE WHEN o.majg = '610' THEN 'Fiber' ELSE 'Plastic' END substance
|
||||
,fs_line
|
||||
,r_currency
|
||||
,r_rate
|
||||
,c_currency
|
||||
,c_rate
|
||||
,fb_qty units
|
||||
,fb_val_loc value_loc
|
||||
,fb_val_loc * r_rate value_usd
|
||||
,fb_cst_loc_cur cost_loc
|
||||
,fb_cst_loc_cur * c_rate cost_usd
|
||||
,calc_status
|
||||
,flag
|
||||
,o.odate order_date
|
||||
,to_char(CASE WHEN extract(month FROM o.odate) >= 6 THEN -5 ELSE 7 END + extract(month FROM o.odate),'FM00')||' - '||to_char(o.odate,'TMMon') order_month
|
||||
,oseas order_season
|
||||
,rdate request_date
|
||||
,to_char(CASE WHEN extract(month FROM o.rdate) >= 6 THEN -5 ELSE 7 END + extract(month FROM o.rdate),'FM00')||' - '||to_char(o.rdate,'TMMon') request_month
|
||||
,rseas request_season
|
||||
,sdate ship_date
|
||||
,to_char(CASE WHEN extract(month FROM o.sdate) >= 6 THEN -5 ELSE 7 END + extract(month FROM o.sdate),'FM00')||' - '||to_char(o.sdate,'TMMon') ship_month
|
||||
,sseas ship_season
|
||||
,version
|
||||
,iter
|
||||
,logload.id logid
|
||||
,logload.doc->>'tag' tag
|
||||
,logload.doc->>'message' "comment"
|
||||
,logload.doc->>'type' module
|
||||
FROM
|
||||
rlarp.osmf_dev o
|
||||
CROSS JOIN logload
|
||||
LEFT OUTER JOIN lgdat.cust bc ON
|
||||
bc.bvcust = o.bill_cust
|
||||
LEFT OUTER JOIN lgdat.cust sc ON
|
||||
sc.bvcust = o.ship_cust
|
||||
LEFT OUTER JOIN repc ON
|
||||
repc.rcode = o.dsm
|
||||
/*
|
||||
LEFT OUTER JOIN lgdat.majg ON
|
||||
bqgrp = o.majg
|
||||
LEFT OUTER JOIN lgdat.mmgp ON
|
||||
brmgrp = o.ming
|
||||
AND BRGRP = o.majg
|
||||
LEFT OUTER JOIN si ON
|
||||
si.bsmjcd = o.majs
|
||||
AND si.bsmncd = o.mins
|
||||
LEFT OUTER JOIN sj ON
|
||||
sj.bsmjcd = o.majs
|
||||
*/
|
||||
LEFT OUTER JOIN seg ON
|
||||
seg.glec = o.glec
|
||||
LEFT OUTER JOIN rlarp.itemm i ON
|
||||
i.item = o.part
|
||||
--LIMIT 100
|
||||
) WITH DATA;
|
||||
|
||||
--CREATE INDEX osm_qr ON rlarp.osm_pool(quota_rep_descr, bill_cust_descr, ship_cust_descr);
|
||||
--ALTER TABLE rlarp.osm_pool ADD CONSTRAINT logfk FOREIGN KEY (logid) REFERENCES rlarp.osm_log(id);
|
||||
--CREATE INDEX osm_pool_logid ON rlarp.osm_pool(logid);
|
||||
--GRANT ALL ON TABLE rlarp.osm_log TO api;
|
||||
--GRANT ALL ON TABLE rlarp.osm_pool TO api;
|
||||
|
||||
COMMIT;
|
@ -1,7 +1,7 @@
|
||||
BEGIN;
|
||||
--\timing
|
||||
--CREATE TABLE IF NOT EXISTS rlarp.osmf_stage AS (SELECT * FROM rlarp.osmf_dev) WITH no data;
|
||||
TRUNCATE TABLE rlarp.osmf_stage;
|
||||
TRUNCATE TABLE rlarp.osmf_dev;
|
||||
|
||||
DROP TABLE IF EXISTS tdr;
|
||||
CREATE TEMP TABLE tdr AS (
|
||||
@ -608,8 +608,44 @@ SELECT * FROM baseline
|
||||
,o.sseas
|
||||
--,o.version
|
||||
--,o.iter
|
||||
HAVING
|
||||
sum(o.fb_qty) <> 0
|
||||
AND sum(o.fb_val_loc) <> 0
|
||||
AND sum(o.fb_cst_loc) <> 0
|
||||
)
|
||||
INSERT INTO rlarp.osmf_stage SELECT * FROM merge_diff
|
||||
INSERT INTO rlarp.osmf_dev SELECT * FROM merge_diff;
|
||||
|
||||
|
||||
UPDATE
|
||||
rlarp.osmf_dev f
|
||||
SET
|
||||
fspr = gld.fspr
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
N1COMP COMP
|
||||
,N1CCYY FSYRq
|
||||
,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'
|
||||
) gld
|
||||
WHERE
|
||||
f.sdate BETWEEN gld.sdat AND gld.edat
|
||||
AND coalesce(f.fspr,'') <> gld.fspr;
|
||||
|
||||
COMMIT;
|
||||
|
||||
|
@ -1,8 +1,5 @@
|
||||
$PG -f build_forecast.sql
|
||||
$PG -f snap_itemm.sql
|
||||
$PG -f snap_cost_current.sql
|
||||
$PG -f snap_customer.sql
|
||||
$PG -f snap_fx.sql
|
||||
$PG -f build_pool.sql
|
||||
$PG -f convert_pool_all.sql
|
||||
$PG -c "CALL rlarp.osm_stack_refresh();"
|
||||
$PGD -f ./build_stage.sql
|
||||
$PGD -f ./snap_itemm.sql
|
||||
$PGD -f ./snap_cost_current.sql
|
||||
$PGD -f ./snap_customer.sql
|
||||
$PGD -f ./build_pool.sql
|
||||
|
Loading…
Reference in New Issue
Block a user