1
0
Fork 0
mirror of https://github.com/maybe-finance/maybe.git synced 2025-08-07 06:25:19 +02:00

perf(transactions): add kind to Transaction model and remove expensive Transfer joins in aggregations (#2388)

* add kind to transaction model

* Basic transfer creator

* Fix method naming conflict

* Creator form pattern

* Remove stale methods

* Tweak migration

* Remove BaseQuery, write entire query in each class for clarity

* Query optimizations

* Remove unused exchange rate query lines

* Remove temporary cache-warming strategy

* Fix test

* Update transaction search

* Decouple transactions endpoint from IncomeStatement

* Clean up transactions controller

* Update cursor rules

* Cleanup comments, logic in search

* Fix totals logic on transactions view

* Fix pagination

* Optimize search totals query

* Default to last 30 days on transactions page if no filters

* Decouple transactions list from transfer details

* Revert transfer route

* Migration reset

* Bundle update

* Fix matching logic, tests

* Remove unused code
This commit is contained in:
Zach Gollwitzer 2025-06-20 13:31:58 -04:00 committed by GitHub
parent 7aca5a2277
commit 1aae00f586
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
49 changed files with 1749 additions and 705 deletions

View file

@ -1,43 +0,0 @@
module IncomeStatement::BaseQuery
private
def base_query_sql(family:, interval:, transactions_scope:)
sql = <<~SQL
SELECT
c.id as category_id,
c.parent_id as parent_category_id,
date_trunc(:interval, ae.date) as date,
CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END as classification,
SUM(ae.amount * COALESCE(er.rate, 1)) as total,
COUNT(ae.id) as transactions_count,
BOOL_OR(ae.currency <> :target_currency AND er.rate IS NULL) as missing_exchange_rates
FROM (#{transactions_scope.to_sql}) at
JOIN entries ae ON ae.entryable_id = at.id AND ae.entryable_type = 'Transaction'
LEFT JOIN categories c ON c.id = at.category_id
LEFT JOIN (
SELECT t.*, t.id as transfer_id, a.accountable_type
FROM transfers t
JOIN entries ae ON ae.entryable_id = t.inflow_transaction_id
AND ae.entryable_type = 'Transaction'
JOIN accounts a ON a.id = ae.account_id
) transfer_info ON (
transfer_info.inflow_transaction_id = at.id OR
transfer_info.outflow_transaction_id = at.id
)
LEFT JOIN exchange_rates er ON (
er.date = ae.date AND
er.from_currency = ae.currency AND
er.to_currency = :target_currency
)
WHERE (
transfer_info.transfer_id IS NULL OR
(ae.amount > 0 AND transfer_info.accountable_type = 'Loan')
)
GROUP BY 1, 2, 3, 4
SQL
ActiveRecord::Base.sanitize_sql_array([
sql,
{ target_currency: family.currency, interval: interval }
])
end
end

View file

@ -1,40 +1,61 @@
class IncomeStatement::CategoryStats
include IncomeStatement::BaseQuery
def initialize(family, interval: "month")
@family = family
@interval = interval
end
def call
ActiveRecord::Base.connection.select_all(query_sql).map do |row|
ActiveRecord::Base.connection.select_all(sanitized_query_sql).map do |row|
StatRow.new(
category_id: row["category_id"],
classification: row["classification"],
median: row["median"],
avg: row["avg"],
missing_exchange_rates?: row["missing_exchange_rates"]
avg: row["avg"]
)
end
end
private
StatRow = Data.define(:category_id, :classification, :median, :avg, :missing_exchange_rates?)
StatRow = Data.define(:category_id, :classification, :median, :avg)
def sanitized_query_sql
ActiveRecord::Base.sanitize_sql_array([
query_sql,
{
target_currency: @family.currency,
interval: @interval,
family_id: @family.id
}
])
end
def query_sql
base_sql = base_query_sql(family: @family, interval: @interval, transactions_scope: @family.transactions.active)
<<~SQL
WITH base_totals AS (
#{base_sql}
WITH period_totals AS (
SELECT
c.id as category_id,
date_trunc(:interval, ae.date) as period,
CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END as classification,
SUM(ae.amount * COALESCE(er.rate, 1)) as total
FROM transactions t
JOIN entries ae ON ae.entryable_id = t.id AND ae.entryable_type = 'Transaction'
JOIN accounts a ON a.id = ae.account_id
LEFT JOIN categories c ON c.id = t.category_id
LEFT JOIN exchange_rates er ON (
er.date = ae.date AND
er.from_currency = ae.currency AND
er.to_currency = :target_currency
)
WHERE a.family_id = :family_id
AND t.kind NOT IN ('funds_movement', 'one_time', 'cc_payment')
GROUP BY c.id, period, CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END
)
SELECT
category_id,
classification,
ABS(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY total)) as median,
ABS(AVG(total)) as avg,
BOOL_OR(missing_exchange_rates) as missing_exchange_rates
FROM base_totals
category_id,
classification,
ABS(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY total)) as median,
ABS(AVG(total)) as avg
FROM period_totals
GROUP BY category_id, classification;
SQL
end

View file

@ -1,46 +1,57 @@
class IncomeStatement::FamilyStats
include IncomeStatement::BaseQuery
def initialize(family, interval: "month")
@family = family
@interval = interval
end
def call
ActiveRecord::Base.connection.select_all(query_sql).map do |row|
ActiveRecord::Base.connection.select_all(sanitized_query_sql).map do |row|
StatRow.new(
classification: row["classification"],
median: row["median"],
avg: row["avg"],
missing_exchange_rates?: row["missing_exchange_rates"]
avg: row["avg"]
)
end
end
private
StatRow = Data.define(:classification, :median, :avg, :missing_exchange_rates?)
StatRow = Data.define(:classification, :median, :avg)
def sanitized_query_sql
ActiveRecord::Base.sanitize_sql_array([
query_sql,
{
target_currency: @family.currency,
interval: @interval,
family_id: @family.id
}
])
end
def query_sql
base_sql = base_query_sql(family: @family, interval: @interval, transactions_scope: @family.transactions.active)
<<~SQL
WITH base_totals AS (
#{base_sql}
), aggregated_totals AS (
WITH period_totals AS (
SELECT
date,
classification,
SUM(total) as total,
BOOL_OR(missing_exchange_rates) as missing_exchange_rates
FROM base_totals
GROUP BY date, classification
date_trunc(:interval, ae.date) as period,
CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END as classification,
SUM(ae.amount * COALESCE(er.rate, 1)) as total
FROM transactions t
JOIN entries ae ON ae.entryable_id = t.id AND ae.entryable_type = 'Transaction'
JOIN accounts a ON a.id = ae.account_id
LEFT JOIN exchange_rates er ON (
er.date = ae.date AND
er.from_currency = ae.currency AND
er.to_currency = :target_currency
)
WHERE a.family_id = :family_id
AND t.kind NOT IN ('funds_movement', 'one_time', 'cc_payment')
GROUP BY period, CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END
)
SELECT
classification,
ABS(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY total)) as median,
ABS(AVG(total)) as avg,
BOOL_OR(missing_exchange_rates) as missing_exchange_rates
FROM aggregated_totals
classification,
ABS(PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY total)) as median,
ABS(AVG(total)) as avg
FROM period_totals
GROUP BY classification;
SQL
end

