DROP TABLE IF EXISTS rlarp.osm_pool; 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','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 ,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 cost_loc ,fb_cst_loc * 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 ,null::int logid ,''::text "comment" ,''::text module FROM rlarp.osmf_dev o 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); ALTER TABLE rlarp.osm_pool ADD CONSTRAINT logfk FOREIGN KEY (logid) REFERENCES rlarp.osm_log(id); 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); GRANT ALL ON TABLE rlarp.osm_log TO api; GRANT ALL ON TABLE rlarp.osm_pool TO api;