Implement balance assertions view

This commit is contained in:
RunasSudo 2024-11-22 18:12:40 +11:00
parent 8ccbe44102
commit e791fb2a8a
Signed by: RunasSudo
GPG Key ID: 7234E476BF21C61A
5 changed files with 202 additions and 17 deletions

View File

@ -68,7 +68,10 @@ export async function totalBalances(session: ExtendedDatabase): Promise<Map<stri
(
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
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
@ -78,6 +81,29 @@ export async function totalBalances(session: ExtendedDatabase): Promise<Map<stri
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`,
[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

View File

@ -30,6 +30,7 @@ async function initApp() {
// Init router
const routes = [
{ path: '/', name: 'index', component: () => import('./pages/HomeView.vue') },
{ path: '/balance-assertions', name: 'balance-assertions', component: () => import('./pages/BalanceAssertionsView.vue') },
{ path: '/chart-of-accounts', name: 'chart-of-accounts', component: () => import('./pages/ChartOfAccountsView.vue') },
{ path: '/general-ledger', name: 'general-ledger', component: () => import('./pages/GeneralLedgerView.vue') },
{ path: '/journal', name: 'journal', component: () => import('./pages/JournalView.vue') },

View File

@ -0,0 +1,132 @@
<!--
DrCr: Web-based double-entry bookkeeping framework
Copyright (C) 20222024 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/>.
-->
<template>
<h1 class="page-heading">
Balance assertions
</h1>
<div class="my-4 flex gap-x-2">
<!--<a href="{{ url_for('balance_assertions_new') }}" class="btn-primary pl-2">
<svg xmlns="http://www.w3.org/2000/svg" fill="none" viewBox="0 0 24 24" stroke-width="1.5" stroke="currentColor" class="w-4 h-4">
<path stroke-linecap="round" stroke-linejoin="round" d="M12 4.5v15m7.5-7.5h-15" />
</svg>
New assertion
</a>-->
</div>
<table class="min-w-full">
<thead>
<tr class="border-b border-gray-300">
<th class="py-0.5 pr-1 text-gray-900 font-semibold text-start">Date</th>
<th class="py-0.5 px-1 text-gray-900 font-semibold text-start">Description</th>
<th class="py-0.5 px-1 text-gray-900 font-semibold text-start">Account</th>
<th class="py-0.5 px-1 text-gray-900 font-semibold text-end">Balance</th>
<th></th>
<th class="py-0.5 px-1 text-gray-900 font-semibold text-start">Status</th>
<th></th>
</tr>
</thead>
<tbody>
<tr v-for="assertion of balanceAssertions">
<td class="py-0.5 pr-1 text-gray-900">{{ dayjs(assertion.dt).format('YYYY-MM-DD') }}</td>
<td class="py-0.5 px-1 text-gray-900">{{ assertion.description }}</td>
<td class="py-0.5 px-1 text-gray-900"><RouterLink :to="{ name: 'transactions', params: { account: assertion.account } }" class="text-gray-900 hover:text-blue-700 hover:underline">{{ assertion.account }}</RouterLink></td>
<td class="py-0.5 px-1 text-gray-900 text-end">{{ pp(Math.abs(assertion.quantity)) }}</td>
<td class="py-0.5 pr-1 text-gray-900">{{ assertion.quantity >= 0 ? 'Dr' : 'Cr' }}</td>
<td class="py-0.5 px-1 text-gray-900">
<CheckIcon class="w-4 h-4" v-if="assertion.isValid" />
<XMarkIcon class="w-4 h-4 text-red-500" v-if="!assertion.isValid" />
</td>
<td class="py-0.5 pl-1 text-gray-900 text-end">
<a href="#" class="text-gray-500 hover:text-gray-700">
<svg xmlns="http://www.w3.org/2000/svg" fill="none" viewBox="0 0 24 24" stroke-width="1.5" stroke="currentColor" class="w-4 h-4 inline align-middle -mt-0.5">
<path stroke-linecap="round" stroke-linejoin="round" d="m16.862 4.487 1.687-1.688a1.875 1.875 0 1 1 2.652 2.652L6.832 19.82a4.5 4.5 0 0 1-1.897 1.13l-2.685.8.8-2.685a4.5 4.5 0 0 1 1.13-1.897L16.863 4.487Zm0 0L19.5 7.125" />
</svg>
</a>
</td>
</tr>
</tbody>
</table>
</template>
<script setup lang="ts">
import dayjs from 'dayjs';
import { ref } from 'vue';
import { db, totalBalancesAtDate } from '../db.ts';
import { pp } from '../display.ts';
import { CheckIcon, XMarkIcon } from '@heroicons/vue/24/outline';
const balanceAssertions = ref([] as ValidatedBalanceAssertion[]);
interface ValidatedBalanceAssertion {
id: number,
dt: string,
description: string,
account: string,
quantity: number,
commodity: string,
isValid: boolean,
}
async function load() {
const session = await db.load();
const rawBalanceAssertions: any[] = await session.select(
`SELECT *
FROM balance_assertions
ORDER BY dt DESC, id DESC`
);
/*
// Cache trial balances in case there are multiple assertions per date
const trialBalanceForDate = new Map<string, TrialBalanceReport>();
for (const balanceAssertion of rawBalanceAssertions) {
// Check assertion status
// TODO: This is very inefficient because API transactions are generated multiple times
if (!trialBalanceForDate.has(balanceAssertion.dt)) {
const reportingWorkflow = new ReportingWorkflow();
await reportingWorkflow.generate(session, balanceAssertion.dt);
const trialBalance = reportingWorkflow.getReportAtStage(ReportingStage.OrdinaryAPITransactions, TrialBalanceReport) as TrialBalanceReport;
trialBalanceForDate.set(balanceAssertion.dt, trialBalance);
}
const trialBalance = trialBalanceForDate.get(balanceAssertion.dt)!;
balanceAssertion.isValid = balanceAssertion.quantity === trialBalance.balances.get(balanceAssertion.account) && balanceAssertion.commodity === db.metadata.reporting_commodity;
}
*/
// Check assertion status
const balancesForDate = new Map<string, Map<string, number>>();
for (const balanceAssertion of rawBalanceAssertions) {
if (!balancesForDate.has(balanceAssertion.dt)) {
// FIXME: This is quite slow
balancesForDate.set(balanceAssertion.dt, await totalBalancesAtDate(session, balanceAssertion.dt));
}
balanceAssertion.isValid = balanceAssertion.quantity === balancesForDate.get(balanceAssertion.dt)!.get(balanceAssertion.account) && balanceAssertion.commodity === db.metadata.reporting_commodity;
}
balanceAssertions.value = rawBalanceAssertions as ValidatedBalanceAssertion[];
}
load();
</script>

View File

@ -23,7 +23,7 @@
<ul class="list-disc ml-6">
<li><RouterLink :to="{ name: 'journal' }" class="text-gray-900 hover:text-blue-700 hover:underline">Journal</RouterLink></li>
<li><RouterLink :to="{ name: 'statement-lines' }" class="text-gray-900 hover:text-blue-700 hover:underline">Statement lines</RouterLink></li>
<!--<li><a href="#" class="text-gray-900 hover:text-blue-700 hover:underline">Balance assertions</a></li>-->
<li><RouterLink :to="{ name: 'balance-assertions' }" class="text-gray-900 hover:text-blue-700 hover:underline">Balance assertions</RouterLink></li>
<li><RouterLink :to="{ name: 'chart-of-accounts' }" class="text-gray-900 hover:text-blue-700 hover:underline">Chart of accounts</RouterLink></li>
<!-- TODO: Plugin reports -->
</ul>

View File

@ -17,7 +17,7 @@
*/
import { asCost } from './amounts.ts';
import { JoinedTransactionPosting, StatementLine, Transaction, joinedToTransactions, totalBalances } from './db.ts';
import { JoinedTransactionPosting, StatementLine, Transaction, joinedToTransactions, totalBalances, totalBalancesAtDate } from './db.ts';
import { ExtendedDatabase } from './dbutil.ts';
export enum ReportingStage {
@ -32,7 +32,7 @@ export class ReportingWorkflow {
transactionsForStage: Map<ReportingStage, Transaction[]> = new Map();
reportsForStage: Map<ReportingStage, Report[]> = new Map();
async generate(session: ExtendedDatabase) {
async generate(session: ExtendedDatabase, dt?: string) {
// ------------------------
// TransactionsFromDatabase
@ -40,16 +40,32 @@ export class ReportingWorkflow {
{
// Load balances from database
balances = await totalBalances(session);
if (dt) {
balances = await totalBalancesAtDate(session, dt);
} else {
balances = await totalBalances(session);
}
this.reportsForStage.set(ReportingStage.TransactionsFromDatabase, [new TrialBalanceReport(balances)]);
// Load transactions from database
const joinedTransactionPostings: JoinedTransactionPosting[] = 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`
);
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
WHERE DATE(dt) <= DATE($1)
ORDER BY dt, transaction_id, postings.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`
);
}
const transactions = joinedToTransactions(joinedTransactionPostings);
this.transactionsForStage.set(ReportingStage.TransactionsFromDatabase, transactions);
}
@ -59,12 +75,22 @@ export class ReportingWorkflow {
{
// Get unreconciled statement lines
const unreconciledStatementLines: StatementLine[] = await session.select(
// On testing, JOIN is much faster than WHERE NOT EXISTS
`SELECT statement_lines.* FROM statement_lines
LEFT JOIN statement_line_reconciliations ON statement_lines.id = statement_line_reconciliations.statement_line_id
WHERE statement_line_reconciliations.id IS NULL`
);
let unreconciledStatementLines: StatementLine[];
if (dt) {
unreconciledStatementLines = await session.select(
// On testing, JOIN is much faster than WHERE NOT EXISTS
`SELECT statement_lines.* FROM statement_lines
LEFT JOIN statement_line_reconciliations ON statement_lines.id = statement_line_reconciliations.statement_line_id
WHERE statement_line_reconciliations.id IS NULL AND DATE(dt) <= DATE($1)`,
[dt]
);
} else {
unreconciledStatementLines = await session.select(
`SELECT statement_lines.* FROM statement_lines
LEFT JOIN statement_line_reconciliations ON statement_lines.id = statement_line_reconciliations.statement_line_id
WHERE statement_line_reconciliations.id IS NULL`
);
}
const transactions = [];
for (const line of unreconciledStatementLines) {