-- This template returns a monthly summary of your activities, including all payments in the UTC time zone
-- Note: this query may need to be modified to handle additional payout/transfer types if you are using Connect
-- monthly_balance_transactions is a temporary table that aggregates and pivots different
-- balance_transaction types on a monthly basis for each currency
-- Note: only months with at least 1 balance transaction will be returned
with monthly_balance_transactions as (
select
date_trunc('month', case when type = 'payout' then available_on else created end) as month, -- payouts are considered when they are posted (available_on)
currency,
sum(case when type in ('charge', 'payment') then amount else 0 end) as sales,
sum(case when type in ('payment_refund', 'refund') then amount else 0 end) as refunds,
sum(case when type = 'adjustment' then amount else 0 end) as adjustments,
sum(case when type not in ('charge', 'payment', 'payment_refund', 'refund', 'adjustment', 'payout') and type not like '%transfer%' then amount else 0 end) as other,
sum(case when type <> 'payout' and type not like '%transfer%' then amount else 0 end) as gross_transactions,
sum(case when type <> 'payout' and type not like '%transfer%' then net else 0 end) as net_transactions,
sum(case when type = 'payout' or type like '%transfer%' then fee * -1.0 else 0 end) as payout_fees,
sum(case when type = 'payout' or type like '%transfer%' then amount else 0 end) as gross_payouts,
sum(case when type = 'payout' or type like '%transfer%' then fee * -1.0 else net end) as monthly_net_activity,
count_if(type in ('payment', 'charge')) as sales_count,
count_if(type = 'payout') as payouts_count,
count(distinct case when type = 'adjustment' then source_id end) as adjustments_count
from balance_transactions
group by 1, 2
)
-- Compute the month_end_balance for each month and format output
-- Note: if you have currencies that do not have cents (e.g. JPY), you should not divide by 100.0
select
date_format(month, '%Y-%m') as month,
currency,
sales / 100.0 as sales,
refunds / 100.0 as refunds,
adjustments/100.0 as adjustments,
other / 100.0 as other,
gross_transactions / 100.0 as gross_transactions,
net_transactions / 100.0 as net_transactions,
payout_fees / 100.0 as payout_fees,
gross_payouts / 100.0 as gross_payouts,
monthly_net_activity/100.0 as monthly_net_activity,
sum(monthly_net_activity + gross_payouts) over(partition by currency order by month)/100.0 as month_end_balance, -- use SUM Window Function
sales_count,
payouts_count,
adjustments_count
from monthly_balance_transactions
where month < date_trunc('month', current_date) -- exclude current, partial month
order by 1 desc, 2