Compare commits

...

2 Commits

Author SHA1 Message Date
c932ee21de
Compute cost basis in SQL where possible 2025-02-16 20:23:56 +11:00
2404def901
Compute running balances in SQL 2025-02-16 18:43:14 +11:00
11 changed files with 211 additions and 194 deletions

123
schema.sql Normal file
View File

@ -0,0 +1,123 @@
-- DrCr: Web-based double-entry bookkeeping framework
-- Copyright (C) 2022–2025 Lee Yingtong Li (RunasSudo)
--
-- This program is free software: you can redistribute it and/or modify
-- it under the terms of the GNU Affero General Public License as published by
-- the Free Software Foundation, either version 3 of the License, or
-- (at your option) any later version.
--
-- This program is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
-- GNU Affero General Public License for more details.
--
-- You should have received a copy of the GNU Affero General Public License
-- along with this program. If not, see <https://www.gnu.org/licenses/>.
---------
-- Tables
CREATE TABLE account_configurations (
id INTEGER NOT NULL,
account VARCHAR,
kind VARCHAR,
data JSON,
PRIMARY KEY(id)
);
CREATE TABLE balance_assertions (
id INTEGER NOT NULL,
dt DATETIME,
description VARCHAR,
account VARCHAR,
quantity INTEGER,
commodity VARCHAR,
PRIMARY KEY(id)
);
CREATE TABLE metadata (
id INTEGER NOT NULL,
key VARCHAR,
value VARCHAR,
PRIMARY KEY(id)
);
CREATE TABLE postings (
id INTEGER NOT NULL,
transaction_id INTEGER,
description VARCHAR,
account VARCHAR,
quantity INTEGER,
commodity VARCHAR,
PRIMARY KEY(id),
FOREIGN KEY(transaction_id) REFERENCES transactions(id)
);
CREATE TABLE statement_line_reconciliations (
id INTEGER NOT NULL,
statement_line_id INTEGER,
posting_id INTEGER,
PRIMARY KEY(id),
FOREIGN KEY(statement_line_id) REFERENCES statement_lines(id),
FOREIGN KEY(posting_id) REFERENCES postings(id)
);
CREATE TABLE statement_lines (
id INTEGER NOT NULL,
source_account VARCHAR,
dt DATETIME,
description VARCHAR,
quantity INTEGER,
balance INTEGER,
commodity VARCHAR,
PRIMARY KEY(id)
);
CREATE TABLE transactions (
id INTEGER NOT NULL,
dt DATETIME,
description VARCHAR,
PRIMARY KEY(id)
);
--------
-- Views
-- Join transactions and postings
CREATE VIEW joined_transactions AS
SELECT transaction_id, dt, transactions.description AS transaction_description, postings.id, postings.description, account, quantity, commodity
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
ORDER BY dt, transaction_id, postings.id;
-- Convert amounts into cost basis in reporting commodity
CREATE VIEW transactions_with_quantity_ascost AS
SELECT
*,
CAST(ROUND(
-- If already in reporting commodity
IIF(
commodity = '$',
quantity,
-- Else if specified as total cost
IIF(
commodity LIKE '% {{%}}',
substr(commodity, instr(commodity, ' {{') + 3, length(commodity) - instr(commodity, ' {{') - 4) * sign(quantity) * 100,
-- Else if specified as unit cost
IIF(
commodity LIKE '% {%}',
substr(commodity, instr(commodity, ' {') + 2, length(commodity) - instr(commodity, ' {') - 2) * quantity,
-- Unexpected
NULL
)
)
)
) AS INTEGER) AS quantity_ascost
FROM joined_transactions;
-- Sum running balances
CREATE VIEW transactions_with_running_balances AS
SELECT
*,
SUM(quantity_ascost) OVER (PARTITION BY account ROWS UNBOUNDED PRECEDING) AS running_balance
FROM transactions_with_quantity_ascost;

View File

