From 3d59720cc4c4eecf9cecf2eeb7697ad74473dd33 Mon Sep 17 00:00:00 2001 From: yrzam Date: Sun, 18 Feb 2024 05:12:18 +0400 Subject: [PATCH] make more data historical --- README.md | 28 ++++++++--- schema.sql | 139 +++++++++++++++++++++++++++++++++++++---------------- 2 files changed, 118 insertions(+), 49 deletions(-) diff --git a/README.md b/README.md index 459c31b..1a44d4d 100644 --- a/README.md +++ b/README.md @@ -97,8 +97,8 @@ Exchanges and self-transfers should be represented by two transactions, both hav ``` asset_storage_id - points to storage and asset that took part in in transaction, direction is determined by the sign of [amount] amount - numeric, can be negative -reason_fin_asset_storage_id - (optional) financial asset, due to which transaction has occurred. This must be not manipulation with the asset itself, but the byproduct of its ownership -reason_phys_asset_id - (optional) physical asset, due to which transaction has occurred. This must be not manipulation with the asset itself, but the byproduct of its ownership +reason_fin_asset_storage_id - (optional) indirectly points to the financial asset, due to which transaction has occurred. This must be not manipulation with the asset itself, but the byproduct of its ownership +reason_phys_asset_ownership_id - (optional) indirectly points to the physical asset, due to which transaction has occurred. This must be not manipulation with the asset itself, but the byproduct of its ownership ... ``` @@ -194,13 +194,25 @@ Goals that result in financial transactions are hidden. Goal is considered accom ### phys_assets (table) -Represents real-world assets, purchases and other non-fungible (non-interchangeable) things that a person owns. The intended use case is to track large and important assets, especially ones that generate passive gains and losses. - -The asset is considered currently owned if it is neither sold (`sell_transaction_id is null`) nor naturally expired (`is_expired=0`). +Represents real-world assets, purchases and other non-fungible (non-interchangeable) things. The intended use case is to track large and important assets, especially ones that generate passive gains and losses. > Examples: house, apartment rented for a year, commercial property, car, blockchain NFT +### phys_asset_ownerships (table) + +Tracks whether physical asset is owned by a person at a particular date. Possibly binds ownership status changes to the financial transactions. + +One asset may be owned at many time periods, or not be owned at all. Asset belongs to a person if two conditions are met: `start_date<=[current date]` and `end_date>=[current_date] or end_date is null`. + +``` +start_date - first day of ownership +end_day - (optional) last day of ownership +buy_fin_tx_id - (optional) transaction id, if redeemed in exchange for financial asset +sell_fin_tx_id - (optional) transaction id, if sold for financial asset +``` + + ### fin_allocation_groups (table) This table sets a goal for the financial asset distribution. @@ -209,12 +221,12 @@ Each asset & storage (`fin_assets_storages`) from your portfolio can reference a ``` target share - a desired fraction of all your assets that the group should take. This may be any non-negative number +start_date - since that day a rule is appled +end_date - optional, the last day to be covered by the rule ... ``` -This table is not historical. - -> Examples: allocation group "CASH" should have a 5% target share +> Examples: allocation group "CASH" should have a 5% target share in 2025 Q2 ### current_fin_allocation (view) diff --git a/schema.sql b/schema.sql index f9d5bcf..e764ddc 100644 --- a/schema.sql +++ b/schema.sql @@ -22,7 +22,10 @@ CREATE TABLE "balances" ( CREATE TABLE "fin_allocation_groups" ( "id" INTEGER NOT NULL, "name" TEXT NOT NULL UNIQUE, - "target_share" NUMERIC NOT NULL DEFAULT 0, priority int, + "target_share" NUMERIC NOT NULL DEFAULT 0, + "start_date" NUMERIC NOT NULL, + "end_date" INTEGER, + "priority" INTEGER UNIQUE, PRIMARY KEY("id") ); CREATE TABLE "fin_asset_rates" ( @@ -89,22 +92,29 @@ CREATE TABLE "fin_transactions" ( "amount" NUMERIC NOT NULL, "category_id" INTEGER NOT NULL, "reason_fin_asset_storage_id" INTEGER, - "reason_phys_asset_id" INTEGER, - PRIMARY KEY("id"), - FOREIGN KEY("reason_phys_asset_id") REFERENCES "phys_assets"("id"), + "reason_phys_asset_ownership_id" INTEGER, + FOREIGN KEY("category_id") REFERENCES "fin_transaction_categories"("id"), FOREIGN KEY("reason_fin_asset_storage_id") REFERENCES "fin_assets_storages"("id"), - FOREIGN KEY("category_id") REFERENCES "fin_transaction_categories"("id") + FOREIGN KEY("reason_phys_asset_ownership_id") REFERENCES "phys_asset_ownerships"("id"), + PRIMARY KEY("id") +); +CREATE TABLE "phys_asset_ownerships" ( + "id" INTEGER NOT NULL, + "asset_id" INTEGER NOT NULL, + "start_date" NUMERIC NOT NULL, + "end_date" NUMERIC, + "buy_fin_tx_id" INTEGER, + "sell_fin_tx_id" INTEGER, + FOREIGN KEY("sell_fin_tx_id") REFERENCES "fin_transactions"("id"), + FOREIGN KEY("buy_fin_tx_id") REFERENCES "fin_transactions"("id"), + FOREIGN KEY("asset_id") REFERENCES "phys_assets"("id"), + PRIMARY KEY("id") ); CREATE TABLE "phys_assets" ( "id" INTEGER NOT NULL, "name" TEXT NOT NULL UNIQUE, "description" TEXT, - "buy_transaction_id" INTEGER, - "sell_transaction_id" INTEGER, - "is_expired" INTEGER NOT NULL DEFAULT 0, - FOREIGN KEY("sell_transaction_id") REFERENCES "fin_transactions"("id"), - PRIMARY KEY("id"), - FOREIGN KEY("buy_transaction_id") REFERENCES "fin_transactions"("id") + PRIMARY KEY("id") ); CREATE INDEX "i_balance_goals_asset_storage_id" ON "balance_goals" ( "asset_storage_id" @@ -116,6 +126,9 @@ CREATE INDEX "i_balances_asset_storage_id_date" ON "balances" ( "asset_storage_id", "date" DESC ); +CREATE INDEX "i_fin_allocation_groups_end_date" ON "fin_allocation_groups" ( + "end_date" DESC +); CREATE INDEX "i_fin_asset_rates_asset_id_date" ON "fin_asset_rates" ( "asset_id", "date" DESC @@ -135,6 +148,9 @@ CREATE INDEX "i_fin_assets_storages_storage_id" ON "fin_assets_storages" ( CREATE INDEX "i_fin_assets_type_id" ON "fin_assets" ( "type_id" ); +CREATE INDEX "i_fin_transaction_categories_parent_id" ON "fin_transaction_categories" ( + "parent_id" +); CREATE INDEX "i_fin_transactions_asset_storage_id_date" ON "fin_transactions" ( "asset_storage_id", "date" DESC @@ -145,11 +161,21 @@ CREATE INDEX "i_fin_transactions_category_id" ON "fin_transactions" ( CREATE INDEX "i_fin_transactions_date" ON "fin_transactions" ( "date" DESC ); +CREATE INDEX "i_fin_transactions_reason_phys_asset_ownership_id" ON "fin_transactions" ( + "reason_phys_asset_ownership_id" +); CREATE INDEX "i_fin_transactions_result_fin_asset_storage_id" ON "fin_transactions" ( "reason_fin_asset_storage_id" ); -CREATE INDEX "i_fin_transactions_result_phys_asset_id" ON "balance_goals" ( - "result_transaction_id" +CREATE INDEX "i_phys_asset_ownerships_asset_id_end_date" ON "phys_asset_ownerships" ( + "asset_id", + "end_date" DESC +); +CREATE INDEX "i_phys_asset_ownerships_buy_fin_tx_id" ON "phys_asset_ownerships" ( + "buy_fin_tx_id" +); +CREATE INDEX "i_phys_asset_ownerships_sell_fin_tx_id" ON "phys_asset_ownerships" ( + "sell_fin_tx_id" ); CREATE VIEW "current_balance_goals" AS select t.amount_left=0 as is_accomplished, @@ -258,8 +284,14 @@ from ( left join fin_assets fa on fa.id=fas.asset_id left join fin_storages fs on fs.id=fas.storage_id where - fas.id is null or - (fa.is_active and fs.is_active) + ( + date('now')>=fag.start_date and + (date('now')<=fag.end_date or fag.end_date is null) + ) and + ( + fas.id is null or + (fa.is_active and fs.is_active) + ) group by fag.id ) t @@ -468,7 +500,8 @@ from 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 phys_asset_ownerships r_pao on r_pao.id=ft.reason_phys_asset_ownership_id + left join phys_assets r_pa on r_pa.id=r_pao.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 @@ -588,28 +621,28 @@ begin end; CREATE TRIGGER fin_transaction_categories_insert insert on fin_transaction_categories begin -with -recursive parents(path, parent_id) as ( - values('/'||new.id||'/', new.parent_id) - union all +with recursive +parents(parent_id) as ( + values(new.parent_id) + union select - p.path||cat.id||'/', cat.parent_id + cat.parent_id from parents p join fin_transaction_categories cat on cat.id=p.parent_id where - p.path not like '%/'||cat.id||'/%' + cat.id!=new.id ), -children(path, id) as ( - values('/'||new.id||'/', new.id) - union all +children(id) as ( + values(new.id) + union select - c.path||cat.id||'/', cat.id + cat.id from children c join fin_transaction_categories cat on cat.parent_id=c.id where - c.path not like '%/'||cat.id||'/%' + cat.id!=new.id ) select case @@ -646,28 +679,28 @@ from end; CREATE TRIGGER fin_transaction_categories_update update of id,parent_id,is_passive,is_rebalance,is_initial_import on fin_transaction_categories begin -with -recursive parents(path, parent_id) as ( - values('/'||new.id||'/', new.parent_id) - union all +with recursive +parents(parent_id) as ( + values(new.parent_id) + union select - p.path||cat.id||'/', cat.parent_id + cat.parent_id from parents p join fin_transaction_categories cat on cat.id=p.parent_id where - p.path not like '%/'||cat.id||'/%' + cat.id!=new.id ), -children(path, id) as ( - values('/'||new.id||'/', new.id) - union all +children(id) as ( + values(new.id) + union select - c.path||cat.id||'/', cat.id + cat.id from children c join fin_transaction_categories cat on cat.parent_id=c.id where - c.path not like '%/'||cat.id||'/%' + cat.id!=new.id ) select case @@ -720,7 +753,7 @@ begin ) on conflict do nothing; - insert into fin_transactions(date, asset_storage_id, amount, category_id, reason_fin_asset_storage_id, reason_phys_asset_id) + insert into fin_transactions(date, asset_storage_id, amount, category_id, reason_fin_asset_storage_id, reason_phys_asset_ownership_id) values( coalesce(new.date, date('now')), ( @@ -751,7 +784,19 @@ begin 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 + pao.id + from + phys_assets pa + join phys_asset_ownerships pao on pao.asset_id=pa.id + where + pa.name=new.reason_phys_asset and + ( + coalesce(new.date, date('now'))>=pao.start_date and + (coalesce(new.date, date('now'))<=pao.end_date or pao.end_date is null) + ) + ) ); select @@ -822,7 +867,19 @@ begin 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) + reason_phys_asset_ownership_id = ( + select + pao.id + from + phys_assets pa + join phys_asset_ownerships pao on pao.asset_id=pa.id + where + pa.name=new.reason_phys_asset and + ( + coalesce(new.date, date('now'))>=pao.start_date and + (coalesce(new.date, date('now'))<=pao.end_date or pao.end_date is null) + ) + ) where id=new.pseudo_id;