new view and triggers

This commit is contained in:
yrzam 2023-12-20 05:03:56 +04:00
parent cb71023773
commit 36f26448fc
2 changed files with 358 additions and 84 deletions

View File

@ -77,7 +77,15 @@ rate = [asset_id value] / [base asset from fin_assets value] at [date]
### current_fin_asset_rates (editable view)
Shows current exchange rates. If you edit something, a new rate will be saved with a `date` of the current day.
Shows current exchange rates. Inactive assets are skipped. If you modify something, a new rate will be saved with a `date` of the current day.
> edit operations: update, insert
```
{asset_type, asset} - lookup tuple
rate - value
other columns - ignored
```
### fin_transactions (table)
@ -110,7 +118,7 @@ is_initial_import - whether the transaction is an upload of the existing assets
Income or expense is considered passive if two conditions are met:
1. It occurred because of some ownership
1. It occurred because of some ownership title of which did not change because of the current transaction.
2. * For gains, there are no severe non-monetary losses associated with the transaction reason.
* For losses, there are no severe non-monetary gains associated with the transaction reason.
@ -118,6 +126,24 @@ Income or expense is considered passive if two conditions are met:
> Examples of transaction categories: salary transfer, rent payment, self transfer or exchange, dividends payout.
### latest_fin_transactions (editable view)
Shows the latest transactions.
All fields except for pseudo-id are editable. There is also one special column `adjust_balance` - it allows to auto-update `balances` with the amount of the current transaction. It must be set explicitly during any operation (`insert` or `update`) that you want to affect balances. An error will be thrown if transaction's date is not the current date. **Please be cautious: while this option is convenient, used wrongly it may mess up your balance. Verify balances.**
> edit operations: update, insert
```
{pseudo_id} - lookup tuple
amount, date, category, reason_phys_asset - values
{asset_type, asset_code, storage}, {reason_fin_asset_type, reason_fin_asset_code, reason_fin_asset_storage} - value tuples
adjust_balance - pseudo-column, if set to true current operation will be auto-reflected in balances. Works only with transactions of the current day
other columns - ignored
```
### balances (table)
Stores historical balances.
@ -127,9 +153,17 @@ Stores historical balances.
### current_balances (editable view)
Shows current exchange rates.
Shows current financial balances. Inactive assets and storages are skipped.
If you edit `balance`, a supplied one will be saved with a date of the current day. You can also insert a new row - it will insert a record into `fin_assets_astorages` if needed, and upsert balances. For updates and inserts, lookup is performed via the tuple `{asset_type, asset_code, storage}`, and `balance` is used as the value. Other columns are ignored.
If you edit `balance`, a supplied one will be saved with a date of the current day. Upon the insertion of a new row, a record in `fin_assets_storages` is created if needed and the balance is upserted.
> edit operations: update, insert
```
{asset_type, asset_code, storage} - lookup tuple
balance - value
other columns - ignored
```
### balance_goals (table)

View File