@ -51,6 +51,7 @@ export class Balance {
export function asCost(quantity: number, commodity: string): number {
// Convert the amount to cost price in the reporting commodity
// NB: This function is rarely used - most conversions are performed in SQL via the transactions_with_quantity_ascost view
if (commodity === db.metadata.reporting_commodity) {
return quantity;

View File

@ -243,8 +243,8 @@
// Insert new posting
const result = await dbTransaction.execute(
`INSERT INTO postings (transaction_id, description, account, quantity, commodity, running_balance)
VALUES ($1, $2, $3, $4, $5, NULL)`,
`INSERT INTO postings (transaction_id, description, account, quantity, commodity)
VALUES ($1, $2, $3, $4, $5)`,
[newTransaction.id, posting.description, posting.account, posting.quantity, posting.commodity]
);
@ -267,37 +267,6 @@
[posting.description, posting.account, posting.quantity, posting.commodity, posting.id]
);
}
// Invalidate running balances
await dbTransaction.execute(
`UPDATE postings
SET running_balance = NULL
FROM (
SELECT postings.id
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
WHERE DATE(dt) >= DATE($1) AND account = $2
) p
WHERE postings.id = p.id`,
[newTransaction.dt, posting.account]
);
// Must also invalidate running balance of original account, if the account has changed
const originalAccount = (posting as unknown as EditingPosting).originalAccount;
if (originalAccount && originalAccount !== posting.account) {
await dbTransaction.execute(
`UPDATE postings
SET running_balance = NULL
FROM (
SELECT postings.id
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
WHERE DATE(dt) >= DATE($1) AND account = $2
) p
WHERE postings.id = p.id`,
[newTransaction.dt, (posting as unknown as EditingPosting).originalAccount]
);
}
}
await dbTransaction.commit();

122
src/db.ts
View File

