@@ -0,0 +1,130 @@
|
||||
WITH income AS (
|
||||
-- Regular income based on INCOME accounts
|
||||
SELECT p.ID, SUM(asIncome.spending_total_from) AS incomeSum
|
||||
FROM period p
|
||||
INNER JOIN account_statistic asIncome ON asIncome.period_id = p.id
|
||||
INNER JOIN account aIncome ON aIncome.id = asIncome.account_id AND aIncome.type = 'INCOME'
|
||||
GROUP BY p.id, p.type, p.start, p."end"
|
||||
),
|
||||
incomeCredit as (
|
||||
-- Special case for credits that can be booked from a LIABILITY account to a BANK/CASH account
|
||||
-- Need to be counted as income as the money is used for expenses and those expenses will be counted
|
||||
-- as expense, so to make it even we need to count it here as well
|
||||
SELECT p2.id, SUM(amount) AS incomeCreditSum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_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 a.type in ('LIABILITY')
|
||||
AND a2.type in ('BANK', 'CASH')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."end"
|
||||
),
|
||||
incomeStart as (
|
||||
-- Special case for money that was there at the starting time of a financer instance
|
||||
-- Will be counted as income as this money is used for expanses, so to make it even
|
||||
-- we need to count it here as well
|
||||
SELECT p2.id, SUM(amount) AS incomeStartSum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_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 a.type in ('START')
|
||||
AND a2.type in ('BANK', 'CASH')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."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 account a2 on a2.id = t.to_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 a.type in ('BANK', 'CASH')
|
||||
AND a2.type in ('EXPENSE')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."end"
|
||||
),
|
||||
liability AS (
|
||||
-- Excluded is the special case for start bookings, START -> LIABILITY
|
||||
-- as the actual expense for that was some time in the past before the starting
|
||||
-- of the financer instance
|
||||
SELECT p2.id, SUM(amount) AS liabilitySum
|
||||
FROM "transaction" t
|
||||
INNER JOIN account a on a.id = t.from_account_id
|
||||
INNER JOIN account a2 on a2.id = t.to_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 a.type in ('BANK', 'CASH')
|
||||
AND a2.type in ('LIABILITY')
|
||||
GROUP BY p2.id, p2.type, p2.start, p2."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
|
||||
-- 2^3 possible cases
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NULL THEN 0
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NULL THEN i.incomeSum
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NULL THEN ic.incomeCreditSum
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NULL THEN (i.incomeSum + ic.incomeCreditSum)
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NOT NULL THEN "is".incomeStartSum
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NULL AND "is".incomeStartSum IS NOT NULL THEN (i.incomeSum + "is".incomeStartSum)
|
||||
WHEN i.incomeSum IS NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NOT NULL THEN (ic.incomeCreditSum + "is".incomeStartSum)
|
||||
WHEN i.incomeSum IS NOT NULL AND ic.incomeCreditSum IS NOT NULL AND "is".incomeStartSum IS NOT NULL THEN (i.incomeSum + ic.incomeCreditSum + "is".incomeStartSum)
|
||||
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 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 incomeCredit ic ON ic.ID = p.ID
|
||||
LEFT JOIN incomeStart "is" ON "is".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;
|
||||
Reference in New Issue
Block a user