WITH target AS (SELECT $$swap_doc$$::jsonb swap) ,pl AS ( SELECT -----trim white space on CMS part numbers coming from spreadsheet master data---- rtrim(x.original) AS original ,sales ,rtrim(x."replace") AS replace ,rtrim(x.fit) fit FROM TARGET LEFT JOIN LATERAL jsonb_to_recordset(target.swap->'rows') AS x(original text, sales numeric, replace text, fit text)ON TRUE WHERE COALESCE(x.replace,'') <> '' ) --select * from pl ,seg AS ( SELECT x.glec ,x.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) ) ,log AS ( INSERT INTO rlarp.osm_log(doc) SELECT $$replace_iterdef$$::jsonb doc RETURNING * ) ,remove AS ( SELECT fspr ,plnt ---master data ,promo --history date mix ,terms ,bill_cust_descr --history cust mix ,ship_cust_descr --history cust mix ,dsm ,quota_rep_descr --master data ,director ,billto_group --master data ,shipto_group ,chan --master data ,chansub ,chan_retail ,part ,part_descr ,part_group ,branding ,majg_descr ,ming_descr ,majs_descr ,mins_descr ,segm ,substance ,fs_line --master data ,r_currency --history cust mix ,r_rate --master data ,c_currency --master data ,c_rate --master data ,-units units ,-value_loc value_loc ,-value_usd value_usd ,-cost_loc cost_loc ,-cost_usd cost_usd ,calc_status --0 ,flag --0 ,order_date --history date mix ,order_month ,order_season ,request_date --history date mix ,request_month ,request_season ,ship_date --history date mix ,ship_month ,ship_season ,'replace_version' "version" ,'replace_source'||' volume' iter ,log.id ,COALESCE(log.doc->>'tag','') "tag" ,log.doc->>'message' "comment" ,log.doc->>'type' module FROM rlarp.osm_pool o CROSS JOIN log INNER JOIN pl ON pl.original = o.part WHERE -----------------scenario---------------------------- where_clause ) ,repl AS ( SELECT fspr ,m.dplt plnt ---master data ,promo --history date mix ,terms ,bill_cust_descr --history cust mix ,ship_cust_descr --history cust mix ,dsm ,quota_rep_descr --master data ,director ,billto_group --master data ,shipto_group ,chan --master data ,chansub ,chan_retail ,pl.replace part ,m.item || ' - ' || m.descr partd ,substring(pl.replace,1,8) part_group ,m.branding branding ,m.majg||' - '||m.majgd majg_descr ,m.ming||' - '||m.mingd ming_descr ,m.majs||' - '||m.majsd majs_descr ,m.mins||' - '||m.minsd mins_descr ,seg.segm ,substance ,fs_line --master data ,r_currency --history cust mix ,r_rate --master data ,r.curr c_currency --master data ,x.rate c_rate --master data ,-units units ,-value_loc value_loc ,-value_usd value_usd ,-units * c.std cost_loc ,-units * c.std * x.rate cost_usd ,calc_status --0 ,flag --0 ,order_date --history date mix ,order_month ,order_season ,request_date --history date mix ,request_month ,request_season ,ship_date --history date mix ,ship_month ,ship_season ,o."version" ,o.iter ,o.id ,o."tag" ,o."comment" ,o.module FROM remove o INNER JOIN pl ON pl.original = o.part INNER JOIN rlarp.itemmv m ON m.item = pl.replace LEFT OUTER JOIN rlarp.icstx c ON c.part = pl.replace AND c.plnt = m.dplt LEFT OUTER JOIN rlarp.plpr r ON yaplnt = m.dplt LEFT OUTER JOIN rlarp.ffcret x ON x.fcur = r.curr AND x.tcur = 'US' AND x.rtyp = 'BG' AND x.perd = '2101' LEFT OUTER JOIN seg ON seg.glec = m.glec ) ,ins AS ( INSERT INTO rlarp.osm_pool SELECT * FROM remove UNION ALL SELECT * FROM repl RETURNING * ) ,insagg AS ( SELECT ---------customer info----------------- bill_cust_descr ,billto_group ,ship_cust_descr ,shipto_group ,quota_rep_descr ,director ,segm ,substance ,chan ,chansub ---------product info------------------ ,majg_descr ,ming_descr ,majs_descr ,mins_descr --,brand --,part_family ,part_group ,branding --,color ,part_descr ---------dates------------------------- ,order_season ,order_month ,ship_season ,ship_month ,request_season ,request_month ,promo ,version ,iter ,logid ,tag ,comment --------values------------------------- ,sum(value_loc) value_loc ,sum(value_usd) value_usd ,sum(cost_loc) cost_loc ,sum(cost_usd) cost_usd ,sum(units) units FROM ins GROUP BY ---------customer info----------------- bill_cust_descr ,billto_group ,ship_cust_descr ,shipto_group ,quota_rep_descr ,director ,segm ,substance ,chan ,chansub ---------product info------------------ ,majg_descr ,ming_descr ,majs_descr ,mins_descr --,brand --,part_family ,part_group ,branding --,color ,part_descr ---------dates------------------------- ,order_season ,order_month ,ship_season ,ship_month ,request_season ,request_month ,promo ,version ,iter ,logid ,tag ,comment ) SELECT json_agg(row_to_json(insagg)) x from insagg