Skip to content

Commit

Permalink
Refactor rolling total queries
Browse files Browse the repository at this point in the history
  • Loading branch information
JoshAntBrown committed Apr 23, 2024
1 parent 1b66160 commit d3b4d55
Show file tree
Hide file tree
Showing 3 changed files with 39 additions and 31 deletions.
31 changes: 2 additions & 29 deletions app/models/family.rb
Original file line number Diff line number Diff line change
Expand Up @@ -49,38 +49,11 @@ def snapshot_account_transactions
end

def snapshot_transactions
period = Period.last_30_days
days_rolling = period.date_range.count

start_date = period.date_range.first - days_rolling.days
end_date = period.date_range.last
sql_dates = self.class.sanitize_sql([ "generate_series(?, ?, interval '1 day') AS gs(date)", start_date, end_date ])

normalized_query = Transaction
.select(
"gs.date",
"COALESCE(SUM(converted_amount) FILTER (WHERE converted_amount > 0), 0) AS spending",
"COALESCE(SUM(-converted_amount) FILTER (WHERE converted_amount < 0), 0) AS income"
)
.from(transactions.with_converted_amount, :t)
.joins("RIGHT JOIN #{sql_dates} ON t.date = gs.date")
.group("gs.date")

rolling_query = Transaction
.from(normalized_query, :v)
.select(
"v.*",
"SUM(spending) OVER (ORDER BY date RANGE BETWEEN INTERVAL '#{days_rolling.to_i} days' PRECEDING AND CURRENT ROW) as rolling_spend",
"SUM(income) OVER (ORDER BY date RANGE BETWEEN INTERVAL '#{days_rolling.to_i} days' PRECEDING AND CURRENT ROW) as rolling_income"
)
.order("date")

query = Transaction.select("*").from(rolling_query, :rq)
query = query.where("date >= ?", period.date_range.begin) if period.date_range.begin
rolling_totals = Transaction.daily_rolling_totals(transactions, period: Period.last_30_days)

spending = []
income = []
query.each do |r|
rolling_totals.each do |r|
spending << {
date: r.date,
value: Money.new(r.rolling_spend, self.currency)
Expand Down
4 changes: 4 additions & 0 deletions app/models/period.rb
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,10 @@ def initialize(name: "custom", date_range:)
@date_range = date_range
end

def extend_backward(duration)
Period.new(name: name + "_extended", date_range: (date_range.first - duration)..date_range.last)
end

BUILTIN = [
new(name: "all", date_range: nil..Date.current),
new(name: "last_7_days", date_range: 7.days.ago.to_date..Date.current),
Expand Down
35 changes: 33 additions & 2 deletions app/models/transaction.rb
Original file line number Diff line number Diff line change
Expand Up @@ -12,14 +12,45 @@ class Transaction < ApplicationRecord
scope :outflows, -> { where("amount < 0") }
scope :active, -> { where(excluded: false) }
scope :with_converted_amount, ->(currency = Current.family.currency) {
# Join with exchange rates to convert the amount to the given currency
# If no rate is available, exclude the transaction from the results
select(
"transactions.*",
"transactions.amount * COALESCE(er.rate, 1) AS converted_amount"
)
.joins(sanitize_sql_array([ "LEFT JOIN exchange_rates er ON transactions.date = er.date AND transactions.currency = er.base_currency AND er.converted_currency = ?", currency ]))
.where("er.rate IS NOT NULL OR transactions.currency = ?", currency)
.joins(sanitize_sql_array([ "LEFT JOIN exchange_rates er ON transactions.date = er.date AND transactions.currency = er.base_currency AND er.converted_currency = ?", currency ]))
.where("er.rate IS NOT NULL OR transactions.currency = ?", currency)
}

def self.daily_totals(transactions, period: Period.last_30_days, currency: Current.family.currency)
# Sum spending and income for each day in the period with the given currency
select(
"gs.date",
"COALESCE(SUM(converted_amount) FILTER (WHERE converted_amount > 0), 0) AS spending",
"COALESCE(SUM(-converted_amount) FILTER (WHERE converted_amount < 0), 0) AS income"
)
.from(transactions.with_converted_amount(currency), :t)
.joins(sanitize_sql([ "RIGHT JOIN generate_series(?, ?, interval '1 day') AS gs(date) ON t.date = gs.date", period.date_range.first, period.date_range.last ]))
.group("gs.date")
end

def self.daily_rolling_totals(transactions, period: Period.last_30_days)
# Extend the period to include the rolling window
period_with_rolling = period.extend_backward(period.date_range.count.days)

# Aggregate the rolling sum of spending and income based on daily totals
rolling_totals = from(daily_totals(transactions, period: period_with_rolling))
.select(
"*",
sanitize_sql_array([ "SUM(spending) OVER (ORDER BY date RANGE BETWEEN INTERVAL ? PRECEDING AND CURRENT ROW) as rolling_spend", "#{period.date_range.count} days" ]),
sanitize_sql_array([ "SUM(income) OVER (ORDER BY date RANGE BETWEEN INTERVAL ? PRECEDING AND CURRENT ROW) as rolling_income", "#{period.date_range.count} days" ])
)
.order("date")

# Trim the results to the original period
select("*").from(rolling_totals).where("date >= ?", period.date_range.first)
end

def self.ransackable_attributes(auth_object = nil)
%w[name amount date]
end
Expand Down

0 comments on commit d3b4d55

Please sign in to comment.