script pieces for merging actuals #2
							
								
								
									
										6
									
								
								build/merge_actuals_exec.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										6
									
								
								build/merge_actuals_exec.sql
									
									
									
									
									
										Normal file
									
								
							| @ -0,0 +1,6 @@ | ||||
| 
 | ||||
| DELETE FROM rlarp.osmf_dev WHERE odate < '2020-04-01'; | ||||
| INSERT INTO rlarp.osmf_dev SELECT * FROM rlarp.osmfs_dev WHERE odate < '2020-04-01'; | ||||
| 
 | ||||
| 
 | ||||
| 
 | ||||
							
								
								
									
										163
									
								
								build/merge_actuals_pool.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										163
									
								
								build/merge_actuals_pool.sql
									
									
									
									
									
										Normal file
									
								
							| @ -0,0 +1,163 @@ | ||||
| BEGIN; | ||||
| 
 | ||||
| DELETE FROM rlarp.osm_pool WHERE order_date < '2020-04-01'; | ||||
| 
 | ||||
| INSERT INTO rlarp.osm_pool | ||||
| 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','Retail'), | ||||
|             ('1GR','Greenhouse'), | ||||
|             ('1NU','Nursery'), | ||||
|             ('1RE','Retail'), | ||||
|             ('2WI','Greenhouse'), | ||||
|             ('3BM','Other'), | ||||
|             ('3CO','Other'), | ||||
|             ('3PE','Other'), | ||||
|             ('3PP','Other'), | ||||
|             ('4CO','Other'), | ||||
|             ('4RA','Other'), | ||||
|             ('9MI','Other'), | ||||
|             ('9SA','Other'), | ||||
|             ('9TO','Other') | ||||
|         ) X(GLEC, SEGM) | ||||
| ) | ||||
| ----------------------------------------------------sales major codes---------------------------------------------------------------------------------------------------------------------------------- | ||||
| ,SJ AS ( | ||||
|     SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') = '' | ||||
| ) | ||||
| ----------------------------------------------------sales minor codes---------------------------------------------------------------------------------------------------------------------------------- | ||||
| ,SI AS ( | ||||
|     SELECT * FROM LGDAT.MMSL WHERE COALESCE(BSMNCD,'') <> '' | ||||
| ) | ||||
| 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 | ||||
|         WHEN 'Retail' THEN | ||||
|             CASE o.bill_class | ||||
|                 WHEN 'RMAS' THEN 'MASS'  | ||||
|                 WHEN 'RNAT' THEN 'NATIONAL'  | ||||
|                 ELSE 'OTHER'  | ||||
|             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 | ||||
|     INNER JOIN rlarp.osm_log logload ON | ||||
|         logload.id = 1 | ||||
|     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 | ||||
| WHERE | ||||
|     odate < '2020-04-01'; | ||||
| 
 | ||||
| 
 | ||||
| SELECT | ||||
|     "version", | ||||
|     iter, | ||||
|     order_season, | ||||
|     order_month , | ||||
|     sum(value_usd ) value_usd | ||||
| FROM | ||||
|     RLARP.osm_pool op  | ||||
| WHERE | ||||
|     --oseas = 2020 | ||||
|     fs_line = '41010' | ||||
|     --AND odate < '2020-04-01' | ||||
|     AND CALC_STATUS <> 'CANCELED' | ||||
|     AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') | ||||
| GROUP BY  | ||||
|     "version", | ||||
|     iter, | ||||
|     order_season, | ||||
|     order_month; | ||||
|      | ||||
|      | ||||
| --ROLLBACK; | ||||
| 
 | ||||
| commit; | ||||
							
								
								
									
										186
									
								
								build/merge_actuals_prep.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										186
									
								
								build/merge_actuals_prep.sql
									
									
									
									
									
										Normal file
									
								
							| @ -0,0 +1,186 @@ | ||||
| --\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('2019-06-01','2020-04-01') | ||||
|             --...or any open orders currently booked before cutoff.... | ||||
|             OR (o.calc_status IN ('OPEN','BACKORDER') and o.odate < '2020-04-01') | ||||
|             --...or anything that shipped in that period | ||||
|             OR o.fspr BETWEEN '2001' AND '2010' | ||||
|         ) | ||||
|         AND fs_line = '41010' | ||||
|         AND calc_status <> 'CANCELED' | ||||
|         AND NOT (calc_status = 'CLOSED' AND flag = 'REMAINDER') | ||||
|     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; | ||||
| @ -33,6 +33,7 @@ FROM | ||||
|     clist c | ||||
| WHERE | ||||
|     c.part = o.part | ||||
|     AND  c.plnt = o.plnt; | ||||
|     AND  c.plnt = o.plnt | ||||
|     AND version = 'b21'; | ||||
| 
 | ||||
| commit; | ||||
| @ -1,7 +1,9 @@ | ||||
| ------------update fx rates----------------------------------------------------------------- | ||||
| UPDATE rlarp.osmf_dev SET r_rate = .7518 WHERE r_currency = 'CA' | ||||
| UPDATE rlarp.osmf_dev SET c_rate = .7518 WHERE c_currency = 'CA' | ||||
| UPDATE rlarp.osm_pool SET r_rate = .7518 WHERE r_currency = 'CA' | ||||
| UPDATE rlarp.osm_pool SET value_usd = value_loc * r_rate WHERE r_currency = 'CA' | ||||
| UPDATE rlarp.osm_pool SET c_rate = .7518 WHERE c_currency = 'CA' | ||||
| UPDATE rlarp.osm_pool SET cost_usd = cost_loc * c_rate WHERE c_currency = 'CA' | ||||
| UPDATE rlarp.osmf_dev SET r_rate = .7518 WHERE r_currency = 'CA' AND version = 'b21'; | ||||
| UPDATE rlarp.osmf_dev SET r_rate = 1.0000 WHERE r_currency = 'US' AND version = 'b21'; | ||||
| UPDATE rlarp.osmf_dev SET c_rate = .7518 WHERE c_currency = 'CA' AND version = 'b21'; | ||||
| UPDATE rlarp.osmf_dev SET c_rate = 1.0000 WHERE c_currency = 'US' AND version = 'b21'; | ||||
| UPDATE rlarp.osm_pool SET r_rate = .7518 WHERE r_currency = 'CA' AND version = 'b21'; | ||||
| UPDATE rlarp.osm_pool SET value_usd = value_loc * r_rate WHERE r_currency = 'CA' AND version = 'b21'; | ||||
| UPDATE rlarp.osm_pool SET c_rate = .7518 WHERE c_currency = 'CA' AND version = 'b21'; | ||||
| UPDATE rlarp.osm_pool SET cost_usd = cost_loc * c_rate WHERE c_currency = 'CA' AND version = 'b21'; | ||||
							
								
								
									
										16
									
								
								tots.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										16
									
								
								tots.sql
									
									
									
									
									
										Normal file
									
								
							| @ -0,0 +1,16 @@ | ||||
| SELECT  | ||||
|     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') order_month, | ||||
|     version,  | ||||
|     iter,  | ||||
|     sum(fb_val_loc) value_loc | ||||
| FROM | ||||
|     rlarp.osmfs_dev  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'), | ||||
|     version,  | ||||
|     iter | ||||
| ORDER BY | ||||
|     oseas asc, | ||||
|     order_month asc | ||||
		Loading…
	
		Reference in New Issue
	
	Block a user