View file

@ -1,6 +1,4 @@
class IncomeStatement::Totals
include IncomeStatement::BaseQuery
def initialize(family, transactions_scope:)
@family = family
@transactions_scope = transactions_scope
@ -13,31 +11,47 @@ class IncomeStatement::Totals
category_id: row["category_id"],
classification: row["classification"],
total: row["total"],
transactions_count: row["transactions_count"],
missing_exchange_rates?: row["missing_exchange_rates"]
transactions_count: row["transactions_count"]
)
end
end
private
TotalsRow = Data.define(:parent_category_id, :category_id, :classification, :total, :transactions_count, :missing_exchange_rates?)
TotalsRow = Data.define(:parent_category_id, :category_id, :classification, :total, :transactions_count)
def query_sql
base_sql = base_query_sql(family: @family, interval: "day", transactions_scope: @transactions_scope)
ActiveRecord::Base.sanitize_sql_array([
optimized_query_sql,
sql_params
])
end
# OPTIMIZED: Direct SUM aggregation without unnecessary time bucketing
# Eliminates CTE and intermediate date grouping for maximum performance
def optimized_query_sql
<<~SQL
WITH base_totals AS (
#{base_sql}
)
SELECT
parent_category_id,
category_id,
classification,
ABS(SUM(total)) as total,
BOOL_OR(missing_exchange_rates) as missing_exchange_rates,
SUM(transactions_count) as transactions_count
FROM base_totals
GROUP BY 1, 2, 3;
c.id as category_id,
c.parent_id as parent_category_id,
CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END as classification,
ABS(SUM(ae.amount * COALESCE(er.rate, 1))) as total,
COUNT(ae.id) as transactions_count
FROM (#{@transactions_scope.to_sql}) at
JOIN entries ae ON ae.entryable_id = at.id AND ae.entryable_type = 'Transaction'
LEFT JOIN categories c ON c.id = at.category_id
LEFT JOIN exchange_rates er ON (
er.date = ae.date AND
er.from_currency = ae.currency AND
er.to_currency = :target_currency
)
WHERE at.kind NOT IN ('funds_movement', 'one_time', 'cc_payment')
GROUP BY c.id, c.parent_id, CASE WHEN ae.amount < 0 THEN 'income' ELSE 'expense' END;
SQL
end
def sql_params
{
target_currency: @family.currency
}
end
end