@ -1,6 +1,6 @@
/*
DrCr: Web-based double-entry bookkeeping framework
Copyright (C) 20222024 Lee Yingtong Li (RunasSudo)
Copyright (C) 20222025 Lee Yingtong Li (RunasSudo)
This program is free software: you can redistribute it and/or modify
it under the terms of the GNU Affero General Public License as published by
@ -22,7 +22,7 @@ import Database from '@tauri-apps/plugin-sql';
import { reactive } from 'vue';
import { asCost, Balance } from './amounts.ts';
import { Balance } from './amounts.ts';
import { ExtendedDatabase } from './dbutil.ts';
export const DT_FORMAT = 'YYYY-MM-DD HH:mm:ss.SSS000';
@ -68,98 +68,53 @@ export const db = reactive({
});
export async function totalBalances(session: ExtendedDatabase): Promise<Map<string, number>> {
await updateRunningBalances(session);
const resultsRaw: {account: string, quantity: number}[] = await session.select(`
SELECT p3.account AS account, running_balance AS quantity FROM
(
SELECT p1.account, max(p2.transaction_id) AS max_tid FROM
(
SELECT account, max(dt) AS max_dt
FROM postings
JOIN transactions ON postings.transaction_id = transactions.id
GROUP BY account
) p1
JOIN postings p2 ON p1.account = p2.account AND p1.max_dt = transactions.dt JOIN transactions ON p2.transaction_id = transactions.id GROUP BY p2.account
) p3
JOIN postings p4 ON p3.account = p4.account AND p3.max_tid = p4.transaction_id ORDER BY account
`);
const resultsRaw: {account: string, quantity: number}[] = await session.select(
`-- Get last transaction for each account
WITH max_dt_by_account AS (
SELECT account, max(dt) AS max_dt
FROM joined_transactions
GROUP BY account
),
max_tid_by_account AS (
SELECT max_dt_by_account.account, max(transaction_id) AS max_tid
FROM max_dt_by_account
JOIN joined_transactions ON max_dt_by_account.account = joined_transactions.account AND max_dt_by_account.max_dt = joined_transactions.dt
GROUP BY max_dt_by_account.account
)
-- Get running balance at last transaction for each account
SELECT max_tid_by_account.account, running_balance AS quantity
FROM max_tid_by_account
JOIN transactions_with_running_balances ON max_tid = transactions_with_running_balances.transaction_id AND max_tid_by_account.account = transactions_with_running_balances.account`
);
return new Map(resultsRaw.map((x) => [x.account, x.quantity]));
}
export async function totalBalancesAtDate(session: ExtendedDatabase, dt: string): Promise<Map<string, number>> {
await updateRunningBalances(session);
const resultsRaw: {account: string, quantity: number}[] = await session.select(
`SELECT p3.account AS account, running_balance AS quantity FROM
(
SELECT p1.account, max(p2.transaction_id) AS max_tid FROM
(
SELECT account, max(dt) AS max_dt
FROM postings
JOIN transactions ON postings.transaction_id = transactions.id
WHERE DATE(dt) <= DATE($1)
GROUP BY account
) p1
JOIN postings p2 ON p1.account = p2.account AND p1.max_dt = transactions.dt JOIN transactions ON p2.transaction_id = transactions.id GROUP BY p2.account
) p3
JOIN postings p4 ON p3.account = p4.account AND p3.max_tid = p4.transaction_id ORDER BY account`,
`-- Get last transaction for each account
WITH max_dt_by_account AS (
SELECT account, max(dt) AS max_dt
FROM joined_transactions
WHERE DATE(dt) <= DATE($1)
GROUP BY account
),
max_tid_by_account AS (
SELECT max_dt_by_account.account, max(transaction_id) AS max_tid
FROM max_dt_by_account
JOIN joined_transactions ON max_dt_by_account.account = joined_transactions.account AND max_dt_by_account.max_dt = joined_transactions.dt
GROUP BY max_dt_by_account.account
)
-- Get running balance at last transaction for each account
SELECT max_tid_by_account.account, running_balance AS quantity
FROM max_tid_by_account
JOIN transactions_with_running_balances ON max_tid = transactions_with_running_balances.transaction_id AND max_tid_by_account.account = transactions_with_running_balances.account`,
[dt]
);
return new Map(resultsRaw.map((x) => [x.account, x.quantity]));
}
export async function updateRunningBalances(session: ExtendedDatabase) {
// TODO: This is very slow - it would be faster to do this in Rust
// Recompute any required running balances
const staleAccountsRaw: {account: string}[] = await session.select('SELECT DISTINCT account FROM postings WHERE running_balance IS NULL');
const staleAccounts: string[] = staleAccountsRaw.map((x) => x.account);
if (staleAccounts.length === 0) {
return;
}
// Get all relevant Postings in database in correct order
// FIXME: Recompute balances only from the last non-stale balance to be more efficient
const arraySQL = '(?' + ', ?'.repeat(staleAccounts.length - 1) + ')';
const joinedTransactionPostings: JoinedTransactionPosting[] = await session.select(
`SELECT postings.id, account, quantity, commodity, running_balance
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
WHERE postings.account IN ${arraySQL}
ORDER BY dt, transaction_id, postings.id`,
staleAccounts
);
// Update running balances atomically
const dbTransaction = await session.begin();
const runningBalances = new Map();
for (const posting of joinedTransactionPostings) {
const openingBalance = runningBalances.get(posting.account) ?? 0;
const quantityCost = asCost(posting.quantity, posting.commodity);
const runningBalance = openingBalance + quantityCost;
runningBalances.set(posting.account, runningBalance);
// Update running balance of posting
// Only perform this update if required, to avoid expensive call to DB
if (posting.running_balance !== runningBalance) {
await dbTransaction.execute(
`UPDATE postings
SET running_balance = $1
WHERE id = $2`,
[runningBalance, posting.id]
);
}
}
await dbTransaction.commit();
}
export function joinedToTransactions(joinedTransactionPostings: JoinedTransactionPosting[]): Transaction[] {
// Group postings into transactions
const transactions: Transaction[] = [];
@ -180,6 +135,7 @@ export function joinedToTransactions(joinedTransactionPostings: JoinedTransactio
account: joinedTransactionPosting.account,
quantity: joinedTransactionPosting.quantity,
commodity: joinedTransactionPosting.commodity,
quantity_ascost: joinedTransactionPosting.quantity_ascost,
running_balance: joinedTransactionPosting.running_balance
});
}
@ -278,6 +234,7 @@ export interface Posting {
account: string,
quantity: number,
commodity: string,
quantity_ascost?: number,
running_balance?: number
}
@ -290,6 +247,7 @@ export interface JoinedTransactionPosting {
account: string,
quantity: number,
commodity: string,
quantity_ascost?: number,
running_balance?: number
}

View File

@ -66,7 +66,6 @@
import { ref } from 'vue';
import { asCost } from '../amounts.ts';
import { db } from '../db.ts';
import { pp } from '../display.ts';
import { ReportingStage, ReportingWorkflow } from '../reporting.ts';
@ -108,7 +107,7 @@
if (dayjs(transaction.dt) <= balanceAssertionDt) {
for (const posting of transaction.postings) {
if (posting.account === balanceAssertion.account) {
accountBalance += asCost(posting.quantity, posting.commodity);
accountBalance += posting.quantity_ascost!;
}
}
}

View File

@ -46,11 +46,10 @@
const session = await db.load();
const joinedTransactionPostings: JoinedTransactionPosting[] = await session.select(
`SELECT transaction_id, dt, transactions.description AS transaction_description, postings.id, postings.description, account, quantity, commodity
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
WHERE transactions.id = $1
ORDER BY postings.id`,
`SELECT transaction_id, dt, transaction_description, id, description, account, quantity, commodity
FROM joined_transactions
WHERE transaction_id = $1
ORDER BY id`,
[route.params.id]
);

View File

@ -1,6 +1,6 @@
<!--
DrCr: Web-based double-entry bookkeeping framework
Copyright (C) 20222024 Lee Yingtong Li (RunasSudo)
Copyright (C) 20222025 Lee Yingtong Li (RunasSudo)
This program is free software: you can redistribute it and/or modify
it under the terms of the GNU Affero General Public License as published by
@ -67,7 +67,6 @@
import { onUnmounted, ref, watch } from 'vue';
import { asCost } from '../amounts.ts';
import { Transaction, db } from '../db.ts';
import { pp, ppWithCommodity } from '../display.ts';
import { ReportingStage, ReportingWorkflow } from '../reporting.ts';
@ -132,10 +131,10 @@
<td class="py-0.5 px-1 text-gray-900 text-end"><i>${ posting.quantity >= 0 ? 'Dr' : 'Cr' }</i></td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[30%]"><a href="/transactions/${ encodeURIComponent(posting.account) }" class="text-gray-900 hover:text-blue-700 hover:underline">${ posting.account }</a></td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">
${ posting.quantity >= 0 ? pp(asCost(posting.quantity, posting.commodity)) : '' }
${ posting.quantity >= 0 ? pp(posting.quantity_ascost!) : '' }
</td>
<td class="py-0.5 pl-1 text-gray-900 lg:w-[12ex] text-end">
${ posting.quantity < 0 ? pp(asCost(-posting.quantity, posting.commodity)) : '' }
${ posting.quantity < 0 ? pp(-posting.quantity_ascost!) : '' }
</td>
</tr>`
);

View File

@ -1,6 +1,6 @@
<!--
DrCr: Web-based double-entry bookkeeping framework
Copyright (C) 20222024 Lee Yingtong Li (RunasSudo)
Copyright (C) 20222025 Lee Yingtong Li (RunasSudo)
This program is free software: you can redistribute it and/or modify
it under the terms of the GNU Affero General Public License as published by
@ -68,7 +68,6 @@
import { onUnmounted, ref, watch } from 'vue';
import { asCost } from '../amounts.ts';
import { JoinedTransactionPosting, Transaction, db, joinedToTransactions } from '../db.ts';
import { pp, ppWithCommodity } from '../display.ts';
import { renderComponent } from '../webutil.ts';
@ -82,10 +81,9 @@
const session = await db.load();
const joinedTransactionPostings: JoinedTransactionPosting[] = await session.select(
`SELECT transaction_id, dt, transactions.description AS transaction_description, postings.id, postings.description, account, quantity, commodity
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
ORDER BY dt DESC, transaction_id DESC, postings.id`
`SELECT transaction_id, dt, transaction_description, id, description, account, quantity, commodity, quantity_ascost
FROM transactions_with_quantity_ascost
ORDER BY dt DESC, transaction_id DESC, id`
);
transactions.value = joinedToTransactions(joinedTransactionPostings);
@ -131,10 +129,10 @@
<td class="py-0.5 px-1 text-gray-900 text-end"><i>${ posting.quantity >= 0 ? 'Dr' : 'Cr' }</i></td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[30%]"><a href="/transactions/${ encodeURIComponent(posting.account) }" class="text-gray-900 hover:text-blue-700 hover:underline">${ posting.account }</a></td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">
${ posting.quantity >= 0 ? pp(asCost(posting.quantity, posting.commodity)) : '' }
${ posting.quantity >= 0 ? pp(posting.quantity_ascost!) : '' }
</td>
<td class="py-0.5 pl-1 text-gray-900 lg:w-[12ex] text-end">
${ posting.quantity < 0 ? pp(asCost(-posting.quantity, posting.commodity)) : '' }
${ posting.quantity < 0 ? pp(-posting.quantity_ascost!) : '' }
</td>
</tr>`
);

View File

@ -203,16 +203,16 @@
// Insert posting for this account
const accountPostingResult = await dbTransaction.execute(
`INSERT INTO postings (transaction_id, description, account, quantity, commodity, running_balance)
VALUES ($1, NULL, $2, $3, $4, NULL)`,
`INSERT INTO postings (transaction_id, description, account, quantity, commodity)
VALUES ($1, NULL, $2, $3, $4)`,
[transactionId, statementLine.source_account, statementLine.quantity, statementLine.commodity]
);
const accountPostingId = accountPostingResult.lastInsertId;
// Insert posting for the charge account - no need to remember this ID
await dbTransaction.execute(
`INSERT INTO postings (transaction_id, description, account, quantity, commodity, running_balance)
VALUES ($1, NULL, $2, $3, $4, NULL)`,
`INSERT INTO postings (transaction_id, description, account, quantity, commodity)
VALUES ($1, NULL, $2, $3, $4)`,
[transactionId, chargeAccount, -statementLine.quantity, statementLine.commodity]
);
@ -223,20 +223,6 @@
[statementLine.id, accountPostingId]
);
// Invalidate running balances
await dbTransaction.execute(
`UPDATE postings
SET running_balance = NULL
FROM (
SELECT postings.id
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
WHERE DATE(dt) >= DATE($1) AND account IN ($2, $3)
) p
WHERE postings.id = p.id`,
[statementLine.dt, statementLine.source_account, chargeAccount]
);
dbTransaction.commit();
// Reload transactions and re-render the table
@ -280,8 +266,8 @@
// Insert posting for line1
const postingResult1 = await dbTransaction.execute(
`INSERT INTO postings (transaction_id, description, account, quantity, commodity, running_balance)
VALUES ($1, $2, $3, $4, $5, NULL)`,
`INSERT INTO postings (transaction_id, description, account, quantity, commodity)
VALUES ($1, $2, $3, $4, $5)`,
[transactionId, line1.description, line1.source_account, line1.quantity, line1.commodity]
);
const postingId1 = postingResult1.lastInsertId;
@ -295,8 +281,8 @@
// Insert posting for line2
const postingResult2 = await dbTransaction.execute(
`INSERT INTO postings (transaction_id, description, account, quantity, commodity, running_balance)
VALUES ($1, $2, $3, $4, $5, NULL)`,
`INSERT INTO postings (transaction_id, description, account, quantity, commodity)
VALUES ($1, $2, $3, $4, $5)`,
[transactionId, line2.description, line2.source_account, line2.quantity, line2.commodity]
);
const postingId2 = postingResult2.lastInsertId;
@ -308,20 +294,6 @@
[line2.id, postingId2]
);
// Invalidate running balances
await dbTransaction.execute(
`UPDATE postings
SET running_balance = NULL
FROM (
SELECT postings.id
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
WHERE DATE(dt) >= DATE($1) AND account IN ($2, $3)
) p
WHERE postings.id = p.id`,
[line1.dt, line1.source_account, line2.source_account]
);
dbTransaction.commit();
// Reload transactions and re-render the table

View File

@ -1,6 +1,6 @@
<!--
DrCr: Web-based double-entry bookkeeping framework
Copyright (C) 20222024 Lee Yingtong Li (RunasSudo)
Copyright (C) 20222025 Lee Yingtong Li (RunasSudo)
This program is free software: you can redistribute it and/or modify
it under the terms of the GNU Affero General Public License as published by
@ -49,7 +49,6 @@
import { onMounted, onUnmounted, watch } from 'vue';
import { useRoute } from 'vue-router';
import { asCost } from '../amounts.ts';
import { Transaction } from '../db.ts';
import { pp } from '../display.ts';
import { renderComponent } from '../webutil.ts';
@ -67,8 +66,8 @@
const transaction = transactions[i];
for (const posting of transaction.postings) {
if (posting.account === route.params.account) {
balance += asCost(posting.quantity, posting.commodity);
posting.running_balance = balance; // We should absolutely not commit this to the database!
balance += posting.quantity_ascost!;
posting.running_balance = balance;
}
}
}
@ -100,8 +99,8 @@
<td class="py-0.5 pr-1 text-gray-900 lg:w-[12ex]">${ dayjs(transaction.dt).format('YYYY-MM-DD') }</td>
<td class="py-0.5 px-1 text-gray-900">${ transaction.description } ${ editLink }</td>
<td class="py-0.5 px-1 text-gray-900"><a href="/transactions/${ encodeURIComponent(otherAccountPosting!.account) }" class="text-gray-900 hover:text-blue-700 hover:underline">${ otherAccountPosting!.account }</a></td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ thisAccountPosting!.quantity >= 0 ? pp(asCost(thisAccountPosting!.quantity, thisAccountPosting!.commodity)) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ thisAccountPosting!.quantity < 0 ? pp(asCost(-thisAccountPosting!.quantity, thisAccountPosting!.commodity)) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ thisAccountPosting!.quantity >= 0 ? pp(thisAccountPosting!.quantity_ascost!) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ thisAccountPosting!.quantity < 0 ? pp(-thisAccountPosting!.quantity_ascost!) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ pp(Math.abs(thisAccountPosting!.running_balance!)) }</td>
<td class="py-0.5 text-gray-900">${ thisAccountPosting!.running_balance! >= 0 ? 'Dr' : 'Cr' }</td>
</tr>`
@ -125,8 +124,8 @@
<td></td>
<td class="py-0.5 px-1 text-gray-900 text-end"><i>${ posting.quantity >= 0 ? 'Dr' : 'Cr' }</i></td>
<td class="py-0.5 px-1 text-gray-900"><a href="/transactions/${ encodeURIComponent(posting.account) }" class="text-gray-900 hover:text-blue-700 hover:underline">${ posting.account }</a></td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ posting.quantity >= 0 ? pp(asCost(posting.quantity, posting.commodity)) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ posting.quantity < 0 ? pp(asCost(-posting.quantity, posting.commodity)) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ posting.quantity >= 0 ? pp(posting.quantity_ascost!) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ posting.quantity < 0 ? pp(-posting.quantity_ascost!) : '' }</td>
<td class="py-0.5 px-1 text-gray-900 lg:w-[12ex] text-end">${ posting.account === route.params.account ? pp(Math.abs(posting.running_balance!)) : '' }</td>
<td class="py-0.5 text-gray-900">${ posting.account === route.params.account ? (posting.running_balance! >= 0 ? 'Dr' : 'Cr') : '' }</td>
</tr>`

View File

@ -75,19 +75,17 @@ export class ReportingWorkflow {
let joinedTransactionPostings: JoinedTransactionPosting[];
if (dt) {
joinedTransactionPostings = await session.select(
`SELECT transaction_id, dt, transactions.description AS transaction_description, postings.id, postings.description, account, quantity, commodity, running_balance
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
`SELECT transaction_id, dt, transaction_description, id, description, account, quantity, commodity, quantity_ascost, running_balance
FROM transactions_with_running_balances
WHERE DATE(dt) <= DATE($1)
ORDER BY dt, transaction_id, postings.id`,
ORDER BY dt, transaction_id, id`,
[dt]
);
} else {
joinedTransactionPostings = await session.select(
`SELECT transaction_id, dt, transactions.description AS transaction_description, postings.id, postings.description, account, quantity, commodity, running_balance
FROM transactions
JOIN postings ON transactions.id = postings.transaction_id
ORDER BY dt, transaction_id, postings.id`
`SELECT transaction_id, dt, transaction_description, id, description, account, quantity, commodity, quantity_ascost, running_balance
FROM transactions_with_running_balances
ORDER BY dt, transaction_id, id`
);
}
const transactions = joinedToTransactions(joinedTransactionPostings);
@ -129,14 +127,16 @@ export class ReportingWorkflow {
description: null,
account: line.source_account,
quantity: line.quantity,
commodity: line.commodity
commodity: line.commodity,
quantity_ascost: asCost(line.quantity, line.commodity),
},
{
id: null,
description: null,
account: unclassifiedAccount,
quantity: -line.quantity,
commodity: line.commodity
commodity: line.commodity,
quantity_ascost: asCost(-line.quantity, line.commodity),
}
]
));
@ -165,7 +165,7 @@ export class ReportingWorkflow {
for (const transaction of this.transactionsForStage.get(ReportingStage.OrdinaryAPITransactions)!) {
if (!dayjs(transaction.dt).isAfter(dayBeforePeriodStart)) {
for (const posting of transaction.postings) {
balancesAtPeriodStart.set(posting.account, (balancesAtPeriodStart.get(posting.account) ?? 0) + asCost(posting.quantity, posting.commodity));
balancesAtPeriodStart.set(posting.account, (balancesAtPeriodStart.get(posting.account) ?? 0) + posting.quantity_ascost!);
}
}
}
@ -195,14 +195,16 @@ export class ReportingWorkflow {
description: null,
account: account,
quantity: -balanceAtPeriodStart,
commodity: db.metadata.reporting_commodity
commodity: db.metadata.reporting_commodity,
quantity_ascost: asCost(-balanceAtPeriodStart, db.metadata.reporting_commodity),
},
{
id: null,
description: null,
account: 'Accumulated surplus (deficit)',
quantity: balanceAtPeriodStart,
commodity: db.metadata.reporting_commodity
commodity: db.metadata.reporting_commodity,
quantity_ascost: asCost(balanceAtPeriodStart, db.metadata.reporting_commodity),
},
]
));
@ -282,9 +284,7 @@ function applyTransactionsToBalances(balances: Map<string, number>, transactions
for (const transaction of transactions) {
for (const posting of transaction.postings) {
const openingBalance = newBalances.get(posting.account) ?? 0;
const quantityCost = asCost(posting.quantity, posting.commodity);
const runningBalance = openingBalance + quantityCost;
const runningBalance = openingBalance + posting.quantity_ascost!;
newBalances.set(posting.account, runningBalance);
}
}