WITH income AS ( SELECT p.id, SUM(amount) AS incomeSum FROM "transaction" t INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id INNER JOIN period p on p.id = ltp.period_id WHERE 1 = 1 AND t.transaction_type = 'INCOME' GROUP BY p.id, p.type, p.start, p."end" ), expense AS ( -- Expense booking - NOT counted is the case LIABILITY -> EXPENSE even though that is a -- valid booking in the app. This is because we would count the expense once here and a second time -- with the liability query SELECT p2.id, SUM(amount) AS expenseSum FROM "transaction" t INNER JOIN account a on a.id = t.from_account_id INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id INNER JOIN period p2 on p2.id = ltp.period_id WHERE 1 = 1 AND t.transaction_type = 'EXPENSE' AND a.type in ('BANK', 'CASH') GROUP BY p2.id, p2.type, p2.start, p2."end" ), liability AS ( SELECT p3.id, SUM(amount) AS liabilitySum FROM "transaction" t INNER JOIN link_transaction_period ltp on ltp.transaction_id = t.id INNER JOIN period p3 on p3.id = ltp.period_id WHERE 1 = 1 AND t.transaction_type = 'LIABILITY' GROUP BY p3.id, p3.type, p3.start, p3."end" ), assets AS ( -- Returns only the assets for closed periods SELECT p.ID, SUM(asBankCash.end_balance) AS assetSum FROM period p INNER JOIN account_statistic asBankCash ON asBankCash.period_id = p.id INNER JOIN account aBankCash ON aBankCash.id = asBankCash.account_id AND aBankCash.type IN ('BANK', 'CASH') GROUP BY p.id, p.type, p.start, p."end" ), transactions AS ( -- The count of transactions in a period SELECT ltp.period_id, COUNT(*) AS transaction_count FROM link_transaction_period ltp GROUP BY ltp.period_id ) SELECT p.ID PERIOD_ID, p.type PERIOD_TYPE, p.start PERIOD_START, p."end" PERIOD_END, CASE WHEN i.incomeSum IS NULL THEN 0 WHEN i.incomeSum IS NOT NULL THEN i.incomeSum END INCOME_SUM, CASE WHEN e.expenseSum IS NULL THEN 0 WHEN e.expenseSum IS NOT NULL THEN e.expenseSum END EXPENSE_SUM, CASE WHEN l.liabilitySum IS NULL THEN 0 WHEN l.liabilitySum IS NOT NULL THEN l.liabilitySum END LIABILITY_SUM, CASE -- 2^2 possible cases WHEN e.expenseSum IS NULL AND l.liabilitySum IS NULL THEN 0 WHEN e.expenseSum IS NOT NULL AND l.liabilitySum IS NULL THEN e.expenseSum WHEN e.expenseSum IS NULL AND l.liabilitySum IS NOT NULL THEN l.liabilitySum WHEN e.expenseSum IS NOT NULL AND l.liabilitySum IS NOT NULL THEN (e.expenseSum + l.liabilitySum) END TOTAL, a.assetSum ASSETS_SUM, CASE WHEN p.TYPE != 'EXPENSE' THEN NULL WHEN LEAD(a.assetSum, 1) OVER (ORDER BY "end" DESC, start ASC) < a.assetSum THEN 'UP' WHEN LEAD(a.assetSum, 1) OVER (ORDER BY "end" DESC, start ASC) > a.assetSum THEN 'DOWN' WHEN LEAD(a.assetSum, 1) OVER (ORDER BY "end" DESC, start ASC) = a.assetSum THEN 'EQUAL' END ASSET_TREND, CASE WHEN t.transaction_count IS NULL THEN 0 WHEN t.transaction_count IS NOT NULL THEN t.transaction_count END TRANSACTION_COUNT FROM period p LEFT JOIN income i ON i.ID = p.ID LEFT JOIN expense e ON e.ID = p.ID LEFT JOIN assets a ON a.ID = p.ID LEFT JOIN liability l ON l.ID = p.ID LEFT JOIN transactions t ON t.period_id = p.ID ORDER BY "end" DESC, start ASC;