Skip to content

Commit

Permalink
feat(book_ops): handle non-USD assets in balanceSheet
Browse files Browse the repository at this point in the history
  • Loading branch information
dckc committed Feb 5, 2024
1 parent 47ed8e7 commit 5f3a0c5
Showing 1 changed file with 79 additions and 31 deletions.
110 changes: 79 additions & 31 deletions packages/brcal/src/book_ops.sql
Original file line number Diff line number Diff line change
Expand Up @@ -150,52 +150,100 @@ select 5 o, n.* from net_income n
order by o, path
;

-- balanceSheet:
with period as (select '2021-12-31' as hi)
, acct as (
select code, guid, name
, case account_type
drop view if exists accounting_period;
create VIEW accounting_period as
select null lo, '2022-12-31' hi
union all
select null lo, '2023-12-31' hi
;
select * from accounting_period ;

drop view if exists asset_price;
create view asset_price as
with price_yr as (
select substr(date, 1, 4) yr, 1.0 * value_num / value_denom price, date, commodity_guid , currency_guid from prices
)
, price_ix as (
select row_number() over (partition by yr, commodity_guid order by date desc) ix, price_yr.*
from price_yr
)
select s.mnemonic symbol, c.mnemonic currency, p.*
from price_ix p
join commodities s on p.commodity_guid =s.guid
join commodities c on p.currency_guid =c.guid
where ix = 1
and c.namespace ='CURRENCY' and c.mnemonic='USD'
order by symbol, yr
;

drop view if exists balance_by_acct;
create view balance_by_acct as
with s as (
select date(tx.post_date) tx_date, tx.description
, 1.0 * value_num / value_denom value
, 1.0 * quantity_num / quantity_denom qty
, s.account_guid
-- , s.*
from transactions tx
join splits s on tx.guid = s.tx_guid
),
dur_acct as (
select dur.hi, account_guid
, round(sum(qty), 4) qty
, count(tx_date) tx_ct
, round(sum(value), 2) value
from accounting_period dur
join s on s.tx_date <= dur.hi
group by dur.hi, account_guid
)
select substr(da.hi, 1, 4) yr
, case account_type
when 'MUTUAL' then 'ASSET'
when 'CREDIT' then 'LIABILITY'
when 'BANK' then 'ASSET'
when 'CASH' then 'ASSET'
when 'RECEIVABLE' then 'ASSET'
else account_type end account_type
from accounts
where account_type not in ('INCOME', 'EXPENSE')
and commodity_guid in (select guid from commodities where mnemonic = 'USD')
)
, tx as (select post_date, guid from transactions join period where date(post_date) <= hi)
, split as (
select tx_guid, account_guid, code, account_type, s.value_num * 1.0 / s.value_denom value from splits s
join tx on s.tx_guid = tx.guid
join acct on s.account_guid = acct.guid
)
, by_acct as (
select account_type, code, a.path, round(sum(value), 2) balance -- TODO: parameterize 2 by log10(commodities.fraction)
from split join account_tree a on split.account_guid = a.guid
where a.path not like 'History:%'
group by split.account_guid
)
, by_type as (
select account_type, null, 'Total:', round(sum(balance), 2)
from by_acct
group by account_type
else account_type
end account_type
, tr.path
, da.qty
, case when ap.symbol is null then null else ap.symbol || '@' || round(ap.price, 4) end symbol
, case when ap.symbol is null then qty else round(da.qty * ap.price, 2) end balance
-- , da.*
from dur_acct da
join account_tree tr on tr.guid = account_guid
join accounts a on a.guid = account_guid
left join asset_price ap on a.commodity_guid = ap.commodity_guid and substr(da.hi, 1, 4) = ap.yr
where account_type not in ('INCOME', 'EXPENSE')
and da.qty != 0
order by da.hi, tr.path
;

select * from balance_by_acct order by yr, account_type, path;


-- balanceSheet:
with by_type as (
select yr, account_type, 'Total ' || account_type account_type, null, null, round(sum(balance), 2)
from balance_by_acct
group by yr, account_type
)
, net_worth as (
select hi, null, 'Net Worth', round(sum(balance), 2)
from by_acct join period
select yr, null, 'Net Worth', null, null, round(sum(balance), 2)
from balance_by_acct
where account_type in ('ASSET', 'LIABILITY')
group by yr
)
select 1 o, a.* from by_acct a where account_type = 'ASSET' and (balance < 0 or balance > 0)
select 1 o, a.* from balance_by_acct a where account_type = 'ASSET' and (balance < 0 or balance > 0)
union all
select 2 o, t.* from by_type t where account_type = 'ASSET'
union all
select 3 o, a.* from by_acct a where account_type = 'LIABILITY' and balance != 0
select 3 o, a.* from balance_by_acct a where account_type = 'LIABILITY' and balance != 0
union all
select 4 o, t.* from by_type t where account_type = 'LIABILITY'
union ALL
select 5 o, n.* from net_worth n
order by o, path
order by yr, o, path
;

-- TODO: 1099-B
Expand Down

0 comments on commit 5f3a0c5

Please sign in to comment.