@ -92,27 +92,6 @@ from
where
fa.is_active=1
/* current_fin_asset_rates(pseudo_id,asset_type,asset,rate,base_asset) */;
CREATE TRIGGER current_fin_asset_rates_update
instead of update of rate on current_fin_asset_rates
begin
insert into fin_asset_rates (asset_id, date, rate)
values(
(
select
fa.id
from
fin_assets fa
join fin_asset_types fat on fat.id=fa.type_id
where
fa.code=new.asset and
fat.name=new.asset_type
),
date('now'),
new.rate
)
on conflict(asset_id,date) do update
set rate=new.rate;
end;
CREATE VIEW current_fin_allocation as
select
t.name as "group",
@ -205,65 +184,6 @@ from (
where
t.balance is not null
/* current_balances(pseudo_id,asset_type,asset_name,storage,balance,asset_code,base_balance,base_asset) */;
CREATE TRIGGER current_balances_insert
instead of insert on current_balances
begin
insert into fin_assets_storages(asset_id, storage_id)
values(
(select fa.id from fin_assets fa join fin_asset_types fat on fat.id=fa.type_id where fa.code=new.asset_code and fat.name=new.asset_type),
(select id from fin_storages where name=new.storage)
)
on conflict do nothing;
insert into balances(asset_storage_id, date, amount)
values(
(
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
date('now'),
new.balance
)
on conflict(asset_storage_id, date) do update
set
amount = new.balance;
end;
CREATE TRIGGER current_balances_update
instead of update of balance on current_balances
begin
insert into balances(asset_storage_id, date, amount)
values(
(
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
date('now'),
new.balance
)
on conflict(asset_storage_id, date) do update
set
amount = new.balance;
end;
CREATE TABLE IF NOT EXISTS "fin_transactions" (
"id" INTEGER NOT NULL,
"date" NUMERIC NOT NULL,
@ -518,3 +438,323 @@ group by
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 INDEX "i_fin_transactions_date" ON "fin_transactions" (
"date" DESC
);
CREATE TRIGGER current_fin_asset_rates_insert
instead of insert on current_fin_asset_rates
begin
insert into fin_asset_rates (asset_id, date, rate)
values(
(
select
fa.id
from
fin_assets fa
join fin_asset_types fat on fat.id=fa.type_id
where
fa.code=new.asset and
fat.name=new.asset_type
),
date('now'),
new.rate
)
on conflict(asset_id,date) do update
set rate=new.rate;
end;
CREATE TRIGGER current_balances_insert
instead of insert on current_balances
begin
insert into fin_assets_storages(asset_id, storage_id)
values(
(select fa.id from fin_assets fa join fin_asset_types fat on fat.id=fa.type_id where fa.code=new.asset_code and fat.name=new.asset_type),
(select id from fin_storages where name=new.storage)
)
on conflict do nothing;
insert into balances(asset_storage_id, date, amount)
values(
(
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
date('now'),
new.balance
)
on conflict(asset_storage_id, date) do update
set
amount = new.balance;
end;
CREATE TRIGGER current_balances_update
instead of update of balance on current_balances
begin
insert into fin_assets_storages(asset_id, storage_id)
values(
(select fa.id from fin_assets fa join fin_asset_types fat on fat.id=fa.type_id where fa.code=new.asset_code and fat.name=new.asset_type),
(select id from fin_storages where name=new.storage)
)
on conflict do nothing;
insert into balances(asset_storage_id, date, amount)
values(
(
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
date('now'),
new.balance
)
on conflict(asset_storage_id, date) do update
set
amount = new.balance;
end;
CREATE TRIGGER current_fin_asset_rates_update
instead of update of rate on current_fin_asset_rates
begin
insert into fin_asset_rates (asset_id, date, rate)
values(
(
select
fa.id
from
fin_assets fa
join fin_asset_types fat on fat.id=fa.type_id
where
fa.code=new.asset and
fat.name=new.asset_type
),
date('now'),
new.rate
)
on conflict(asset_id,date) do update
set rate=new.rate;
end;
CREATE VIEW latest_fin_transactions as
select
ft.id as pseudo_id,
ft.date,
fat.name as asset_type,
coalesce(fa.name, fa.code) as asset_name,
fs.name as storage,
ft.amount,
fa.code as asset_code,
ftc.name as category,
r_pa.name as reason_phys_asset,
r_fat.name as reason_fin_asset_type,
r_fa.code as reason_fin_asset_code,
r_fs.name as reason_fin_asset_storage,
cast(null as int) as adjust_balance
from
fin_transactions ft
join fin_transaction_categories ftc on ftc.id=ft.category_id
join fin_assets_storages fas on fas.id=ft.asset_storage_id
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
left join phys_assets r_pa on r_pa.id=ft.reason_phys_asset_id
left join fin_assets_storages r_fas on r_fas.id=ft.reason_fin_asset_storage_id
left join fin_assets r_fa on r_fa.id=r_fas.asset_id
left join fin_asset_types r_fat on r_fat.id=r_fa.type_id
left join fin_storages r_fs on r_fs.id=r_fas.storage_id
order by
ft.date desc
/* latest_fin_transactions(pseudo_id,date,asset_type,asset_name,storage,amount,asset_code,category,reason_phys_asset,reason_fin_asset_type,reason_fin_asset_code,reason_fin_asset_storage,adjust_balance) */;
CREATE TRIGGER latest_fin_transactions_insert
instead of insert on latest_fin_transactions
begin
insert into fin_assets_storages(asset_id, storage_id)
values(
(select fa.id from fin_assets fa join fin_asset_types fat on fat.id=fa.type_id where fa.code=new.asset_code and fat.name=new.asset_type),
(select id from fin_storages where name=new.storage)
)
on conflict do nothing;
insert into fin_transactions(date, asset_storage_id, amount, category_id, reason_fin_asset_storage_id, reason_phys_asset_id)
values(
coalesce(new.date, date('now')),
(
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
new.amount,
(select id from fin_transaction_categories where name=new.category),
(
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.reason_fin_asset_code and
fat.name = new.reason_fin_asset_type and
fs.name = new.reason_fin_asset_storage
),
(select id from phys_assets where name=new.reason_phys_asset)
);
select
case
when coalesce(new.date, date('now'))!=date('now') and new.adjust_balance=1
then raise(abort, 'adjust_balance works only with current date')
end;
insert into balances(asset_storage_id, date, amount)
values(
(
select
fas.id as asset_storage_id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
date('now'),
coalesce((
select
(select b.amount from balances b where b.asset_storage_id=fas.id and b.date<=date('now') order by b.date desc limit 1) as last_balance
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),0) + new.amount
)
on conflict(asset_storage_id, date) do update
set
amount = amount + new.amount
where
new.adjust_balance=1;
end;
CREATE TRIGGER latest_fin_transactions_update
instead of update of date, asset_type, storage, amount, asset_code, category, reason_phys_asset, reason_fin_asset_type, reason_fin_asset_code, reason_fin_asset_storage on latest_fin_transactions
begin
insert into fin_assets_storages(asset_id, storage_id)
values(
(select fa.id from fin_assets fa join fin_asset_types fat on fat.id=fa.type_id where fa.code=new.asset_code and fat.name=new.asset_type),
(select id from fin_storages where name=new.storage)
)
on conflict do nothing;
update
fin_transactions
set
date = new.date,
asset_storage_id = (
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
amount = new.amount,
category_id = (select id from fin_transaction_categories where name=new.category),
reason_fin_asset_storage_id = (
select
fas.id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.reason_fin_asset_code and
fat.name = new.reason_fin_asset_type and
fs.name = new.reason_fin_asset_storage
),
reason_phys_asset_id = (select id from phys_assets where name=new.reason_phys_asset)
where
id=new.pseudo_id;
select
case
when (new.date!=date('now') or old.date!=date('now')) and new.adjust_balance=1
then raise(abort, 'adjust_balance works only with current date')
end;
insert into balances(asset_storage_id, date, amount)
values(
(
select
fas.id as asset_storage_id
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),
date('now'),
coalesce((
select
(select b.amount from balances b where b.asset_storage_id=fas.id and b.date<=date('now') order by b.date desc limit 1) as last_balance
from
fin_assets_storages fas
join fin_assets fa on fa.id=fas.asset_id
join fin_asset_types fat on fat.id=fa.type_id
join fin_storages fs on fs.id=fas.storage_id
where
fa.code = new.asset_code and
fat.name = new.asset_type and
fs.name = new.storage
),0) + new.amount - old.amount
)
on conflict(asset_storage_id, date) do update
set
amount = amount + new.amount - old.amount
where
new.adjust_balance=1;
end;