From c48054179b085e06e8cc63199443bb2c0d449f2a Mon Sep 17 00:00:00 2001 From: yrzam Date: Sun, 10 Dec 2023 23:02:12 +0400 Subject: [PATCH] new view --- .gitignore | 2 +- README.md | 11 +++++++++-- schema.sql | 54 +++++++++++++++++++++++++++++++++++++++++++++++++++++- 3 files changed, 63 insertions(+), 4 deletions(-) diff --git a/.gitignore b/.gitignore index 76e579a..4192976 100644 --- a/.gitignore +++ b/.gitignore @@ -1,2 +1,2 @@ test - +.wakatime-project \ No newline at end of file diff --git a/README.md b/README.md index 3e19a1b..9c9d225 100644 --- a/README.md +++ b/README.md @@ -183,18 +183,25 @@ This table is not historical. Shows current asset allocation calculated based on your balance and exchange rates. Both current and target shares are displayed. +### historical_monthly_txs_balances_mismatch (view) + +Allows to keep balances consistent with transactions for the analytical purposes. + +This view contains a row only if there is a mismatch between transaction delta and balance delta during the last 2 years. It is advised to keep this view empty via adding missing transactions or adjusting balances on a monthly basis. + + ### historical_monthly_balances (view) Shows monthly balance with source, calculates deltas - total and grouped by asset type. -Data is calculated over 10 years with a period of 1 month for the last day of that month. +Data is calculated over the last 10 years with a period of 1 month for the last day of that month. ``` base_balance - total balance, converted to the base asset base_balance_delta - balance change since the previous month base_active_delta - delta (gains - losses) for all transactions that are not passive income/expenses and occurred during this month base_passive_delta - balance change caused by exchange rate fluctuations, passive income/expenses, non-specified transactions -*_by_type - same data but per asset type +*_by_type - same data but per asset type, represented as a concatenated string ... ``` diff --git a/schema.sql b/schema.sql index 4adab84..ca25e5d 100644 --- a/schema.sql +++ b/schema.sql @@ -447,9 +447,61 @@ from where t.base_balance is not null ) t - left join fin_asset_types fat on fat.id=t.asset_type_id + join fin_asset_types fat on fat.id=t.asset_type_id group by 1 order by t.date desc /* historical_monthly_balances(date,base_balance,base_balance_delta,base_active_delta,base_passive_delta,base_asset,base_balance_by_type,base_balance_delta_by_type,base_active_delta_by_type,base_passive_delta_by_type) */; +CREATE VIEW historical_monthly_txs_balances_mismatch as +with recursive dates(mo_start_date, date) as ( + values( + date('now', 'start of month'), + date('now', 'start of month', '+1 month', '-1 day') + ) + union all + select + date(mo_start_date, '-1 month'), + date(mo_start_date, '-1 day') + from + dates + where + mo_start_date > (select min(date) from balances) or + mo_start_date > (select min(date) from fin_transactions) + limit 2*12 -- 2 years +), +constants as ( + select + (select min(mo_start_date) from dates) as start_date +) + +select + t.mo_start_date as start_date, + t.date as end_date, + fs.name as storage, + t.balance_delta - t.tx_delta as amount_unaccounted, + coalesce(fa.code,fa.name) as asset, + t.tx_delta, + t.balance_delta +from ( + select + d.*, + fas.asset_id as asset_id, + fas.storage_id as storage_id, + coalesce((select sum(amount) from fin_transactions ft where ft.asset_storage_id=fas.id and ft.date>=d.mo_start_date and ft.date<=d.date),0) as tx_delta, + coalesce(( + select b.amount from balances b where b.asset_storage_id=fas.id and b.date<=d.date order by b.date desc limit 1 + ),0) - coalesce(( + select coalesce(b.amount,0) from balances b where b.asset_storage_id=fas.id and b.date