From f3f7b7a1778626933c6d4e4608d58283c267c473 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Fri, 9 Jul 2021 00:54:44 -0400 Subject: [PATCH] work on a new forecast approach --- build/build_baseline.sql | 1012 ++++++++++++++++++++++++++++++++++++++ build/build_stage.sql | 10 +- build/tots.sql | 7 +- 3 files changed, 1024 insertions(+), 5 deletions(-) create mode 100644 build/build_baseline.sql diff --git a/build/build_baseline.sql b/build/build_baseline.sql new file mode 100644 index 0000000..c93c252 --- /dev/null +++ b/build/build_baseline.sql @@ -0,0 +1,1012 @@ +BEGIN; +--\timing +--CREATE TABLE IF NOT EXISTS rlarp.osmf_stage AS (SELECT * FROM rlarp.osmf_dev) WITH no data; +--will not match actuals exactly due to short-ships +TRUNCATE TABLE rlarp.osmf_dev; + +DROP TABLE IF EXISTS tdr; + +CREATE TEMP TABLE tdr AS ( + SELECT + -----------actuals into baseline------------------------------------- + DATERANGE('2020-06-01','2021-07-07','[]') arange + -----------plan into baseline---------------------------------------- + ,DATERANGE('2021-07-08','2022-06-01','[)') prange + -----------forecast into baseline------------------------------------ + ,DATERANGE('2022-06-01','2022-06-01','[)') frange + -----------baseline selection for increment-------------------------- + ,DATERANGE('2021-07-08','2021-07-08','[)') selection + -----------selection increment size---------------------------------- + --need to specify the overlap, or derive it? + ,'0 year'::interval AS incr + -----------iterations to merge with---------------------------------- + ,(SELECT jsonb_agg(x.v) FROM (VALUES('copy'),('actuals'),('actuals_plug')) AS x(v)) iter +); + +--select * from tdr + +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 ( + ------------------------------------------------------------------------------------- + -----------------------------------actuals------------------------------------------- + ------------------------------------------------------------------------------------- + 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 + ,o."version" + ,o.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 arange FROM tdr) + --...or any open orders currently booked before cutoff.... + OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate <= (SELECT UPPER(arange) FROM tdr)) + --...or anything that shipped in that period + OR (o.sdate <@ (SELECT arange FROM tdr) AND sseas IS NOT NULL) + ) + ---exclude R&A's + AND fs_line = '41010' + ---exclude canceled orders + AND calc_status <> 'CANCELED' + ---exclude short ships + 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 + ,o."version" + ,o.iter + UNION ALL + ------------------------------------------------------------------------------------- + -----------------------------------plan---------------------------------------------- + ------------------------------------------------------------------------------------- + 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 + ,o."version" + ,o.iter + FROM + rlarp.osmp_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 prange FROM tdr) + --...or any open orders currently booked before cutoff.... + --OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate <= (SELECT UPPER(prange) FROM tdr)) + --...or anything that shipped in that period + --OR (o.sdate <@ (SELECT prange FROM tdr) AND sseas IS NOT NULL) + ) + ---exclude R&A's + AND fs_line = '41010' + ---exclude canceled orders + AND calc_status <> 'CANCELED' + ---exclude short ships + --AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') + ---exclude integrated quotes---- + AND version = 'b22' + 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 + ,o."version" + ,o.iter + UNION ALL + ------------------------------------------------------------------------------------- + -----------------------------------forecast------------------------------------------ + ------------------------------------------------------------------------------------- + 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 + ,o."version" + ,o.iter + FROM + rlarp.osmf_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 frange FROM tdr) + --...or any open orders currently booked before cutoff.... + --OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate <= (SELECT UPPER(prange) FROM tdr)) + --...or anything that shipped in that period + --OR (o.sdate <@ (SELECT prange FROM tdr) AND sseas IS NOT NULL) + ) + ---exclude R&A's + AND fs_line = '41010' + ---exclude canceled orders + AND calc_status <> 'CANCELED' + ---exclude short ships + 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 + ,o."version" + ,o.iter +) +--SELECT * FROM baseline where version = 'b22' +,incr AS ( +SELECT + o."ddord#" + ,o."dditm#" + ,o."fgbol#" + ,o."fgent#" + ,o."diinv#" + ,o."dilin#" + ,o.quoten + ,o.quotel + ,o.dcodat + (SELECT incr FROM tdr) dcodat --incremented + ,o.ddqdat + (SELECT incr FROM tdr) ddqdat --incremented + ,o.dcmdat + ,o.fesdat + ,o.dhidat + (SELECT incr FROM tdr) dhidat --incremented + ,o.fesind + ,o.dhpost + ,sg.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 + (SELECT incr FROM tdr))::date odate --incremented + ,og.ssyr oseas --incremented + ,(o.rdate + (SELECT incr FROM tdr))::date rdate --incremented + ,rg.ssyr rseas --incremented + ,(o.sdate + (SELECT incr FROM tdr))::date sdate --incremented + ,sg.ssyr sseas --incremented + ,'b22' "version" + ,'copy' iter +FROM + baseline o + -----join to date tables based on revised dating-------------- + LEFT OUTER JOIN rlarp.gld sg ON + sg.drange @> (o.sdate + (SELECT incr FROM tdr))::date + LEFT OUTER JOIN rlarp.gld og ON + og.drange @> (o.odate + (SELECT incr FROM tdr))::date + LEFT OUTER JOIN rlarp.gld rg ON + rg.drange @> (o.odate + (SELECT incr FROM tdr))::date +WHERE + -------only return orders where the forecast orderdate is in the target forecast range----------- + (o.odate + (SELECT incr FROM tdr))::date <@ (SELECT selection FROM tdr) OR + (o.sdate + (SELECT incr FROM tdr))::date <@ (SELECT selection FROM tdr) +) +--SELECT count(*) FROM baseline +,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.osmf_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.arange + OR o.odate <@ tdr.selection + ) + ---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 + true + --collect all the rows in the base period and + --the destination slot for the new rows + --o.odate <@ (SELECT tdr.arange FROM tdr) + --OR o.sdate <@ (SELECT tdr.arange FROM tdr) + --OR o.odate <@ (SELECT tdr.selection FROM tdr) + --OR o.sdate <@ (SELECT tdr.selection 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; + +---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/build_stage.sql b/build/build_stage.sql index fc3a9cd..a4e76e3 100644 --- a/build/build_stage.sql +++ b/build/build_stage.sql @@ -1,6 +1,7 @@ BEGIN; --\timing --CREATE TABLE IF NOT EXISTS rlarp.osmf_stage AS (SELECT * FROM rlarp.osmf_dev) WITH no data; +--will not match actuals exactly due to short-ships TRUNCATE TABLE rlarp.osmf_dev; DROP TABLE IF EXISTS tdr; @@ -8,12 +9,12 @@ DROP TABLE IF EXISTS tdr; CREATE TEMP TABLE tdr AS ( SELECT -----------actuals--------------------------------------------------- - DATERANGE('2020-06-01','2021-07-01','[)') adrange + DATERANGE('2020-06-01','2021-07-07','[]') adrange -----------actuals to target for incremnt---------------------------- - ,DATERANGE('2021-08-01','2022-06-01','[)') arepl + ,DATERANGE('2022-06-01','2022-06-01','[)') arepl ,'0 year'::interval AS aincr -----------budget to target for increment---------------------------- - ,DATERANGE('2021-07-01','2022-06-01','[)') prepl + ,DATERANGE('2021-07-08','2022-06-01','[)') prepl ,'0 year'::interval AS pincr -----------iterations to merge with---------------------------------- ,(SELECT jsonb_agg(x.v) FROM (VALUES('copy'),('actuals'),('actuals_plug')) AS x(v)) iter @@ -173,8 +174,11 @@ gld AS ( --...or anything that shipped in that period OR (o.sdate <@ (SELECT adrange FROM tdr) AND sseas IS NOT NULL) ) + ---exclude R&A's AND fs_line = '41010' + ---exclude canceled orders AND calc_status <> 'CANCELED' + ---exclude short ships AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') ---exclude integrated quotes---- AND version = 'ACTUALS' diff --git a/build/tots.sql b/build/tots.sql index b7c3b07..d46fc4b 100644 --- a/build/tots.sql +++ b/build/tots.sql @@ -3,9 +3,12 @@ SELECT 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, version, iter, - sum(fb_val_loc) value_loc + sum(fb_val_loc * r_rate) value_loc FROM rlarp.osmf_dev o +WHERE + fs_line = '41010' + and calc_status <> 'CANCELED' 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'), @@ -28,7 +31,7 @@ WHERE --oseas = 2020 fs_line = '41010' --AND odate < '2020-04-01' - AND CALC_STATUS <> 'CANCELED' + --AND CALC_STATUS <> 'CANCELED' AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') GROUP BY version,