fixes & new view

This commit is contained in:
yrzam 2024-03-04 03:37:23 +04:00
parent 8e114fadd7
commit d49893a481
2 changed files with 201 additions and 42 deletions

View File

@ -260,7 +260,7 @@ This is a core table of financial planning. It allows to specify expected transa
Transaction plan describes a value delta tied to a specific `transaction category`. Parent category involves child categories, so any subtree of hierarchy may be covered. Plan may be also constrained with a specific `asset & storage`.
Plan may be single-run or recurrent. This is defined by presence of `recurrence_datetime_modifier` which forms the date sequence, possibly ended by `end_datetime`. A `deviation_datetime_modifier` must be set to provide the allowed deviation of the factual datetime from the planned datetime. Plan execution is defined by plan/fact amounts and `criteria_operator` (less, more, etc.).
Plan may be single-run or recurrent. This is defined by presence of `recurrence_datetime_modifiers` which forms the date sequence, possibly ended by `end_datetime`. A `deviation_datetime_modifier` must be set to provide the allowed deviation of the factual datetime from the planned datetime. Plan execution is defined by plan/fact amounts and `criteria_operator` (less, more, etc.).
Balance may be nominated either in the base asset or in the asset of `asset & storage`. For recurrent plans, it is also possible to set the multiplier of amount per each iteration.
@ -270,12 +270,12 @@ transaction_category_id (fk fin_transaction_categories not null) - transact
criteria_operator (text not null) - comparison operator used between desired amount and planned amount, one of [= > < <= >=]. For negative amounts, standard mathematical rules apply so that "more" operator leads to a greater balance
start_datetime (datetime as text not null) - target transaction(s) datetime, for recurrent plan it defines datetime of the first iteration.
end_datetime (datetime as text) - stops the recurrent sequence.
recurrence_datetime_modifier (semicolon separated datetime modifiers, up to 3, as text) - if set, it is used to make a possibly infinite sequence of datetime values, thus making the plan recurrent. Result must only increase. Last moment is defined by end_datetime if it is set.
recurrence_datetime_modifiers (semicolon separated datetime modifiers, up to 3, as text) - if set, it is used to make a possibly infinite sequence of datetime values, thus making the plan recurrent. Result must only increase. Last moment is defined by end_datetime if it is set.
recurrence_amount_multiplier (real) - for recurrent plans, every subsequent amount will equal previous amount multiplied by this value, aka p=a*mult^N, where N starts with 0. Value of 1 used if not set.
deviation_datetime_modifier (reversible positive datetime modifier as text not null) - allowed deviation of transactions' datetime from the plan datetime. plan datetime += deviation defines a range in which tx delta is calculated.
asset_storage_id (fk fin_assets_storages not null) asset storage which target transactions are going to be applied to.
local_amount (real) - amount in the currency of asset storage, allowed if base_amount is not set.
base_amount (real) - amount in the base currency, allowed if local_amount not set.
base_amount (real) - amount in the base currency, allowed if local_amount not set.
```
@ -371,6 +371,40 @@ info:
```
### historical_monthly_balances
Shows monthly changes of balances, both total and detailed by the asset type. It also summarizes transaction data in order to present the following categories:
* balance delta - change of the balance since the previous month
* active delta - change caused by active profits and losses (transactions)
* passive delta - changes caused by passive profits and losses (transactions) and by fluctuations of the exchange rates
* unaccounted delta - changes:
* not reflected in transactions
* caused by initial import of assets
* caused by the swap of one financial asset to another. In that case, amount is calculated based on the credit transaction amount for both source and destination and then converted to the base asset. Thus, total amount always equals zero, although for cross-type conversions it will equal the same amount with the opposite sign. Spread losses are counted as passive losses.
> operations: select
```
info:
start_datetime
end_datetime
base_balance - total balance
base_balance_delta - total balance change since prev month
base_active_delta
base_passive_delta
base_unaccounted_delta
base_asset
base_balance_by_type
base_balance_delta_by_type
base_active_delta_by_type
base_passive_delta_by_type
base_unaccounted_delta_by_type
```
For the most accurate results, `balances` and `fin_asset_rates` should be up-to-date right before the month ends. Note that transaction datetimes must be less then datetime of the balance snapshot. For exchange transactions, `fin_asset_rates` should be up-to-date for the asset which was sent at a datetime of sending transaction (otherwise the most recent rate at that time will be used).
### current_balance_goals (view)
View that shows statuses of all goals (amount left, whether goal is accomplished, etc.).

View File

