mirror of
https://github.com/yrzam/findb.git
synced 2025-04-11 06:12:29 +00:00
new table
This commit is contained in:
parent
cda89fd521
commit
582b72d6bb
111
README.md
111
README.md
@ -166,6 +166,55 @@ Whenever possible, balance should be queried directly from this table instead of
|
||||
One may argue that storing balances separately is a bad practice because it causes denormalization and data inconsistency. However, it is a deliberate choice to store conflicting data, as such data is loaded from external sources. Purpose of this project is to offer a viewpoint on multiple versions of data in order to resolve these conflicts.
|
||||
|
||||
|
||||
### phys_assets (table)
|
||||
|
||||
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.
|
||||
|
||||
```
|
||||
id (pk)
|
||||
name (text unique not null)
|
||||
description (text)
|
||||
```
|
||||
|
||||
> Examples: house, apartment rented for a year, commercial property, car
|
||||
|
||||
|
||||
### phys_asset_ownerships (table)
|
||||
|
||||
Tracks whether physical asset is owned by a person at a particular moment. One asset may be owned at many time periods, or not be owned at all.
|
||||
|
||||
```
|
||||
id (pk)
|
||||
asset_id (fk phys_asset_id not null)
|
||||
start_datetime (datetime as text not null) - since that moment an asset is owned
|
||||
end_datetime - (datetime as text) - up to that moment (excl) an asset is owned. Owned indefinitely if null
|
||||
```
|
||||
|
||||
Ownership periods for the same asset must not intersect.
|
||||
|
||||
|
||||
### swaps (table)
|
||||
|
||||
Provides double-entry bookkeeping for the operations where both sides are tracked. Swap is an internal transfer of value that may happen between same or different assets, possibly of different nature. Swap changes the value allocation between financial accounts or physical items.
|
||||
|
||||
```
|
||||
id (pk)
|
||||
credit_fin_transaction_id (fk fin_transactions)
|
||||
credit_phys_ownership_id (fk phys_asset_ownerships)
|
||||
debit_fin_transaction_id (fk fin_transactions)
|
||||
debit_phys_ownership_id (fk phys_asset_ownerships)
|
||||
```
|
||||
|
||||
Therefore, possible operations are:
|
||||
- fin asset -> fin asset (exchange or transfer)
|
||||
- fin asset -> phys asset (buy)
|
||||
- phys asset -> fin_asset (sell)
|
||||
- phys asset -> phys asset (exchange)
|
||||
- phys asset -> phys asset + fin asset (exchange with change)
|
||||
|
||||
> Examples: transfer between bank accounts, currency exchange, buying some item
|
||||
|
||||
|
||||
### balance_goals (table)
|
||||
|
||||
A **balance goal** is a plan to have a certain amount of financial assets on a balance for the specific purpose in the future, or keep it there constantly.
|
||||
@ -205,54 +254,30 @@ priority (integer unique)
|
||||
> Examples: allocation group "CASH" should have a 5% target share in 2025 Q2
|
||||
|
||||
|
||||
### phys_assets (table)
|
||||
### fin_transaction_plans (table)
|
||||
|
||||
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.
|
||||
This is a core table of financial planning. It allows to specify expected transactions in a flexible way.
|
||||
|
||||
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.).
|
||||
|
||||
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.
|
||||
|
||||
```
|
||||
id (pk)
|
||||
name (text unique not null)
|
||||
description (text)
|
||||
id (pk)
|
||||
transaction_category_id (fk fin_transaction_categories not null) - transaction category that this plan covers. Specify the root category if you want to cover all transactions.
|
||||
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_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.
|
||||
```
|
||||
|
||||
> Examples: house, apartment rented for a year, commercial property, car
|
||||
|
||||
|
||||
### phys_asset_ownerships (table)
|
||||
|
||||
Tracks whether physical asset is owned by a person at a particular moment. One asset may be owned at many time periods, or not be owned at all.
|
||||
|
||||
```
|
||||
id (pk)
|
||||
asset_id (fk phys_asset_id not null)
|
||||
start_datetime (datetime as text not null) - since that moment an asset is owned
|
||||
end_datetime - (datetime as text) - up to that moment (excl) an asset is owned. Owned indefinitely if null
|
||||
```
|
||||
|
||||
Ownership periods for the same asset must not intersect.
|
||||
|
||||
|
||||
### swaps (table)
|
||||
|
||||
Provides double-entry bookkeeping for the operations where both sides are tracked. Swap is an internal transfer of value that may happen between same or different assets, possibly of different nature. Swap changes the value allocation between financial accounts or physical items.
|
||||
|
||||
```
|
||||
id (pk)
|
||||
credit_fin_tx_id (fk fin_transactions)
|
||||
credit_phys_ownership_id (fk phys_asset_ownerships)
|
||||
debit_fin_tx_id (fk fin_transactions)
|
||||
debit_phys_ownership_id (fk phys_asset_ownerships)
|
||||
```
|
||||
|
||||
Therefore, possible operations are:
|
||||
- fin asset -> fin asset (exchange or transfer)
|
||||
- fin asset -> phys asset (buy)
|
||||
- phys asset -> fin_asset (sell)
|
||||
- phys asset -> phys asset (exchange)
|
||||
- phys asset -> phys asset + fin asset (exchange with change)
|
||||
|
||||
> Examples: transfer between bank accounts, currency exchange, buying some item
|
||||
|
||||
|
||||
### current_balances (view)
|
||||
|
||||
|
31
schema.sql
31
schema.sql
@ -94,6 +94,23 @@ CREATE TABLE "fin_transaction_categories" (
|
||||
FOREIGN KEY("parent_id") REFERENCES "fin_transaction_categories"("id")
|
||||
);
|
||||
|
||||
CREATE TABLE "fin_transaction_plans" (
|
||||
"id" INTEGER NOT NULL,
|
||||
"transaction_category_id" INTEGER NOT NULL,
|
||||
"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_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")
|
||||
);
|
||||
|
||||
CREATE TABLE "fin_transactions" (
|
||||
"id" INTEGER NOT NULL,
|
||||
"datetime" TEXT NOT NULL CHECK("datetime" IS datetime("datetime")),
|
||||
@ -126,14 +143,14 @@ CREATE TABLE "phys_assets" (
|
||||
);
|
||||
|
||||
CREATE TABLE "swaps" (
|
||||
"credit_fin_tx_id" INTEGER UNIQUE,
|
||||
"credit_fin_transaction_id" INTEGER UNIQUE,
|
||||
"credit_phys_ownership_id" INTEGER UNIQUE,
|
||||
"debit_fin_tx_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_tx_id") REFERENCES "fin_transactions"("id"),
|
||||
FOREIGN KEY("debit_fin_tx_id") REFERENCES "fin_transactions"("id"),
|
||||
FOREIGN KEY("credit_phys_ownership_id") REFERENCES "phys_asset_ownerships"("id")
|
||||
FOREIGN KEY("credit_fin_transaction_id") REFERENCES "fin_transactions"("id")
|
||||
);
|
||||
|
||||
CREATE INDEX "balance_goals_end_datetime_part_no_result" ON "balance_goals" (
|
||||
@ -213,7 +230,7 @@ CREATE INDEX "i_phys_asset_ownerships_asset_id_end_datetime" ON "phys_asset_owne
|
||||
);
|
||||
|
||||
CREATE INDEX "i_swaps_credit_fin_tx_id" ON "swaps" (
|
||||
"credit_fin_tx_id"
|
||||
"credit_fin_transaction_id"
|
||||
);
|
||||
|
||||
CREATE INDEX "i_swaps_credit_phys_ownership_id" ON "swaps" (
|
||||
@ -221,7 +238,7 @@ CREATE INDEX "i_swaps_credit_phys_ownership_id" ON "swaps" (
|
||||
);
|
||||
|
||||
CREATE INDEX "i_swaps_debit_fin_tx_id" ON "swaps" (
|
||||
"debit_fin_tx_id"
|
||||
"debit_fin_transaction_id"
|
||||
);
|
||||
|
||||
CREATE INDEX "i_swaps_debit_phys_ownership_id" ON "swaps" (
|
||||
|
Loading…
Reference in New Issue
Block a user