diff --git a/build/build_merge.sql b/build/build_merge.sql new file mode 100644 index 0000000..56604bb --- /dev/null +++ b/build/build_merge.sql @@ -0,0 +1,19 @@ +SELECT + version + ,iter + ,oseas + ,g.sspr || ' ' || to_char(odate,'Mon') omon + ,COUNT(*) cnt + ,sum(fb_val_loc * r_rate) amt +FROM + rlarp.osmf_stage o + INNER JOIN rlarp.gld g ON + o.odate <@ g.drange +GROUP BY + version + ,iter + ,oseas + ,g.sspr || ' ' || to_char(odate,'Mon') +ORDER BY + oseas + ,omon diff --git a/build/build_pool.sql b/build/build_pool.sql index 690f21b..5a58add 100644 --- a/build/build_pool.sql +++ b/build/build_pool.sql @@ -1,11 +1,8 @@ BEGIN; -DROP TABLE IF EXISTS rlarp.osm_pool; -DROP TABLE IF EXISTS rlarp.osm_log; +DROP TABLE IF EXISTS rlarp.osm_pool_stage; -CREATE TABLE IF NOT EXISTS rlarp.osm_log(id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, doc jsonb); - -CREATE TABLE IF NOT EXISTS rlarp.osm_pool AS ( +CREATE TABLE rlarp.osm_pool_stage AS ( WITH repc AS ( SELECT @@ -52,7 +49,7 @@ repc AS ( SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') <> '' ) ,logload AS ( - INSERT INTO rlarp.osm_log (doc) SELECT jsonb_build_object('user',current_user,'tag','Initial Build','type','build_pool','stamp',current_timestamp,'source','top level','message','don''t undo') RETURNING * + 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 @@ -124,11 +121,11 @@ SELECT ,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 + ,round(fb_qty,2) units + ,round(fb_val_loc,2) value_loc + ,round(fb_val_loc * r_rate,2) value_usd + ,round(fb_cst_loc_cur,2) cost_loc + ,round(fb_cst_loc_cur * c_rate,2) cost_usd ,calc_status ,flag ,o.odate order_date @@ -174,10 +171,12 @@ FROM --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; +--INSERT INTO rlarp.osm_pool SELECT * FROM rlarp.osm_pool_stage; + +--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; diff --git a/build/build_pool_schema.sql b/build/build_pool_schema.sql new file mode 100644 index 0000000..690f21b --- /dev/null +++ b/build/build_pool_schema.sql @@ -0,0 +1,183 @@ +BEGIN; + +DROP TABLE IF EXISTS rlarp.osm_pool; +DROP TABLE IF EXISTS rlarp.osm_log; + +CREATE TABLE IF NOT EXISTS rlarp.osm_log(id INT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, doc jsonb); + +CREATE TABLE IF NOT EXISTS rlarp.osm_pool 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','Initial Build','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; diff --git a/build/build_stage.sql b/build/build_stage.sql new file mode 100644 index 0000000..db18bb6 --- /dev/null +++ b/build/build_stage.sql @@ -0,0 +1,657 @@ +BEGIN; +--\timing +--CREATE TABLE IF NOT EXISTS rlarp.osmf_stage AS (SELECT * FROM rlarp.osmf_dev) WITH no data; +TRUNCATE TABLE rlarp.osmf_dev; + +DROP TABLE IF EXISTS tdr; +CREATE TEMP TABLE tdr AS ( + SELECT + DATERANGE('2020-05-01','2021-05-01','[)') drange + ,DATERANGE(('2020-05-01'::date + '1 year'::interval)::date,('2021-05-01'::date + '1 year'::interval)::date,'[)') repl + ,'1 year'::interval AS incr + ,(SELECT jsonb_agg(x.v) FROM (VALUES('copy'),('actuals'),('actuals_plug')) AS x(v)) iter +); + +WITH +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 + CROSS JOIN tdr + WHERE + N1COMP = 93 + --AND DIGITS(N1FSYP) = '1901' +) +--SELECT * FROM gld +,baseline AS ( + SELECT + -----------documents------------- + null::int "ddord#" + ,null::int "dditm#" + ,null::int "fgbol#" + ,null::int "fgent#" + ,null::int "diinv#" + ,null::int "dilin#" + ,null::int quoten + ,null::int quotel + ----------dates/status------------------ + ,o.odate dcodat + ,o.rdate ddqdat + ,null::date dcmdat + ,null::date fesdat + ,greatest(least(o.sdate,gld.edat),gld.sdat) dhidat + ,null::text fesind + ,null::text dhpost + ---for forecasting purposes there are no open orders, populate fspr---- + ,ss.fspr + -----------measures-------------------- + ,null::numeric ddqtoi + ,null::numeric ddqtsi + ,null::numeric fgqshp + ,null::numeric diqtsh + ,null::numeric diext + ,null::numeric ditdis + ,null::jsonb discj + ,null::text dhincr + ,o.plnt + ,COALESCE(o.promo,'') promo + ,null::text return_reas + ,o.terms + ,null::text custpo + ,null::text remit_to + ,null::text bill_class + ,o.bill_cust + ,null::text bill_rep + ,null::text bill_terr + ,null::text ship_class + ,o.ship_cust + ,null::text ship_rep + ,null::text ship_terr + ,o.dsm + ,null::text account + ,null::text shipgrp + ,null::text geo + ,null::text chan + ,null::text chansub + ,null::text orig_ctry + ,null::text orig_prov + ,null::text orig_post + ,null::text bill_ctry + ,null::text bill_prov + ,null::text bill_post + ,null::text dest_ctry + ,null::text dest_prov + ,null::text dest_post + ,o.part + ,null::text styc + ,null::text colc + ,null::text colgrp + ,null::text coltier + ,null::text colstat + ,null::text sizc + ,null::text pckg + ,null::text kit + ,null::text brnd + ,null::text majg + ,null::text ming + ,null::text majs + ,null::text mins + ,null::text gldco + ,null::text gldc + ,null::text glec + ,null::text harm + ,null::text clss + ,null::text brand + ,null::text assc + ,null::text ddunit + ,null::text unti + ,null::numeric lbs + ,null::numeric plt + ,null::text plcd + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,sum(o.fb_qty) fb_qty + ,sum(o.fb_val_loc) fb_val_loc + ,sum(o.fb_val_loc_dis) fb_val_loc_dis + ,sum(o.fb_val_loc_qt) fb_val_loc_qt + ,sum(o.fb_val_loc_pl) fb_val_loc_pl + ,sum(o.fb_val_loc_tar) fb_val_loc_tar + ,sum(o.fb_cst_loc) fb_cst_loc + ,sum(o.fb_cst_loc_cur) fb_cst_loc_cur + ,sum(o.fb_cst_loc_fut) fb_cst_loc_fut + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + -----when null, greatest/least is just going to act like coalesce + ,greatest(least(o.sdate,gld.edat),gld.sdat) sdate + ,ss.ssyr sseas + ,'actuals' "version" + ,'actuals' iter + FROM + rlarp.osm_dev o + --snap the ship dates of the historic fiscal period + LEFT OUTER JOIN gld ON + gld.fspr = o.fspr + --get the shipping season for open orders based on the snapped date + LEFT OUTER JOIN gld ss ON + greatest(least(o.sdate,gld.edat),gld.sdat) BETWEEN ss.sdat AND ss.edat + WHERE + ( + --base period orders booked.... + o.odate <@ (SELECT drange FROM tdr) + --...or any open orders currently booked before cutoff.... + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < (SELECT UPPER(drange) FROM tdr)) + --...or anything that shipped in that period + OR (o.sdate <@ (SELECT drange FROM tdr) AND sseas IS NOT NULL) + ) + AND fs_line = '41010' + AND calc_status <> 'CANCELED' + AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') + ---exclude integrated quotes---- + AND version = 'ACTUALS' + GROUP BY + ss.fspr + ,o.plnt + ,COALESCE(o.promo,'') + ,o.terms + ,o.bill_cust + ,o.ship_cust + ,o.dsm + ,o.part + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,greatest(least(o.sdate,gld.edat),gld.sdat) + ,ss.ssyr +) +,incr AS ( +SELECT + o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.quoten + ,o.quotel + ,o.dcodat + interval '1 year' dcodat --incremented + ,o.ddqdat + interval '1 year' ddqdat --incremented + ,o.dcmdat + ,o.fesdat + ,o.dhidat + interval '1 year' dhidat --incremented + ,o.fesind + ,o.dhpost + ,gld.fspr --incremented + ,o.ddqtoi + ,o.ddqtsi + ,o.fgqshp + ,o.diqtsh + ,o.diext + ,o.ditdis + ,o.discj + ,o.dhincr + ,o.plnt + ,o.promo + ,o.return_reas + ,o.terms + ,o.custpo + ,o.remit_to + ,o.bill_class + ,o.bill_cust + ,o.bill_rep + ,o.bill_terr + ,o.ship_class + ,o.ship_cust + ,o.ship_rep + ,o.ship_terr + ,o.dsm + ,o.account + ,o.shipgrp + ,o.geo + ,o.chan + ,o.chansub + ,o.orig_ctry + ,o.orig_prov + ,o.orig_post + ,o.bill_ctry + ,o.bill_prov + ,o.bill_post + ,o.dest_ctry + ,o.dest_prov + ,o.dest_post + ,o.part + ,o.styc + ,o.colc + ,o.colgrp + ,o.coltier + ,o.colstat + ,o.sizc + ,o.pckg + ,o.kit + ,o.brnd + ,o.majg + ,o.ming + ,o.majs + ,o.mins + ,o.gldco + ,o.gldc + ,o.glec + ,o.harm + ,o.clss + ,o.brand + ,o.assc + ,o.ddunit + ,o.unti + ,o.lbs + ,o.plt + ,o.plcd + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.fb_qty + ,o.fb_val_loc + ,o.fb_val_loc_dis + ,o.fb_val_loc_qt + ,o.fb_val_loc_pl + ,o.fb_val_loc_tar + ,o.fb_cst_loc + ,o.fb_cst_loc_cur + ,o.fb_cst_loc_fut + ,o.calc_status + ,o.flag + ,(o.odate + interval '1 year')::date odate --incremented + ,o.oseas + 1 oseas --incremented + ,(o.rdate + interval '1 year')::date rdate --incremented + ,o.rseas + 1 rseas --incremented + ,(o.sdate + interval '1 year')::date sdate --incremented + ,o.sseas + 1 sseas --incremented + ,'b22' "version" + ,'copy' iter +FROM + baseline o + LEFT OUTER JOIN gld ON + o.sdate + interval '1 year' BETWEEN gld.sdat and gld.edat +WHERE + o.odate + interval '1 year' >= (SELECT LOWER(drange) + INTERVAL '1 year' FROM tdr) +) +,stage AS ( +SELECT * FROM incr +UNION ALL +SELECT * FROM baseline +) +,remove AS ( + SELECT + -----------documents------------- + null::int "ddord#" + ,null::int "dditm#" + ,null::int "fgbol#" + ,null::int "fgent#" + ,null::int "diinv#" + ,null::int "dilin#" + ,null::int quoten + ,null::int quotel + ----------dates/status------------------ + ,o.odate dcodat + ,o.rdate ddqdat + ,null::date dcmdat + ,null::date fesdat + ,o.dhidat + ,null::text fesind + ,null::text dhpost + ,o.fspr + -----------measures-------------------- + ,null::numeric ddqtoi + ,null::numeric ddqtsi + ,null::numeric fgqshp + ,null::numeric diqtsh + ,null::numeric diext + ,null::numeric ditdis + ,null::jsonb discj + ,null::text dhincr + ,o.plnt + ,o.promo + ,o.return_reas + ,o.terms + ,null::text custpo + ,null::text remit_to + ,null::text bill_class + ,o.bill_cust + ,null::text bill_rep + ,null::text bill_terr + ,null::text ship_class + ,o.ship_cust + ,null::text ship_rep + ,null::text ship_terr + ,o.dsm + ,null::text account + ,null::text shipgrp + ,null::text geo + ,null::text chan + ,null::text chansub + ,null::text orig_ctry + ,null::text orig_prov + ,null::text orig_post + ,null::text bill_ctry + ,null::text bill_prov + ,null::text bill_post + ,null::text dest_ctry + ,null::text dest_prov + ,null::text dest_post + ,o.part + ,null::text styc + ,null::text colc + ,null::text colgrp + ,null::text coltier + ,null::text colstat + ,null::text sizc + ,null::text pckg + ,null::text kit + ,null::text brnd + ,null::text majg + ,null::text ming + ,null::text majs + ,null::text mins + ,null::text gldco + ,null::text gldc + ,null::text glec + ,null::text harm + ,null::text clss + ,null::text brand + ,null::text assc + ,null::text ddunit + ,null::text unti + ,null::numeric lbs + ,null::numeric plt + ,null::text plcd + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,-sum(o.fb_qty) fb_qty + ,-sum(o.fb_val_loc) fb_val_loc + ,-sum(o.fb_val_loc_dis) fb_val_loc_dis + ,-sum(o.fb_val_loc_qt) fb_val_loc_qt + ,-sum(o.fb_val_loc_pl) fb_val_loc_pl + ,-sum(o.fb_val_loc_tar) fb_val_loc_tar + ,-sum(o.fb_cst_loc) fb_cst_loc + ,-sum(o.fb_cst_loc_cur) fb_cst_loc_cur + ,-sum(o.fb_cst_loc_fut) fb_cst_loc_fut + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + -----when null, greatest/least is just going to act like coalesce + ,o.sdate + ,o.sseas + ,o.version + ,o.iter + FROM + rlarp.osmfs_dev o + CROSS JOIN tdr + WHERE + --collect all the rows in the base period and + --the destination slot for the new rows + ( + o.odate <@ tdr.drange + OR o.odate <@ tdr.repl + ) + ---only merge with targeted iterations + AND tdr.iter ? o.iter + GROUP BY + o.odate + ,o.rdate + ,o.dhidat + ,o.fspr + ,o.plnt + ,o.promo + ,o.return_reas + ,o.terms + ,o.bill_cust + ,o.ship_cust + ,o.dsm + ,o.part + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,o.sdate + ,o.sseas + ,o.version + ,o.iter +) +,stack AS ( + SELECT * FROM stage + UNION ALL + SELECT * FROM remove +) +,merge_diff AS ( + SELECT + -----------documents------------- + null::int "ddord#" + ,null::int "dditm#" + ,null::int "fgbol#" + ,null::int "fgent#" + ,null::int "diinv#" + ,null::int "dilin#" + ,null::int quoten + ,null::int quotel + ----------dates/status------------------ + ,o.odate dcodat + ,o.rdate ddqdat + ,null::date dcmdat + ,null::date fesdat + ,o.dhidat + ,null::text fesind + ,null::text dhpost + ,o.fspr + -----------measures-------------------- + ,null::numeric ddqtoi + ,null::numeric ddqtsi + ,null::numeric fgqshp + ,null::numeric diqtsh + ,null::numeric diext + ,null::numeric ditdis + ,null::jsonb discj + ,null::text dhincr + ,o.plnt + ,o.promo + ,o.return_reas + ,o.terms + ,null::text custpo + ,null::text remit_to + ,null::text bill_class + ,o.bill_cust + ,null::text bill_rep + ,null::text bill_terr + ,null::text ship_class + ,o.ship_cust + ,null::text ship_rep + ,null::text ship_terr + ,o.dsm + ,null::text account + ,null::text shipgrp + ,null::text geo + ,null::text chan + ,null::text chansub + ,null::text orig_ctry + ,null::text orig_prov + ,null::text orig_post + ,null::text bill_ctry + ,null::text bill_prov + ,null::text bill_post + ,null::text dest_ctry + ,null::text dest_prov + ,null::text dest_post + ,o.part + ,null::text styc + ,null::text colc + ,null::text colgrp + ,null::text coltier + ,null::text colstat + ,null::text sizc + ,null::text pckg + ,null::text kit + ,null::text brnd + ,null::text majg + ,null::text ming + ,null::text majs + ,null::text mins + ,null::text gldco + ,null::text gldc + ,null::text glec + ,null::text harm + ,null::text clss + ,null::text brand + ,null::text assc + ,null::text ddunit + ,null::text unti + ,null::numeric lbs + ,null::numeric plt + ,null::text plcd + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,round(sum(o.fb_qty),2) fb_qty + ,round(sum(o.fb_val_loc),2) fb_val_loc + ,sum(o.fb_val_loc_dis) fb_val_loc_dis + ,sum(o.fb_val_loc_qt) fb_val_loc_qt + ,sum(o.fb_val_loc_pl) fb_val_loc_pl + ,sum(o.fb_val_loc_tar) fb_val_loc_tar + ,round(sum(o.fb_cst_loc),2) fb_cst_loc + ,sum(o.fb_cst_loc_cur) fb_cst_loc_cur + ,sum(o.fb_cst_loc_fut) fb_cst_loc_fut + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,o.sdate + ,o.sseas + --,o.version + --,o.iter + ,'actuals' AS version + ,'copy' iter + FROM + stack o + WHERE + --collect all the rows in the base period and + --the destination slot for the new rows + o.odate <@ (SELECT tdr.drange FROM tdr) + OR o.odate <@ (SELECT tdr.repl FROM tdr) + GROUP BY + o.dhidat + ,o.fspr + ,o.plnt + ,o.promo + ,o.return_reas + ,o.terms + ,o.bill_cust + ,o.ship_cust + ,o.dsm + ,o.part + ,o.fs_line + ,o.r_currency + ,o.r_rate + ,o.c_currency + ,o.c_rate + ,o.calc_status + ,o.flag + ,o.odate + ,o.oseas + ,o.rdate + ,o.rseas + ,o.sdate + ,o.sseas + --,o.version + --,o.iter + HAVING + round(sum(o.fb_qty),2) <> 0 + OR round(sum(o.fb_val_loc),2) <> 0 + --OR round(sum(o.fb_cst_loc),2) <> 0 +) +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; + +END + +---identify short ships: causes disconnect with actual sales------------------------------------------------------------------- +--UPDATE rlarp.osmfs SET iter = 'short ship' WHERE calc_status = 'CLOSED' AND flag = 'REMAINDER'; + +---identify goofy ship dates: causes disconnect with sales when splicing in a forecast that has this problem------------------- +--UPDATE rlarp.osmfs SET iter = 'bad date' WHERE adj_shipdate < adj_orderdate; diff --git a/build/convert_pool_all.sql b/build/convert_pool_all.sql index 95df7af..dc8fa78 100644 --- a/build/convert_pool_all.sql +++ b/build/convert_pool_all.sql @@ -118,7 +118,8 @@ FROM UPDATE RLARP.OSMFS_DEV O SET - COLC = M.COLC + STYC = M.STLC + ,COLC = M.COLC ,COLGRP = M.COLGRP ,COLTIER = M.COLTIER ,COLSTAT = M.COLSTAT diff --git a/build/merge_actuals_exec.sql b/build/merge_actuals_exec.sql index f263fae..891d662 100644 --- a/build/merge_actuals_exec.sql +++ b/build/merge_actuals_exec.sql @@ -1,3 +1,3 @@ -DELETE FROM rlarp.osmf_dev WHERE odate < '2020-06-01'; -INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev WHERE odate < '2020-06-01'; +DELETE FROM rlarp.osmf_dev WHERE odate < '2021-05-01'; +INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev WHERE odate < '2021-05-01'; diff --git a/build/merge_actuals_pool.sql b/build/merge_actuals_pool.sql index d57a96b..a37b194 100644 --- a/build/merge_actuals_pool.sql +++ b/build/merge_actuals_pool.sql @@ -1,6 +1,6 @@ BEGIN; -DELETE FROM rlarp.osm_pool WHERE order_date < '2020-06-01'; +DELETE FROM rlarp.osm_pool WHERE order_date < '2021-05-01'; INSERT INTO rlarp.osm_pool WITH @@ -135,7 +135,7 @@ FROM LEFT OUTER JOIN rlarp.itemm i ON i.item = o.part WHERE - odate < '2020-06-01'; + odate < '2021-05-01'; SELECT diff --git a/build/merge_actuals_prep.sql b/build/merge_actuals_prep.sql index dbc4343..a15580f 100644 --- a/build/merge_actuals_prep.sql +++ b/build/merge_actuals_prep.sql @@ -145,11 +145,11 @@ gld AS ( WHERE ( --base period orders booked.... - o.odate <@ daterange('2019-06-01','2020-06-01') + o.odate <@ daterange('2020-06-01','2021-05-01','[)') --...or any open orders currently booked before cutoff.... - OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2020-06-01') + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2021-05-01') --...or anything that shipped in that period - OR o.fspr BETWEEN '2001' AND '2012' + OR o.fspr BETWEEN '2101' AND '2111' ) AND fs_line = '41010' AND calc_status <> 'CANCELED' diff --git a/build/readme.md b/build/readme.md index 9a4193d..3e3a2f9 100644 --- a/build/readme.md +++ b/build/readme.md @@ -11,3 +11,10 @@ Build A New Forecast * build the pool for the more limited UI data set: build_pool.sql * copy the pool to osmfs_dev from inclusion in the osm_stack and reporting: convert_pool_all.sql * refresh osm_stack_refresh() to integrate into reporting + +Integrate Actuals +------------------------------------------------------------------------------------------------------------------ + +* `merge_actuals_prep` -> push a fresh baseline into a temp table +* `merge_actuals_exec` -> take the baseline and push it into `osmf` +* `merge_actuals_exec` -> manualls splice in `osmf` into `pool` diff --git a/build/rebuild_forecast.sh b/build/rebuild_forecast.sh index 16fbcd7..3bb1b33 100644 --- a/build/rebuild_forecast.sh +++ b/build/rebuild_forecast.sh @@ -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();" +$PG -f ./build_stage.sql +$PG -f ./snap_itemm.sql +$PG -f ./snap_cost_current.sql +$PG -f ./snap_customer.sql +$PG -f ./build_pool.sql diff --git a/build/snap_cust_pool.sql b/build/snap_cust_pool.sql index 937692b..fcfa67a 100644 --- a/build/snap_cust_pool.sql +++ b/build/snap_cust_pool.sql @@ -50,10 +50,13 @@ UPDATE rlarp.osm_pool o SET quota_rep_descr = (regexp_match(r.repp,'.* - (.*)$'))[1] + ,director = r.director FROM rlarp.repc r WHERE r.rcode = o.dsm - AND quota_rep_descr <> (regexp_match(r.repp,'.* - (.*)$'))[1]; - + AND ( + quota_rep_descr <> (regexp_match(r.repp,'.* - (.*)$'))[1] + OR o.director <> r.director + ); COMMIT; diff --git a/build/snap_itemm_pool.sql b/build/snap_itemm_pool.sql index 92723cb..a4db87f 100644 --- a/build/snap_itemm_pool.sql +++ b/build/snap_itemm_pool.sql @@ -39,7 +39,7 @@ SELECT DISTINCT ,CASE WHEN i.majg = '610' THEN 'Fiber' ELSE 'Plastic' END substance FROM rlarp.osm_pool o - LEFT OUTER JOIN rlarp.itemm i ON + LEFT OUTER JOIN rlarp.itemmv i ON i.item = o.part LEFT OUTER JOIN seg ON seg.glec = i.glec diff --git a/build/tots.sql b/build/tots.sql index 4300e0c..5352f7f 100644 --- a/build/tots.sql +++ b/build/tots.sql @@ -5,7 +5,7 @@ SELECT iter, sum(fb_val_loc) value_loc FROM - rlarp.osmfs_dev o + rlarp.osmf_stage o GROUP BY oseas, 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'), diff --git a/offline/account_plug.sql b/offline/account_plug.sql new file mode 100644 index 0000000..d964266 --- /dev/null +++ b/offline/account_plug.sql @@ -0,0 +1,362 @@ +BEGIN; + +WITH +targ AS ( + SELECT + account + ,segment + ,targv::numeric targv + ,targm::numeric targm + ,targv::numeric - targm::numeric targc + FROM (VALUES + ('THE HOME DEPOT','17000000','3074775','Retail'), + ('L&L NURSERY SUPPLY INC','2350000','1323646','Retail'), + ('WAL-MART','0','0','Retail'), + ('FRED MEYER','2000000','856002','Retail'), + ('AMAZON.COM','1640000','1030332','Retail'), + ('BFG SUPPLY','1500000','836573','Retail'), + ('MENARDS','1638401','608147','Retail'), + ('ARETT SALES','1241808','664301','Retail'), + ('VM INNOVATIONS-NE','1000000','550614','Retail'), + ('CANADIAN TIRE CORP LTD','680606','47642','Retail'), + ('CANADIAN TIRE CORP LTD','319394','160394','Sustainable'), + ('ALLIANCE INTERNATIONAL LLC','500000','206602','Retail'), + ('OCEAN STATE JOBBERS','300000','155878','Retail'), + ('GRIFFIN','258240','118623','Retail'), + ('DO IT BEST','297067','177889','Retail'), + ('BWI','249061','117374','Retail'), + ('BRADLEY CALDWELL INC','226211','134560','Retail'), + ('PHILLIPS PET FOOD & SUPPLIES','194414','113853','Retail'), + ('ACE HARDWARE','195043','128460','Retail'), + ('EDDIS WHOLESALE GDN SUPPLIES','156305','76972','Retail'), + ('GARD N WISE','154657','83291','Retail'), + ('FOSTERS INC','154278','84043','Retail'), + ('GARDEN CENTRE GROUP CO-OP','148400','79640','Retail'), + ('TRUE VALUE','125272','66837','Retail'), + ('RONA INC (PICK UP)ACE CANADA','125154','49123','Retail'), + ('HB DAVIS SEED CO','103990','60800','Retail'), + ('BOMGAARS SUPPLY INC. RETAIL','96550','55201','Retail'), + ('CANAC MARQUIS GRENIER','84336','26284','Retail'), + ('LOWES','82640','33445','Retail'), + ('JENSEN DISTRIBUTION','79189','47567','Retail'), + ('EARL MAY SEED','77321','45084','Retail'), + ('INTERMOUNTAIN FARMERS ASSN','71161','25896','Retail'), + ('PEAVEY INDUSTRIES LP RET','63755','38070','Retail'), + ('SRC CORPORATION','62610','34107','Retail'), + ('HORIZON DISTRIBUTION INC','52200','29953','Retail'), + ('HALIFAX SEED CO INC','47859','23365','Retail'), + ('JAVIC STEIN GARDEN CENTER RET','47332','29831','Retail'), + ('TERIS SUPPLY SERVICES','46454','21876','Retail'), + ('LITTLE MOUNTAIN GREENHOUSES','0','0','Retail'), + ('WYATT QUARLES','45961','19806','Retail'), + ('KROGER ACCOUNTING SERVICES','0','0','Retail'), + ('AURORA WHOLESALERS, LLC','39005','1950','Retail'), + ('CIMARRON LUMBER CO','41255','29321','Retail'), + ('SKH WHOLESALE DIST','39498','22002','Retail'), + ('GREENHOUSE MEGASTORE','38481','22165','Retail'), + ('MEYER SEED CO.OF BALTIMORE INC','36907','21255','Retail'), + ('GREEN ISLAND DISTRIBUTORS INC.','36335','16598','Retail'), + ('ALASKA GDN & PET SUPPLY RET','34416','17673','Retail'), + ('CY GROWERS SUPPLIES LTD','33516','17268','Retail'), + ('PL ROHRER & BRO INC RET','32682','18721','Retail'), + ('CISCO COMPANIES (THE)','31294','16958','Retail'), + ('EXACTA SALES','29985','16997','Retail'), + ('CARLIN HORTICULTURAL SUPP','29766','17926','Retail'), + ('LEON KOROL COMPANY','27634','-20540','Retail'), + ('FAMILY TREE NURSERY','26732','14253','Retail'), + ('GREENHOUSE & GARDEN SUPPLY INC','28432','16180','Retail'), + ('MIKES GARDEN CENTER','24804','8682','Retail'), + ('HORTMARK','24148','14260','Retail'), + ('FLORIDA HARDWARE COMPANY','22952','13416','Retail'), + ('EARL''S FARM & GARDEN INC','20856','11680','Retail'), + ('MIZE FARM & GARDEN SUPPLY','20317','11079','Retail'), + ('HUMMERT INTERNATIONAL','19214','10602','Retail'), + ('BAYERS GARDEN SHOP','18177','11247','Retail'), + ('FEDERATED CO-OPERATIVES LTD','16347','9370','Retail'), + ('VANDENBERG BULB CO INC','15895','8533','Retail'), + ('RS GROWERS SUPPLY','15676','8691','Retail'), + ('PLANTERS SEED & SPICE RET','15395','8520','Retail'), + ('UNITED GARDEN CENTER','15303','8117','Retail'), + ('NORTH 40 OUTFITTERS','13975','9093','Retail'), + ('ERVA TOOL & DIE CO','13102','10114','Retail'), + ('NITRO-PHOS FERTILIZERS','12772','7397','Retail'), + ('OTTEN BROS','12390','6556','Retail'), + ('GROSOUTH','12229','5783','Retail'), + ('WAYFAIR LLC','10894','6861','Retail'), + ('PRINCE CORPORATION','10627','6478','Retail'), + ('BLISH-MIZE CO','10502','6181','Retail'), + ('UNITED GARDEN CENTERS RET','10323','5880','Retail'), + ('KC SCHAEFER SUPPLY','10176','5658','Retail'), + ('LIFOAM INDUSTRIES LLC','9922','1437','Retail'), + ('CARL BREHOB & SON','9909','4862','Retail'), + ('GPF CORPORATION','8497','4907','Retail'), + ('APACHE SEEDS LTD','7524','4823','Retail'), + ('PRO GROWER SUPPLY','7160','4488','Retail'), + ('ALTON GREENHOUSES','6282','4571','Retail'), + ('VG SUPPLY CO INC','6170','3302','Retail'), + ('PATRICK MORIN','5550','4185','Retail'), + ('PROFESSIONAL GARDENER CO','5534','3780','Retail'), + ('PREMIUM HORTICULTURAL SUPPLY','5260','2953','Retail'), + ('SCHROTH WHOLESALE SUPPLY CO.','4886','2841','Retail'), + ('WALDO & ASSOCIATES','4848','2662','Retail'), + ('SERRES STE-ELIE','4554','2217','Retail'), + ('JEAN H HENLE INC RET','4390','2596','Retail'), + ('GOLDCREST DIST','4203','2652','Retail'), + ('KEN VAN WINGERDEN GREENHOUSES','3934','2721','Retail'), + ('PASTANCH LLC','3558','2300','Retail'), + ('TESSMAN SEED','3490','1837','Retail'), + ('GEMMELLS GARDEN CENTRE INC','3356','2459','Retail'), + ('BELLE INVESTMENTS INC','2969','1901','Retail'), + ('BLUE STAR WHOLESALE','2870','1321','Retail'), + ('GLEN ECHO NURSERIES INC','2856','1358','Retail'), + ('Distribution','2856','1000','Retail'), + ('EZ GRO GARDEN','2770','970','Retail'), + ('ENVIROGREENERY PLANTS LLC','2759','1546','Retail'), + ('GERTENS GREENHOUSE','2669','934','Retail'), + ('KROGER (KRG LLC)','2363','1074','Retail'), + ('CINNABAR VALLEY','1873','1210','Retail'), + ('EDWARDS GREENHOUSE INC','1842','1179','Retail'), + ('DIRECT DISTRIBUTORS INC','1732','1140','Retail'), + ('YODERS PRODUCE','1295','514','Retail'), + ('ABC NURSERY LANDSCAPEMAIN','556','305','Retail'), + ('DUNN SALES & MARKETING, INC.','385','197','Retail'), + ('GARDENERS SUPPLY CO','375','263','Retail'), + ('FARMERS COOP','355','135','Retail'), + ('CROP PROD SERVICES INC','351','199','Retail'), + ('ARNOLDS GREENHOUSES','309','249','Retail'), + ('GEORGE''S FLOWERS','287','132','Retail'), + ('HJS WHOLESALE LTD','162','117','Retail'), + ('HOLMBERG FARMS INC','101','72','Retail'), + ('KINNEY BONDED','93','49','Retail'), + ('IRRIGATION PLUS INC','35','21','Retail'), + ('GLENKIRK ASSOCIATES INC','0','0','Retail'), + ('MILITARY PRODUCE GROUP LLC','0','0','Retail'), + ('WONDER SOIL','0','0','Retail'), + ('CHUCK BECK','0','0','Retail'), + ('MENARDS INC STORE 3256 RET','0','0','Retail'), + ('GREENSTAR PLANT-MANCHESTER','0','0','Retail'), + ('MAIN LINE POTTERY','0','0','Retail'), + ('PSR SALES INC','0','0','Retail'), + ('CLEVELAND FLORAL PRODUCTS INC','0','0','Retail'), + ('RACHEL BOWMAN','0','0','Retail'), + ('ENG SVCS & PROD','0','0','Retail'), + ('RITCHIE FEED & SEED','0','0','Retail'), + ('PARK SEED (DBA JPPA)','0','0','Retail'), + ('ART KNAPP','0','0','Retail'), + ('VARIETY WHOLESALE (9001)','0','0','Retail'), + ('ROY SIEMENS','0','0','Retail'), + ('MARC DESROSIERS','0','0','Retail'), + ('JIM REGER','0','0','Retail'), + ('MARK WILKINSON','0','0','Retail'), + ('SAN MARCOS GROWERS','0','0','Retail'), + ('GRANBYS GREENHOUSE','0','0','Retail'), + ('GIANT TIGERE STORES LIMITED','0','0','Retail'), + ('INTEGRITY SALES & DISTRIBUTION','0','0','Retail'), + ('GLOECKNER & CO. INC.','0','0','Retail'), + ('DORAN MARABLE','0','0','Retail'), + ('SEVEN OAKS PLANT SHOP INC','0','0','Retail'), + ('BURPEE GARDEN PRODUCTS RET','0','0','Retail'), + ('SHERRILL INC','0','0','Retail'), + ('PARKWAY GARDENS','0','0','Retail'), + ('GS DISTRIBUTION','0','0','Retail'), + ('GALES GARDEN CENTER','0','0','Retail'), + ('DAVE BODO','0','0','Retail'), + ('FLOWERLAND GARDEN CTR OF CLEVE','0','0','Retail'), + ('STACK-A-POTS','0','0','Retail'), + ('BEAUTIFUL LAND PRODUCTS','0','0','Retail'), + ('STRADERS','0','0','Retail'), + ('WESTLAND GREENHOUSES','0','0','Retail'), + ('SUNNYSIDE GREENHOUSES LTD. RET','0','0','Retail'), + ('DM COLOR EXPRESS','0','0','Retail'), + ('TERIS SVSC D''''APPROVISIONNEMNT','0','0','Retail'), + ('YONAS GREENHOUSES','0','0','Retail'), + ('FLORALIES JOUVENCE','0','0','Retail'), + ('ALECIA LATINI','0','0','Retail'), + ('AL PAR PEAT CO','0','0','Retail'), + ('IVAN VANDERDEEN','0','0','Retail'), + ('TIDBURY CREEK FARMS','0','0','Retail'), + ('AGRO PRODUCTS LIMITED','0','0','Retail'), + ('ALDI','0','0','Retail'), + ('MISC ACCT - (US )','0','0','Retail'), + ('TIMBERS MARKETING LLC','0','0','Retail'), + ('ALLEN STERLING AND LOTHROP','0','0','Retail'), + ('TINA PETTIGREW','0','0','Retail'), + ('TONY LANDINO','0','0','Retail'), + ('TRICIA PRICE','0','0','Retail'), + ('PEAK DISTRIBUTION LLC','0','0','Retail'), + ('DILLON SEED & SUPPLY','0','0','Retail'), + ('MENARDS INC STORE 3510 RET','0','0','Retail'), + ('PLANT BEST','0','0','Retail'), + ('DENVER WHOLESALE FLORISTS CO','0','0','Retail'), + ('TSC STORES LIMITED','0','0','Retail'), + ('CENTRAL GARDEN & PET','0','0','Retail'), + ('ESERRO','0','0','Retail'), + ('AMA PLASTICS','0','0','Retail'), + ('LITTLE MOUNTAIN GREENHOUSES U','0','0','Retail'), + ('PATAPSCO VALLEY SALES','0','0','Retail'), + ('UNITED HARDWARE','0','0','Retail'), + ('COLOUR PARADISE GRHS LTD','0','0','Retail'), + ('GARDEN RIDGE CORP','0','0','Retail'), + ('VARIETY DISTRIBUTORS INC','0','0','Retail'), + ('BLUE WATER BALTIMORE','0','0','Retail'), + ('LEE VALLEY TOOLS','0','0','Retail') + ) x(account,targv,targm,segment) +) +,factor AS ( +SELECT + account + ,segment + ,targv + ,targm + ,targc + ,sum(value_usd) value_usd + ,sum(units) units + ,sum(cost_usd) cost_usd + ,round(CASE WHEN sum(value_usd) = 0 THEN 0 ELSE targv::numeric/sum(value_usd) END,5) vfactor + ,round(CASE WHEN sum(cost_usd) = 0 THEN 0 ELSE targc::numeric/sum(cost_usd) END,5) cfactor +FROM + targ t + LEFT OUTER JOIN rlarp.osm_pool o ON + o.billto_group = t.account + AND o.segm = t.segment + AND o.order_season = 2022 +GROUP BY + account + ,segment + ,targv + ,targm + ,targc +) +--SELECT * FROM agg_curr +----------------create a log entry-------------------- +,log AS ( + INSERT INTO + rlarp.osm_log(doc) + SELECT + $${ + "message":"force accounts to match target total value and margin", + "tag":"retail plug", + "type":"build" + }$$::jsonb doc + RETURNING * +) +-------build adjustment rows collapsed for all iterations---------- +,dv AS ( + SELECT + o.fspr + ,o.plnt ---master data + ,o.promo --history date mix + ,o.terms + ,o.bill_cust_descr --history cust mix + ,o.ship_cust_descr --history cust mix + ,o.dsm + ,o.quota_rep_descr --master data + ,o.director + ,o.billto_group --master data + ,o.shipto_group + ,o.chan --master data + ,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 --master data + ,o.r_currency --history cust mix + ,o.r_rate --master data + ,o.c_currency --master data + ,o.c_rate --master data + ,round(sum(o.units*s.cfactor - o.units ),2) units + ,round(sum(o.value_loc*s.vfactor - o.value_loc ),2) value_loc + ,round(sum(o.value_usd*s.vfactor - o.value_usd ),2) value_usd + ,round(sum(o.cost_loc*s.cfactor - o.cost_loc ),2) cost_loc + ,round(sum(o.cost_usd*s.cfactor - o.cost_usd ),2) cost_usd + ,o.calc_status --0 + ,o.flag --0 + ,o.order_date --history date mix + ,o.order_month + ,o.order_season + ,o.request_date --history date mix + ,o.request_month + ,o.request_season + ,o.ship_date --history date mix + ,o.ship_month + ,o.ship_season + ,'b22' aS version + ,'upload volume' iter + ,log.id + ,coalescE(log.doc->>'tag','') AS "tag" + ,log.doc->>'message' AS "comment" + ,log.doc->>'type' module + FROM + rlarp.osm_pool o + INNER JOIN factor s ON + s.account = o.billto_group + CROSS JOIN log + WHERE + o.order_season = 2022 + AND o.segm = s.segment + GROUP BY + o.fspr + ,o.plnt ---master data + ,o.promo --history date mix + ,o.terms + ,o.bill_cust_descr --history cust mix + ,o.ship_cust_descr --history cust mix + ,o.dsm + ,o.quota_rep_descr --master data + ,o.director + ,o.billto_group --master data + ,o.shipto_group + ,o.chan --master data + ,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 --master data + ,o.r_currency --history cust mix + ,o.r_rate --master data + ,o.c_currency --master data + ,o.c_rate --master data + ,o.calc_status --0 + ,o.flag --0 + ,o.order_date --history date mix + ,o.order_month + ,o.order_season + ,o.request_date --history date mix + ,o.request_month + ,o.request_season + ,o.ship_date --history date mix + ,o.ship_month + ,o.ship_season + ,log.id + ,coalescE(log.doc->>'tag','') + ,log.doc->>'message' + ,log.doc->>'type' +) +INSERT INTO rlarp.osm_pool SELECT * FROM dv; +--SELECT +-- billto_group +-- ,sum(value_usd) val +-- ,sum(cost_usd) AS cost +-- ,sum(units) units +--FROM +-- dv +--GROUP BY +-- billto_group + +COMMIT; diff --git a/offline/last_price.sql b/offline/last_price.sql index 74f8352..8379d7a 100644 --- a/offline/last_price.sql +++ b/offline/last_price.sql @@ -1,39 +1,39 @@ ---BEGIN; +BEGIN; WITH ------------------goal price increases--------------------- incr AS ( SELECT * FROM (VALUES - ('110','PP','B',0.25), - ('110','PP','T',0.25), + ('110','PP','B',0.3), + ('110','PP','T',0.3), ('110','PP','L',0.4), ('110','PP','M',0.4), ('110','PP','P',0.4), ('110','PP','C',0.4), - ('210','PE','B',0.25), - ('210','PE','T',0.25), - ('210','PE','L',0.25), - ('210','PE','M',0.25), - ('210','PE','P',0.25), - ('210','PE','C',0.25), - ('310','PE','B',0.15), - ('310','PE','T',0.25), - ('310','PE','L',0.25), - ('310','PE','M',0.25), - ('310','PE','P',0.25), - ('310','PE','C',0.25), - ('310','PP','B',0.13), - ('310','PP','T',0.16), - ('310','PP','L',0.16), - ('310','PP','M',0.16), - ('310','PP','P',0.16), - ('310','PP','C',0.16), - ('310','PS','B',0.13), - ('310','PS','T',0.16), - ('310','PS','L',0.16), - ('310','PS','M',0.16), - ('310','PS','P',0.16), - ('310','PS','C',0.16), + ('210','PE','B',0.3), + ('210','PE','T',0.3), + ('210','PE','L',0.3), + ('210','PE','M',0.3), + ('210','PE','P',0.3), + ('210','PE','C',0.3), + ('310','PE','B',0.25), + ('310','PE','T',0.3), + ('310','PE','L',0.3), + ('310','PE','M',0.3), + ('310','PE','P',0.3), + ('310','PE','C',0.3), + ('310','PP','B',0.25), + ('310','PP','T',0.25), + ('310','PP','L',0.25), + ('310','PP','M',0.25), + ('310','PP','P',0.25), + ('310','PP','C',0.25), + ('310','PS','B',0.25), + ('310','PS','T',0.25), + ('310','PS','L',0.25), + ('310','PS','M',0.25), + ('310','PS','P',0.25), + ('310','PS','C',0.25), ('320','PE','B',0.25), ('320','PE','T',0.25), ('320','PE','L',0.25), @@ -46,21 +46,13 @@ incr AS ( ('320','PP','M',0.25), ('320','PP','P',0.25), ('320','PP','C',0.25), - ('910','PE','B',0.15), + ('910','PE','B',0.25), ('910','PE','D',0.25), ('910','PE','F',0.25), - ('910','PP','B',0.15), + ('910','PP','B',0.25), ('910','PP','D',0.25), ('910','PP','F',0.25), - ('910','PS','B',0.15), - ('910','','B',0.15), - ('910','','D',0.25), - ('910','','F',0.25), - ('910','','T',0.25), - ('910','','L',0.25), - ('910','','M',0.25), - ('910','','P',0.25), - ('910','','C',0.25), + ('910','PS','B',0.25), ('910','PS','D',0.25), ('910','PS','F',0.25), ('610','','B',0.02), @@ -68,10 +60,71 @@ incr AS ( ('610','','W',0.02) ) x(MAJG,ASSC,COLTIER,RATE) ) +,chx AS ( + SELECT * FROM ( VALUES + ('DIRECT','DIR','Direct'), + ('DISTRIB DROP SHIP','DRP','Drop'), + ('DISTRIBUTOR','WHS','Warehouse') + ) x(xchan, chan, tchan) +) +,ds AS ( + SELECT * FROM ( VALUES + ('B','X','BASE','Base',''), + ('B','L','BASE LABELED','Base','L'), + ('B','P','BASE PRINTED','Base','P'), + ('C','X','COLOR','Color',''), + ('C','L','COLOR LABELED','Color','L'), + ('C','P','COLOR PRINTED','Color','P') + ) x(colgrp, brand, dataseg, tcol, tbrand) +) +---customer dba assigned price levels--------- +,dbap AS ( + SELECT + dba + ,jsonb_agg(DISTINCT plevel) plev + ,jsonb_agg(DISTINCT plcd) plist + FROM + rlarp.cust c + INNER JOIN rlarp.sachdef sd ON + sd.plev = c.plevel + AND '2020-05-31' between sd.fdate AND sd.tdate + WHERE + pricing <> '' + AND dba <> '' + GROUP BY + dba +) +----customer dba price list pricing------ +,plist AS ( + SELECT + dbap.dba + ,dbap.plev + ,dbap.plist + ,jcplcd + ,jcpart + ,jcunit + --,jcvoll + -----just use the lowest volume price for the part----- + ,min(jcpric) jcpric + FROM + dbap + INNER JOIN lgdat.iprcc cc ON + dbap.plist ? cc.jcplcd + WHERE + jcunit = 'M' + GROUP BY + dbap.dba + ,dbap.plev + ,dbap.plist + ,jcplcd + ,jcpart + ,jcunit +) ------------carve out pricing baseline data-------------------- ,p AS ( SELECT o.part + ,o.styc||'.'||o.coltier||substring(o.sizc,1,3) productt ,o.styc||'.'||o.colgrp||substring(o.sizc,1,3) product ,o.glec ,o.styc @@ -82,6 +135,7 @@ incr AS ( ,o.sizc ,i.suffix ,substring(o.chan,1,1) chgrp + ,o.chan ,o.account ,o.shipgrp ,o.fb_qty units @@ -127,7 +181,7 @@ incr AS ( ,o.shipgrp ,o.odate DESC ) ---SELECT * FROM p WHERE account ~ 'ACOSTA' +--SELECT * FROM p WHERE account ~ 'AMA P' and product = 'AMK06000.CBXX' order by rn ASC ------------build global py asp------------------ ,baseline AS ( SELECT @@ -136,6 +190,7 @@ incr AS ( ,assc ,chgrp ,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_gasp + ,round(sum(val_usd) FILTER (WHERE oseas = 2021)/sum(units) FILTER (WHERE oseas = 2021),5) cy_gasp FROM p GROUP BY @@ -144,130 +199,22 @@ incr AS ( ,assc ,chgrp ) -----------pivot the pricing out into columns per customer/product-------- -,pivot AS ( -SELECT - p.product - ,p.styc - ,p.glec - ,p.majg - ,p.assc - ,p.colgrp - ,p.coltier - ,p.sizc - ,p.suffix - ,p.chgrp - ,p.account - ,p.shipgrp - ,bl.py_gasp - ,sum(units) FILTER (WHERE oseas = 2021) cy_units - ,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp - ,round(avg(price) FILTER (WHERE rn = 1),5) last_price - ,max(odate) FILTER (WHERE rn = 1) last_order - ,CASE p.chgrp - WHEN 'D' THEN i.rate - ELSE CASE p.majg - WHEN '610' THEN .02 - ElSE CASE p.colgrp - WHEN 'B' THEN .1 - WHEN 'C' THEN .15 - ELSE 1 - END - END - END rate - ,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL - THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL - THEN 'unknown' - ELSE 'new' - END - ELSE CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL - THEN 'lost' - ELSE 'repeat' - END - END flag -FROM - p - LEFT OUTER JOIN baseline bl ON - bl.product = p.product - AND bl.majg = p.majg - AND bl.assc = p.assc - AND bl.chgrp = p.chgrp - LEFT OUTER JOIN incr i ON - i.majg = p.majg - AND i.assc = p.assc - AND i.coltier = p.coltier - AND p.glec <> '1RE' - -GROUP BY - p.product - ,p.styc - ,p.glec - ,p.majg - ,p.assc - ,p.coltier - ,p.colgrp - ,p.sizc - ,p.suffix - ,p.chgrp - ,p.account - ,p.shipgrp - ,bl.py_gasp - ,i.rate -) -----------------create the new price----------------- -,adj AS ( -SELECT - p.product - ,p.styc - ,p.glec - ,p.majg - ,p.assc - ,p.coltier - ,p.sizc - ,p.suffix - ,p.account - ,p.shipgrp - ,p.py_gasp - ,p.cy_units - ,p.py_asp - ,p.last_price - ,p.last_order - ,p.rate - ,p.flag - ,CASE p.flag - ----------------------if repeat business then get to prior year + target %-------------------------------------------------------------- - WHEN 'repeat' THEN greatest(py_asp * COALESCE(1+rate,1) - last_price,0) - WHEN 'lost' THEN greatest(py_asp * COALESCE(1+rate,1) - last_price,0) - ----------------------if new business, move towards py_gasp + target % : lesser of py gloabl + target or last + target------------------ - WHEN 'new' THEN least(last_price * COALESCE(1+rate,1) - last_price,greatest(py_gasp * COALESCE(1+rate,1) - last_price,0)) - END price_increment -FROM - pivot p -) ---SELECT * FROM adj LIMIT 10000 ---------------create a log entry-------------------- -,log AS ( - INSERT INTO - rlarp.osm_log(doc) - SELECT - $${ - "message":"application of last price and target increases to all forecast orders", - "tag":"last price", - "type":"build" - }$$::jsonb doc - RETURNING * -) +--SELECT * FROM baseline WHERE product = 'AMK06000.CBXX' +----------calculate pricing as it sits in the forecast-------------- ,poolprice AS ( SELECT - i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) product + i.stlc||'.'||i.coltier||substring(i.sizc,1,3) productt + ,i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) product ,o.quota_rep_descr + ,substring(majg,1,3) majg + ,substring(chan,1,1) chgrp ,o.billto_group ,o.shipto_group ,order_season - ,sum(units) units - ,sum(value_loc) valloc - ,sum(value_usd) valusd - ,sum(o.value_loc)/sum(o.units) price + ,round(sum(units) ,2) fc_units + --,round(sum(value_loc) ,2) valloc + --,round(sum(value_usd) ,2) valusd + ,round(sum(o.value_loc)/sum(o.units),5) fc_price ,jsonb_agg(DISTINCT iter) iters FROM rlarp.osm_pool o @@ -280,127 +227,355 @@ WHERE --only include baseline stuff--- AND segm <> 'Retail' GROUP BY - i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) + i.stlc||'.'||i.coltier||substring(i.sizc,1,3) + ,i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) ,o.quota_rep_descr + ,substring(majg,1,3) + ,substring(chan,1,1) ,o.billto_group ,o.shipto_group ,order_season --AND iter <> 'upload price' +HAVING + sum(o.units) <> 0 ) -, pooladj AS ( - SELECT - p.product - ,p.quota_rep_descr - ,p.billto_group - ,p.shipto_group - ,p.price - ,a.py_gasp - ,a.rate - ,a.last_price - ,a.price_increment - FROM - poolprice p - ,adj a - WHERE - a.product = p.product - AND a.account = p.billto_group - AND a.shipgrp = p.shipto_group +----------pivot the pricing out into columns per customer/product-------- +,pivot AS ( +SELECT + p.productt + ,p.product + --,p.styc + --,p.glec + ,p.majg + ,p.assc + ,p.colgrp + --,p.coltier + --,p.sizc + --,p.suffix + ,p.chgrp + ,p.account + ,p.shipgrp + ,bl.py_gasp + ,jsonb_agg(DISTINCT part) item + ,sum(units) FILTER (WHERE oseas = 2020) py_units + ,sum(units) FILTER (WHERE oseas = 2021) cy_units + ,round(sum(val_usd) FILTER (WHERE oseas = 2020)/sum(units) FILTER (WHERE oseas = 2020),5) py_asp + ,round(sum(val_usd) FILTER (WHERE oseas = 2021)/sum(units) FILTER (WHERE oseas = 2021),5) cy_asp + ,round(avg(price) FILTER (WHERE rn = 1),5) last_price + ,max(odate) FILTER (WHERE rn = 1) last_order + ,CASE p.chgrp + WHEN 'D' THEN i.rate + ELSE CASE p.majg + WHEN '610' THEN .02 + ElSE CASE p.colgrp + WHEN 'B' THEN .15 + WHEN 'C' THEN .20 + ELSE 1 + END + END + END rate + ,ms.avg_price target + ,JSONB_AGG(DISTINCT plist.jcpric/1000) jcprice + --,CASE WHEN sum(val_usd) FILTER (WHERE oseas = 2020) IS NULL + -- THEN CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL + -- THEN 'unknown' + -- ELSE 'new' + -- END + -- ELSE CASE WHEN sum(units) FILTER (WHERE oseas = 2021) IS NULL + -- THEN 'lost' + -- ELSE 'repeat' + -- END + --END flag +FROM + p + LEFT OUTER JOIN baseline bl ON + bl.product = p.product + AND bl.majg = p.majg + AND bl.assc = p.assc + AND bl.chgrp = p.chgrp + LEFT OUTER JOIN incr i ON + i.majg = p.majg + AND i.assc = p.assc + AND i.coltier = p.coltier + AND p.glec <> '1RE' + -----convert to target price channels--------- + LEFT OUTER JOIN chx ON + chx.chan = p.chan + -----convert to target price product level---- + LEFT OUTER JOIN ds ON + ds.colgrp = p.colgrp + AND ds.brand = substring(p.sizc,3,1) + LEFT OUTER JOIN pricequote.market_setavgprice ms ON + ms.mold = substring(p.product,1,8) + AND ms.chan = chx.xchan + AND ms.data_segment = ds.dataseg + AND ms.season = '2021' + AND ms.region = 'ALL' + LEFT OUTER JOIN plist ON + plist.dba = p.account + AND plist.jcpart = p.part +GROUP BY + p.productt + ,p.product + --,p.styc + --,p.glec + ,p.majg + ,p.assc + --,p.coltier + ,p.colgrp + --,p.sizc + --,p.suffix + ,p.chgrp + ,p.account + ,p.shipgrp + ,bl.py_gasp + ,ms.avg_price + ,i.rate ) -SELECT * FROM pooladj WHERE product ~ 'STG06000' AND shipto_group = 'BWI' limit 100 ---SELECT * FROM poolprice WHERE product ~ 'TCA06600' AND shipto_group = 'BWI' AND quota_rep_descr = 'BRYAN HILL' LIMIT 1000 --------------build the iteration rows---------------- ---,ins AS ( +--,test_unique AS ( --SELECT --- o.fspr --- ,o.plnt ---master data --- ,o.promo --history date mix --- ,o.terms --- ,o.bill_cust_descr --history cust mix --- ,o.ship_cust_descr --history cust mix --- ,o.dsm --- ,o.quota_rep_descr --master data --- ,o.director --- ,o.billto_group --master data --- ,o.shipto_group --- ,o.chan --master data --- ,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 --master data --- ,o.r_currency --history cust mix --- ,o.r_rate --master data --- ,o.c_currency --master data --- ,o.c_rate --master data --- ,0::numeric units --- ,ROUND(o.units * (a.price_increment/o.r_rate),2) value_loc --- ,ROUND(o.units * a.price_increment,2) value_usd --- ,0::numeric cost_loc --- ,0::numeric cost_usd --- ,o.calc_status --0 --- ,o.flag --0 --- ,o.order_date --history date mix --- ,o.order_month --- ,o.order_season --- ,o.request_date --history date mix --- ,o.request_month --- ,o.request_season --- ,o.ship_date --history date mix --- ,o.ship_month --- ,o.ship_season --- ,o.version --- ---this iteration has to be listed in the master template file in order to be effectively included--- --- ,'upload price' iter --- ,log.id --- ,COALESCE(log.doc->>'tag','') "tag" --- ,log.doc->>'message' "comment" --- ,log.doc->>'type' module --- -----------debug columns--------- --- --,value_usd/units price --- --,a.py_gasp --- --,a.rate --- --,a.last_price --- --,a.price_increment +-- p.* +-- ,count(*) OVER (partition by productt, majg, chgrp, account, shipgrp) cnt --FROM --- rlarp.osm_pool o --- ,rlarp.itemmv i --- ,adj a --- ,log ---WHERE --- i.item = o.part --- AND a.product = i.stlc||'.'||i.colgrp||substring(i.sizc,1,3) --- AND a.account = o.billto_group --- AND a.shipgrp = o.shipto_group --- AND a.price_increment <> 0 --- AND o.units <> 0 --- ---only apply to 2022 orders---- --- AND o.order_date >= '2021-06-01' --- --only include baseline stuff--- --- AND iter <> 'upload price' +-- pivot p --) --------------aggregate the impact------------ -----SELECT * FROM ins limit 10000 -----SELECT ----- order_season ----- ,sum(value_loc) val_loc ----- ,sum(value_usd) val_usd -----FROM ----- ins -----GROUP BY ----- order_season; ---,del AS ( --- DELETE FROM rlarp.osm_pool WHERE iter = 'upload price' RETURNING * ---) ---INSERT INTO --- rlarp.osm_pool ---SELECT * FROM ins; --- ---COMMIT; +--SELECT * FROM test_unique where cnt > 1 +----------------create a log entry-------------------- +,log AS ( + INSERT INTO + rlarp.osm_log(doc) + SELECT + $${ + "message":"application of last price and target increases to all forecast orders", + "tag":"last price", + "type":"build" + }$$::jsonb doc + RETURNING * +) +---------collapse iterations----------------------- +,collapse AS ( + SELECT + o.fspr + ,o.plnt ---master data + ,o.promo --history date mix + ,o.terms + ,o.bill_cust_descr --history cust mix + ,o.ship_cust_descr --history cust mix + ,o.dsm + ,o.quota_rep_descr --master data + ,o.director + ,o.billto_group --master data + ,o.shipto_group + ,o.chan --master data + ,o.chansub + ,o.chan_retail + ,o.part + ,o.part_descr + ,i.stlc||'.'||i.coltier||substring(i.sizc,1,3) productt + ,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(o.units) units + ,SUM(o.value_loc) value_loc + ,SUM(o.value_usd) value_usd + ,SUM(o.value_loc)/SUM(o.units) price_loc + ,SUM(o.cost_loc) cost_loc + ,SUM(o.cost_usd) cost_usd + ,o.calc_status --0 + ,o.flag --0 + ,o.order_date --history date mix + ,o.order_month + ,o.order_season + ,o.request_date --history date mix + ,o.request_month + ,o.request_season + ,o.ship_date --history date mix + ,o.ship_month + ,o.ship_season + FROM + rlarp.osm_pool o + --need to join to itemm to get the product from osm_pool + ,rlarp.itemmv i + WHERE + i.item = o.part + GROUP BY + o.fspr + ,o.plnt ---master data + ,o.promo --history date mix + ,o.terms + ,o.bill_cust_descr --history cust mix + ,o.ship_cust_descr --history cust mix + ,o.dsm + ,o.quota_rep_descr --master data + ,o.director + ,o.billto_group --master data + ,o.shipto_group + ,o.chan --master data + ,o.chansub + ,o.chan_retail + ,o.part + ,o.part_descr + ,i.stlc||'.'||i.coltier||substring(i.sizc,1,3) + ,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 --0 + ,o.flag --0 + ,o.order_date --history date mix + ,o.order_month + ,o.order_season + ,o.request_date --history date mix + ,o.request_month + ,o.request_season + ,o.ship_date --history date mix + ,o.ship_month + ,o.ship_season + HAVING + sum(o.units) <> 0 +) +-------------build the iteration rows---------------- +,ins AS ( +SELECT + o.fspr + ,o.plnt ---master data + ,o.promo --history date mix + ,o.terms + ,o.bill_cust_descr --history cust mix + ,o.ship_cust_descr --history cust mix + ,o.dsm + ,o.quota_rep_descr --master data + ,o.director + ,o.billto_group --master data + ,o.shipto_group + ,o.chan --master data + ,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 --master data + ,o.r_currency --history cust mix + ,o.r_rate --master data + ,o.c_currency --master data + ,o.c_rate --master data + --,o.units + ,0::numeric units + ,greatest( + round(least( + least( + COALESCE(a.py_asp,o.price_loc), + COALESCE(a.py_gasp,a.target) + ) * (1 + a.rate), + (a.jcprice->>0)::numeric + )*o.units - o.value_loc,2) + ,0) AS value_loc + ,greatest( + round((least( + least( + COALESCE(a.py_asp,o.price_loc), + COALESCE(a.py_gasp,a.target) + ) * (1 + a.rate), + (a.jcprice->>0)::numeric + )*o.units - o.value_loc) * r_rate,2) + ,0) AS value_usd + ----debug--- + --,least( + -- least( + -- COALESCE(a.py_asp,o.price_loc), + -- COALESCE(a.py_gasp,a.target) + -- ) * (1 + a.rate), + -- (a.jcprice->>0)::numeric + --) AS rev_price + --,o.units + --,o.value_loc + --,o.value_usd + --,o.price_loc + --,a.last_price + --,a.target + --,a.jcprice + --,a.rate + --,a.py_asp + --,a.py_gasp + ----------- + ,0::numeric cost_loc + ,0::numeric cost_usd + ,o.calc_status --0 + ,o.flag --0 + ,o.order_date --history date mix + ,o.order_month + ,o.order_season + ,o.request_date --history date mix + ,o.request_month + ,o.request_season + ,o.ship_date --history date mix + ,o.ship_month + ,o.ship_season + --,o.version + ---this iteration has to be listed in the master template file in order to be effectively included--- + ,'b22' AS version + ,'upload price' iter + ,log.id + ,COALESCE(log.doc->>'tag','') "tag" + ,log.doc->>'message' "comment" + ,log.doc->>'type' module + -----------debug columns--------- + --,value_usd/units price + --,a.py_gasp + --,a.rate + --,a.last_price + --,a.price_increment +FROM + collapse o + --need to join to itemm to get the product from osm_pool + --,fcp a + ,pivot a + ,log +WHERE + -- a.productt = o.productt + --AND a.quota_rep_descr = o.quota_rep_descr + --AND a.majg = SUBSTRING(o.majg_descr,1,3) + --AND a.billto_group = o.billto_group + --AND a.shipto_group = o.shipto_group + --AND a.chgrp = substring(o.chan,1,1) + ---only apply to 2022 orders---- + ---join p + a.productt = o.productt + AND a.majg = SUBSTRING(o.majg_descr,1,3) + AND a.chgrp = substring(o.chan,1,1) + AND a.account = o.billto_group + AND a.shipgrp = o.shipto_group + AND o.order_date >= '2021-06-01' + AND o.segm <> 'Retail' +) +--SELECT order_season, order_month, sum(value_usd) from ins group by order_season, order_month; +INSERT INTO rlarp.osm_pool SELECT * FROM ins; +-----------aggregate the impact------------ + +COMMIT;