@ -100,15 +100,15 @@ CREATE TABLE "fin_transaction_plans" (
"criteria_operator" TEXT NOT NULL CHECK("criteria_operator" IN ('<', '>', '=', '<=', '>=')),
"start_datetime" TEXT NOT NULL CHECK("start_datetime" IS datetime("start_datetime")),
"end_datetime" TEXT CHECK("end_datetime" IS datetime("end_datetime")),
"recurrence_datetime_modifier" TEXT,
"recurrence_datetime_modifiers" TEXT,
"recurrence_amount_multiplier" REAL,
"deviation_datetime_modifier" TEXT NOT NULL,
"asset_storage_id" INTEGER CHECK(NOT ("asset_storage_id" IS null AND "local_amount" IS NOT null)),
"local_amount" REAL CHECK(NOT ("asset_storage_id" IS null AND "local_amount" IS NOT null) AND coalesce("base_amount", "local_amount") IS NOT null AND "base_amount" + "local_amount" IS null),
"base_amount" REAL CHECK(coalesce("base_amount", "local_amount") IS NOT null AND "base_amount" + "local_amount" IS null),
FOREIGN KEY("asset_storage_id") REFERENCES "fin_assets_storages"("id"),
PRIMARY KEY("id"),
FOREIGN KEY("transaction_category_id") REFERENCES "fin_transaction_categories"("id")
FOREIGN KEY("transaction_category_id") REFERENCES "fin_transaction_categories"("id"),
FOREIGN KEY("asset_storage_id") REFERENCES "fin_assets_storages"("id")
);
CREATE TABLE "fin_transactions" (
@ -143,24 +143,26 @@ CREATE TABLE "phys_assets" (
);
CREATE TABLE "swaps" (
"id" INTEGER NOT NULL,
"credit_fin_transaction_id" INTEGER UNIQUE,
"credit_phys_ownership_id" INTEGER UNIQUE,
"debit_fin_transaction_id" INTEGER UNIQUE,
"debit_phys_ownership_id" INTEGER UNIQUE,
FOREIGN KEY("debit_fin_transaction_id") REFERENCES "fin_transactions"("id"),
FOREIGN KEY("credit_phys_ownership_id") REFERENCES "phys_asset_ownerships"("id"),
FOREIGN KEY("debit_phys_ownership_id") REFERENCES "phys_asset_ownerships"("id"),
FOREIGN KEY("credit_fin_transaction_id") REFERENCES "fin_transactions"("id")
FOREIGN KEY("debit_fin_transaction_id") REFERENCES "fin_transactions"("id"),
FOREIGN KEY("credit_fin_transaction_id") REFERENCES "fin_transactions"("id"),
FOREIGN KEY("credit_phys_ownership_id") REFERENCES "phys_asset_ownerships"("id"),
PRIMARY KEY("id")
);
CREATE INDEX "balance_goals_end_datetime_part_no_result" ON "balance_goals" (
"end_datetime" DESC
) WHERE result_transaction_id is not null;
CREATE INDEX "i_balance_goals_asset_storage_id" ON "balance_goals" (
"asset_storage_id"
);
CREATE INDEX "i_balance_goals_end_datetime_part_no_result" ON "balance_goals" (
"end_datetime" DESC
) WHERE "result_transaction_id" IS NOT null;
CREATE INDEX "i_balance_goals_result_transaction_id" ON "balance_goals" (
"result_transaction_id"
);
@ -229,22 +231,6 @@ CREATE INDEX "i_phys_asset_ownerships_asset_id_end_datetime" ON "phys_asset_owne
"end_datetime" DESC
);
CREATE INDEX "i_swaps_credit_fin_transaction_id" ON "swaps" (
"credit_fin_transaction_id"
);
CREATE INDEX "i_swaps_credit_phys_ownership_id" ON "swaps" (
"credit_phys_ownership_id"
);
CREATE INDEX "i_swaps_debit_fin_transaction_id" ON "swaps" (
"debit_fin_transaction_id"
);
CREATE INDEX "i_swaps_debit_phys_ownership_id" ON "swaps" (
"debit_phys_ownership_id"
);
CREATE TRIGGER fin_transaction_categories_insert after insert on fin_transaction_categories
begin
with recursive
@ -383,7 +369,8 @@ from (
from
balances b
where
b.asset_storage_id=bg.asset_storage_id
b.asset_storage_id=bg.asset_storage_id and
b.datetime<=datetime('now')
order by
b.datetime desc
limit 1
@ -414,11 +401,11 @@ from (
fat.name as asset_type,
coalesce(fa.code,fa.name) as asset_name,
fs.name as storage,
(select b.amount from balances b where b.asset_storage_id=fas.id order by b.datetime desc limit 1) as balance,
(select b.amount from balances b where b.asset_storage_id=fas.id and b.datetime<=datetime('now') order by b.datetime desc limit 1) as balance,
fa.code as asset_code,
round(
(select b.amount from balances b where b.asset_storage_id=fas.id order by b.datetime desc limit 1)*
(select far.rate from fin_asset_rates far where far.asset_id=fa.id order by far.datetime desc limit 1),
(select b.amount from balances b where b.asset_storage_id=fas.id and b.datetime<=datetime('now') order by b.datetime desc limit 1)*
(select far.rate from fin_asset_rates far where far.asset_id=fa.id and far.datetime<=datetime('now') order by far.datetime desc limit 1),
2) as base_balance,
(select code from fin_assets fa2 where fa2.is_base limit 1) as base_asset
from
@ -457,8 +444,8 @@ from (
fag.priority,
coalesce(
sum(
(select b.amount from balances b where b.asset_storage_id=fas.id order by b.datetime desc limit 1)*
(select far.rate from fin_asset_rates far where far.asset_id=fa.id order by far.datetime desc limit 1)
(select b.amount from balances b where b.asset_storage_id=fas.id and b.datetime<=datetime('now') order by b.datetime desc limit 1)*
(select far.rate from fin_asset_rates far where far.asset_id=fa.id and far.datetime<=datetime('now') order by far.datetime desc limit 1)
),
0) as base_balance,
fag.target_share * 100 / sum(abs(fag.target_share)) over () as target_share
@ -483,8 +470,8 @@ from (
select
'Others' as name,
sum(
(select b.amount from balances b where b.asset_storage_id=fas.id order by b.datetime desc limit 1)*
(select far.rate from fin_asset_rates far where far.asset_id=fa.id order by far.datetime desc limit 1)
(select b.amount from balances b where b.asset_storage_id=fas.id and b.datetime<=datetime('now') order by b.datetime desc limit 1)*
(select far.rate from fin_asset_rates far where far.asset_id=fa.id and far.datetime<=datetime('now') order by far.datetime desc limit 1)
) as base_balance,
null as current_share,
null as target_share,
@ -502,14 +489,15 @@ from (
where
t.base_balance!=0 or t.target_share!=0
order by
sort1 desc, priority desc;
sort1 desc,
priority desc;
CREATE VIEW "current_fin_asset_rates" as
select
fa.id as pseudo_id,
fat.name as asset_type,
fa.code as asset,
(select rate from fin_asset_rates far where far.asset_id=fa.id order by far.datetime desc limit 1) as rate,
(select rate from fin_asset_rates far where far.asset_id=fa.id and far.datetime<=datetime('now') order by far.datetime desc limit 1) as rate,
(select fa2.code from fin_assets fa2 where fa2.is_base limit 1) as base_asset
from
fin_assets fa
@ -517,14 +505,150 @@ from
where
fa.is_active;
CREATE VIEW historical_monthly_balances as
with recursive
datetimes(start_datetime, end_datetime) as materialized (
select
datetime('now','start of month') as start_datetime,
datetime('now','start of month','+1 month','-1 second') as end_datetime
union all
select
datetime(start_datetime,'-1 month') as start_datetime,
datetime(start_datetime,'-1 second') as end_datetime
from
datetimes
where
start_datetime>=(select min(datetime) from balances)
limit 5*12
),
constants as(
select
(select code from fin_assets fa2 where fa2.is_base limit 1) as base_asset
),
data_by_asset as materialized (
select
b.start_datetime,
b.end_datetime,
b.asset_id,
(select far.rate from fin_asset_rates far where far.asset_id=b.asset_id and far.datetime<=b.end_datetime order by far.datetime desc limit 1) as end_asset_rate,
b.balance as balance,
coalesce(tx.total_delta,0) as tx_total_delta,
coalesce(tx.active_delta,0) as tx_active_delta,
coalesce(tx.base_excluded_delta,0) as base_tx_excluded_delta
from
( -- balances by asset
select
d.start_datetime,
d.end_datetime,
fas.asset_id,
sum(
(select b.amount from balances b where b.asset_storage_id=fas.id and b.datetime<=d.end_datetime order by b.datetime desc limit 1)
) as balance
from
datetimes d,
fin_assets_storages fas
group by
1,2,3
) b
left join ( -- txs by asset
select
d.start_datetime,
d.end_datetime,
fas.asset_id,
sum(ft.amount) as total_delta,
sum(ft.amount) filter(where not ftc.is_passive and not ftc.is_initial_import and s.id is null) as active_delta,
( -- exclude txs:
-- 1) initial import
coalesce(
sum(
ft.amount*
(select far.rate from fin_asset_rates far where far.asset_id=fas.asset_id and far.datetime<=ft.datetime order by far.datetime desc limit 1)
)
filter(where ftc.is_initial_import and s.id is null)
,0) +
-- 2) fin -> fin swap, counted by credit amount
coalesce(
sum(
s_cred_ft.amount*
(case when s.credit_fin_transaction_id=ft.id then 1 else -1 end)* -- if transaction is debit, take credit with the opposite sign
(select far.rate from fin_asset_rates far where far.asset_id=s_cred_fas.asset_id and far.datetime<=ft.datetime order by far.datetime desc limit 1)
)
filter(where s.id is not null)
,0)
) as base_excluded_delta
from
datetimes d
join fin_transactions ft on ft.datetime>=d.start_datetime and ft.datetime<d.end_datetime -- < !!!
join fin_assets_storages fas on fas.id=ft.asset_storage_id
join fin_transaction_categories ftc on ftc.id=ft.category_id
left join swaps s on (s.credit_fin_transaction_id=ft.id or s.debit_fin_transaction_id=ft.id) and (s.credit_fin_transaction_id is not null and s.debit_fin_transaction_id is not null) -- swap fin -> fin
left join fin_transactions s_cred_ft on s_cred_ft.id=s.credit_fin_transaction_id
left join fin_assets_storages s_cred_fas on s_cred_fas.id=s_cred_ft.asset_storage_id
group by
1,2,3
) tx on tx.asset_id=b.asset_id and tx.start_datetime=b.start_datetime and tx.end_datetime=b.end_datetime
where
b.balance is not null
),
data_by_asset_type as materialized (
select
t.start_datetime,
t.end_datetime,
t.asset_type_id,
coalesce(sum(t.balance*t.end_asset_rate),0) as base_balance,
coalesce(sum(t.base_balance_delta),0) as base_balance_delta,
coalesce(sum(t.tx_active_delta*t.end_asset_rate),0) as base_active_delta,
coalesce(sum((t.balance_delta-t.tx_total_delta)*t.end_asset_rate+t.base_tx_excluded_delta),0) as base_unaccounted_delta
from
(
select
t.*,
t.balance-coalesce(
lead(t.balance) over(partition by t.asset_id order by t.end_datetime desc),
0
) as balance_delta,
t.balance*t.end_asset_rate-coalesce(
lead(t.balance*t.end_asset_rate) over(partition by t.asset_id order by t.end_datetime desc),
0
) as base_balance_delta,
fa.type_id as asset_type_id
from
data_by_asset t
join fin_assets fa on fa.id=t.asset_id
) t
group by
1,2,3
)
select
start_datetime,
end_datetime,
round(sum(t.base_balance),2) as base_balance,
round(sum(t.base_balance_delta),2) as base_balance_delta,
round(sum(t.base_active_delta),2) as base_active_delta,
round(sum(t.base_balance_delta)-sum(t.base_active_delta)-sum(t.base_unaccounted_delta),2) as base_passive_delta,
round(sum(t.base_unaccounted_delta),2) as base_unaccounted_delta,
(select base_asset from constants) as base_asset,
group_concat(fat.name||'='||cast(t.base_balance as integer) || ' ' || (select base_asset from constants), '; ') as base_balance_by_type,
group_concat(fat.name||'='||cast(t.base_balance_delta as integer) || ' ' || (select base_asset from constants), '; ') as base_balance_delta_by_type,
group_concat(fat.name||'='||cast(t.base_active_delta as integer) || ' ' || (select base_asset from constants), '; ') as base_active_delta_by_type,
group_concat(fat.name||'='||cast(t.base_balance_delta-t.base_active_delta-t.base_unaccounted_delta as integer) || ' ' || (select base_asset from constants), '; ') as base_passive_delta_by_type,
group_concat(fat.name||'='||cast(t.base_unaccounted_delta as integer) || ' ' || (select base_asset from constants), '; ') as base_unaccounted_delta_by_type
from
data_by_asset_type t
join fin_asset_types fat on fat.id=t.asset_type_id
group by
1,2
order by
t.end_datetime desc;
CREATE VIEW historical_txs_balances_mismatch as select
t.start_datetime,
t.end_datetime,
fs.name as storage,
abs(round(t.balance_delta - t.tx_delta,9)) as amount_unaccounted,
coalesce(fa.code,fa.name) as asset,
t.tx_delta,
t.balance_delta
round(t.tx_delta,9) as tx_delta,
round(t.balance_delta,9) as balance_delta
from
(
select
@ -540,7 +664,8 @@ from
ft.asset_storage_id=t.asset_storage_id and
ft.datetime<t.end_datetime and
(
ft.datetime>=t.start_datetime or t.start_datetime is null
ft.datetime>=t.start_datetime or
t.start_datetime is null
)
) as tx_delta
from (