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;