--\timing truncate table rlarp.osmfs_dev; 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 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 ,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 ,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 ,ship_cust ,null::text ship_rep ,null::text ship_terr ,null::text 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 r_rate ,o.c_currency ,o.c_rate 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 ,'15mo' "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 <@ 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 < '2021-05-01') --...or anything that shipped in that period OR o.fspr BETWEEN '2101' AND '2111' ) AND fs_line = '41010' AND calc_status <> 'CANCELED' AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') AND "version" = 'ACTUALS' GROUP BY o.fspr ,plnt ,COALESCE(o.promo,'') ,o.terms ,o.bill_cust ,ship_cust ,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 ) INSERT INTO rlarp.osmfs_dev SELECT * FROM baseline; ---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;