WITH act as ( SELECT bill_dba ,ship_dba ,dsm --,os.glec --,m.biggroup --,os.priceg ,COALESCE(sum(pounds) filter (WHERE sseas = 2023 AND version = 'Actual' AND SUBSTRING(smon,1,2) <= '08'),0) "Actual 2023" ,COALESCE(sum(pounds) filter (WHERE sseas = 2024 AND version = 'Actual'),0) "Actual 2024" ,COALESCE(sum(pounds) filter (WHERE version = 'Actual' AND ostatus LIKE 'Open%' AND rseas <= 2024),0) "Open Ord" ,COALESCE(sum(pounds) filter (WHERE version = 'Quotes'),0) "Quotes" FROM rlarp.osm_stack os LEFT OUTER JOIN rlarp.molds m ON m.stlc = substring(os.product ,1,8) WHERE ( ( sseas IN (2023,2024) AND version = 'Actual' AND ostatus = 'Shipped' ) OR ( version = 'Quotes' AND odate >= '2023-05-01'::date ) OR (ostatus LIKE 'Open%') ) AND calc_status <> 'CANCELED' AND substring(os.glec,1,1) <= '2' AND os.fs_line = '41010' AND COALESCE(ship_dba,'') <> '' GROUP BY bill_dba ,ship_dba ,dsm --,os.glec --,m.biggroup --,os.priceg ) ,bgt AS ( SELECT bill_dba ,ship_dba ,dsm ,sum(sales_usd) sales ,sum(pounds) pounds --string_agg(distinct mold,', ') FROM rlarp.osm_stack WHERE version = 'Budget' AND oseas = '2024' GROUP BY bill_dba ,ship_dba ,dsm ) ,agg AS ( SELECT COALESCE(act.bill_dba,TRIM(bgt.bill_dba)) bill_dba ,COALESCE(act.ship_dba,TRIM(bgt.ship_dba)) ship_dba ,COALESCE(act.dsm ,TRIM(bgt.dsm )) dsm ,SUM(bgt.pounds ) "Budget 2024" ,SUM(act."Actual 2023") "Actual 2023" ,SUM(act."Actual 2024") "Actual 2024" ,SUM(act."Open Ord" ) "Open Ord" ,SUM(act."Quotes" ) "Quotes" FROM act FULL OUTER JOIN bgt ON TRIM(bgt.bill_dba) = act.bill_dba AND TRIM(bgt.ship_dba) = act.ship_dba AND TRIM(bgt.dsm ) = act.dsm GROUP BY COALESCE(act.bill_dba,TRIM(bgt.bill_dba)) ,COALESCE(act.ship_dba,TRIM(bgt.ship_dba)) ,COALESCE(act.dsm ,TRIM(bgt.dsm )) ) SELECT * FROM agg