From 72eeb034251ba88dcf86b332ead875f7f32d45e4 Mon Sep 17 00:00:00 2001 From: Linus Miller Date: Thu, 18 Dec 2025 07:30:51 +0100 Subject: [PATCH] WIP knex > kysely --- .bruno/API/api-invoices--id.bru | 2 +- .bruno/API/api-invoices-total-amount.bru | 1 - .bruno/API/api-invoices.bru | 8 +- .../{api-objects--id.bru => api-journals.bru} | 7 +- .bruno/API/api-objects--id-transactions.bru | 20 ++ .bruno/API/api-results--year.bru | 6 +- .bruno/API/api-transactions.bru | 4 +- server/lib/kysely_helpers.ts | 57 ++++-- server/routes/api/balances.ts | 30 ++- server/routes/api/entries.ts | 86 +++++---- server/routes/api/financial_years.ts | 4 +- server/routes/api/invoices.ts | 182 +++++++----------- server/routes/api/journals.ts | 5 +- server/routes/api/objects.ts | 35 ++-- server/routes/api/results.ts | 99 +++------- server/routes/api/transactions.ts | 14 +- 16 files changed, 266 insertions(+), 294 deletions(-) rename .bruno/API/{api-objects--id.bru => api-journals.bru} (52%) create mode 100644 .bruno/API/api-objects--id-transactions.bru diff --git a/.bruno/API/api-invoices--id.bru b/.bruno/API/api-invoices--id.bru index e17cad0..8eb799f 100644 --- a/.bruno/API/api-invoices--id.bru +++ b/.bruno/API/api-invoices--id.bru @@ -11,7 +11,7 @@ get { } params:path { - id: 1000 + id: 10 } settings { diff --git a/.bruno/API/api-invoices-total-amount.bru b/.bruno/API/api-invoices-total-amount.bru index 314bf7e..58c5be4 100644 --- a/.bruno/API/api-invoices-total-amount.bru +++ b/.bruno/API/api-invoices-total-amount.bru @@ -12,7 +12,6 @@ get { params:query { supplier: 150 - : } settings { diff --git a/.bruno/API/api-invoices.bru b/.bruno/API/api-invoices.bru index 5d020b2..6798d89 100644 --- a/.bruno/API/api-invoices.bru +++ b/.bruno/API/api-invoices.bru @@ -5,11 +5,17 @@ meta { } get { - url: {{base_url}}/api/invoices + url: {{base_url}}/api/invoices?limit=2&supplierId=10 body: none auth: inherit } +params:query { + limit: 2 + supplierId: 10 + ~year: 2015 +} + settings { encodeUrl: true timeout: 0 diff --git a/.bruno/API/api-objects--id.bru b/.bruno/API/api-journals.bru similarity index 52% rename from .bruno/API/api-objects--id.bru rename to .bruno/API/api-journals.bru index 7d84c0e..64ab9ea 100644 --- a/.bruno/API/api-objects--id.bru +++ b/.bruno/API/api-journals.bru @@ -1,16 +1,15 @@ meta { - name: /api/objects/:id + name: /api/journals type: http - seq: 12 + seq: 20 } get { - url: {{base_url}}/api/objects/10 + url: {{base_url}}/api/journals body: none auth: inherit } settings { encodeUrl: true - timeout: 0 } diff --git a/.bruno/API/api-objects--id-transactions.bru b/.bruno/API/api-objects--id-transactions.bru new file mode 100644 index 0000000..d64d9bd --- /dev/null +++ b/.bruno/API/api-objects--id-transactions.bru @@ -0,0 +1,20 @@ +meta { + name: /api/objects/:id/transactions + type: http + seq: 12 +} + +get { + url: {{base_url}}/api/objects/:id/transactions + body: none + auth: inherit +} + +params:path { + id: 10 +} + +settings { + encodeUrl: true + timeout: 0 +} diff --git a/.bruno/API/api-results--year.bru b/.bruno/API/api-results--year.bru index 9606dda..cbf4b90 100644 --- a/.bruno/API/api-results--year.bru +++ b/.bruno/API/api-results--year.bru @@ -5,11 +5,15 @@ meta { } get { - url: {{base_url}}/api/results/2018 + url: {{base_url}}/api/results/:year body: none auth: inherit } +params:path { + year: 2017 +} + settings { encodeUrl: true timeout: 0 diff --git a/.bruno/API/api-transactions.bru b/.bruno/API/api-transactions.bru index 45059df..daebbf4 100644 --- a/.bruno/API/api-transactions.bru +++ b/.bruno/API/api-transactions.bru @@ -5,14 +5,14 @@ meta { } get { - url: {{base_url}}/api/transactions?year=2020&accountNumber=4800 + url: {{base_url}}/api/transactions?year=2020 body: none auth: inherit } params:query { year: 2020 - accountNumber: 4800 + ~accountNumber: 4800 } settings { diff --git a/server/lib/kysely_helpers.ts b/server/lib/kysely_helpers.ts index fac2401..98a9cd3 100644 --- a/server/lib/kysely_helpers.ts +++ b/server/lib/kysely_helpers.ts @@ -1,9 +1,25 @@ import { type SelectQueryBuilder, type ReferenceExpression, type OperandValueExpression, sql } from 'kysely' +type ColumnsOf = T extends any ? keyof DB[T] & string : never + +type AppearsIn = { + [T in TB]: Col extends ColumnsOf ? T : never +}[TB] + +type IsUnion = T extends any ? ([U] extends [T] ? false : true) : never + +type UniqueColumn = { + [C in ColumnsOf]: IsUnion> extends true ? never : C +}[ColumnsOf] + +type PrefixedColumn = TB extends any ? `${TB & string}.${keyof DB[TB] & string}` : never + +type UnambiguousColumn = PrefixedColumn | UniqueColumn + type WhereInput = Partial<{ - [C in keyof DB[TB]]: - | OperandValueExpression - | readonly OperandValueExpression[] + [C in UnambiguousColumn]: + | OperandValueExpression + | readonly OperandValueExpression[] | null }> @@ -16,10 +32,16 @@ export function applyWhere( if (value === null) { return builder.where(column, 'is', null) - } else if (Array.isArray(value)) { + } + + if (Array.isArray(value)) { return builder.where(column, 'in', value) } + if (value === undefined) { + return builder + } + return builder.where(column, '=', value) }, builder) } @@ -28,20 +50,19 @@ interface PaginationInput { where: WhereInput limit?: number offset?: number - orderBy?: { - column: ReferenceExpression - direction?: 'asc' | 'desc' - } + sort?: UnambiguousColumn | `-${UnambiguousColumn}` } export function applyPagination( builder: SelectQueryBuilder, - { limit, offset, orderBy }: PaginationInput, + { limit, offset, sort }: PaginationInput, ): SelectQueryBuilder { let qb = builder - if (orderBy) { - qb = qb.orderBy(orderBy.column, orderBy.direction ?? 'asc') + if (sort) { + const columnName = (sort.startsWith('-') ? sort.slice(1) : sort) as UnambiguousColumn + + qb = qb.orderBy(columnName, columnName === sort ? 'asc' : 'desc') } if (limit !== undefined) { @@ -68,13 +89,15 @@ export async function paginate( countQuery = applyWhere(countQuery, input.where) } - const [countRow, items] = await Promise.all([countQuery.executeTakeFirstOrThrow(), dataQuery.execute()]) + const [countRow, data] = await Promise.all([countQuery.executeTakeFirstOrThrow(), dataQuery.execute()]) return { - items, - totalCount: (countRow as { totalCount: number }).totalCount, - limit: input.limit, - offset: input.offset, - count: items.length, + data, + meta: { + totalCount: (countRow as { totalCount: number }).totalCount, + limit: input.limit, + offset: input.offset, + count: data.length, + }, } } diff --git a/server/routes/api/balances.ts b/server/routes/api/balances.ts index eda0c7b..a7687b8 100644 --- a/server/routes/api/balances.ts +++ b/server/routes/api/balances.ts @@ -1,32 +1,30 @@ import _ from 'lodash' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' +import { sql } from 'kysely' const balanceRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify + fastify.route({ url: '/', method: 'GET', async handler() { - const financialYears = await knex('financialYear').select('*').orderBy('year', 'asc') + const financialYears = await db.selectFrom('financialYear').select('year').orderBy('year').execute() - return knex('accountBalance AS ab') + return db + .selectFrom('accountBalance as ab') + .innerJoin('financialYear as fy', 'fy.id', 'ab.financialYearId') + .innerJoin('account as a', 'a.number', 'ab.accountNumber') + .select(['ab.accountNumber', 'a.description']) .select( - 'ab.accountNumber', - 'a.description', - Object.fromEntries( - financialYears.map((fy) => [ - fy.year, - knex.raw(`SUM(CASE WHEN fy.year = ${fy.year} THEN ab."out" ELSE 0 END)`), - ]), + financialYears.map((fy) => + sql`SUM(CASE WHEN fy.year = ${fy.year} THEN ab."out" ELSE 0 END)`.as(fy.year.toString()), ), ) - .innerJoin('financialYear AS fy', 'fy.id', 'ab.financialYearId') - .innerJoin('account AS a', function () { - this.on('ab.accountNumber', '=', 'a.number') - }) - .groupBy('ab.accountNumber', 'a.description') - .where('ab.accountNumber', '<', 3000) + .groupBy(['ab.accountNumber', 'a.description']) .orderBy('ab.accountNumber') + .where('ab.accountNumber', '<', 3000) + .execute() }, }) diff --git a/server/routes/api/entries.ts b/server/routes/api/entries.ts index 75a3624..2558687 100644 --- a/server/routes/api/entries.ts +++ b/server/routes/api/entries.ts @@ -1,34 +1,38 @@ import _ from 'lodash' import * as z from 'zod' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' +import { jsonArrayFrom } from 'kysely/helpers/postgres' +import { applyWhere } from '../../lib/kysely_helpers.ts' const entryRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify + fastify.route({ url: '/', method: 'GET', schema: { querystring: z.object({ - journal: z.string(), - year: z.coerce.number(), + journal: z.string().optional(), + year: z.coerce.number().optional(), }), }, - async handler(req) { - const financialYearId = (await knex('financialYear').first('id').where('year', req.query.year))?.id - const journalId = (await knex('journal').first('id').where('identifier', req.query.journal))?.id - - if (!financialYearId || !journalId) { - return null - } - - return knex('entry AS e') - .select('e.*') - .sum('t.amount AS amount') - .innerJoin('transaction AS t', 'e.id', 't.entryId') - .orderBy('e.id') - .where({ financialYearId, journalId }) - .andWhere('t.amount', '>', 0) - .groupBy('e.id') + async handler(request) { + return applyWhere( + db + .selectFrom('entry as e') + .innerJoin('transaction as t', 'e.id', 't.entryId') + .innerJoin('journal as j', 'j.id', 'e.journalId') + .innerJoin('financialYear as fy', 'fy.id', 'e.financialYearId') + .selectAll('e') + .select((eb) => eb.fn.sum('t.amount').as('amount')) + .orderBy('e.id') + .where('t.amount', '>', 0 as ANY) + .groupBy('e.id'), + { + year: request.query.year, + 'j.identifier': request.query.journal, + }, + ).execute() }, }) @@ -37,27 +41,35 @@ const entryRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { method: 'GET', schema: { params: z.object({ - id: z.number(), + id: z.coerce.number(), }), }, async handler(req) { - return knex('entry AS e') - .first('e.id', 'j.identifier AS journal', 'e.number', 'e.entryDate', 'e.transactionDate', 'e.description', { - transactions: knex - .select(knex.raw('json_agg(transactions)')) - .from( - knex('transaction') - .select('accountNumber', 'objectId') - .where('transaction.entryId', knex.ref('e.id')) - .as('transactions'), - ), - }) - .sum('t.amount AS amount') - .innerJoin('journal AS j', 'e.journalId', 'j.id') - .innerJoin('transaction AS t', 'e.id', 't.entryId') - .where('e.id', req.params.id) - .andWhere('t.amount', '>', 0) - .groupBy('e.id', 'j.identifier') + return db + .selectFrom('entry as e') + .innerJoin('journal as j', 'e.journalId', 'j.id') + .innerJoin('transaction as t', 'e.id', 't.entryId') + .select([ + 'e.id', + 'j.identifier as journal', + 'e.number', + 'e.entryDate', + 'e.transactionDate', + 'e.description', + (eb) => eb.fn.sum('t.amount').as('amount'), + (eb) => + jsonArrayFrom( + eb + .selectFrom('transaction as t') + .select(['id', 'accountNumber', 'amount', 'description']) + .selectAll() + .whereRef('t.entryId', '=', 'e.id'), + ).as('transactions'), + ]) + .groupBy(['e.id', 'j.identifier']) + .where('e.id', '=', req.params.id) + .where('t.amount', '>', 0 as ANY) + .execute() }, }) diff --git a/server/routes/api/financial_years.ts b/server/routes/api/financial_years.ts index abec382..989fc2d 100644 --- a/server/routes/api/financial_years.ts +++ b/server/routes/api/financial_years.ts @@ -1,13 +1,13 @@ import _ from 'lodash' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' const financialYearRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify fastify.route({ url: '/', method: 'GET', handler() { - return knex('financialYear').select('*').orderBy('startDate', 'desc') + return db.selectFrom('financialYear').selectAll().orderBy('startDate', 'desc').execute() }, }) diff --git a/server/routes/api/invoices.ts b/server/routes/api/invoices.ts index 1421508..d212889 100644 --- a/server/routes/api/invoices.ts +++ b/server/routes/api/invoices.ts @@ -1,52 +1,52 @@ import _ from 'lodash' +import { jsonArrayFrom } from 'kysely/helpers/postgres' import * as z from 'zod' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' -import StatusError from '../../lib/status_error.ts' +import { applyWhere, paginate } from '../../lib/kysely_helpers.ts' const invoiceRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify + fastify.route({ url: '/', method: 'GET', schema: { querystring: z.object({ - year: z.number().optional(), - supplier: z.number().optional(), + year: z.coerce.number().optional(), + supplierId: z.coerce.number().optional(), + limit: z.coerce.number().default(100), + offset: z.coerce.number().optional(), + sort: z.literal(['supplierId', 'i.id', 'invoiceDate', 'dueDate']).default('i.id'), }), }, - async handler(req) { - let query: { financialYearId?: number; supplierId?: number } = {} + async handler(request) { + const { offset, limit, sort, ...where } = request.query + const baseQuery = db.selectFrom('invoice as i').leftJoin('financialYear as fy', 'fy.id', 'i.financialYearId') - if (req.query.year) { - const year = await knex('financialYear').first('*').where('year', req.query.year) - - if (!year) throw new StatusError(404, `Year ${req.query.year} not found.`) - query.financialYearId = year.id - } - - if (req.query.supplier) { - query.supplierId = req.query.supplier - } - - return knex('invoice AS i') - .select('i.*', 'fy.year', { - files: knex - .select(knex.raw('json_agg(files)')) - .from( - knex - .select('id', 'filename') - .from('file AS f') - .innerJoin('filesToInvoice AS fi', 'f.id', 'fi.fileId') - .where('fi.invoiceId', knex.ref('i.id')) - .as('files'), + return paginate( + baseQuery + .selectAll('i') + .select(['fy.year']) + .select((eb) => [ + jsonArrayFrom( + eb + .selectFrom('file as f') + .innerJoin('filesToInvoice as fi', 'f.id', 'fi.fileId') + .select(['id', 'filename']) + .whereRef('fi.invoiceId', '=', 'i.id'), + ).as('files'), + jsonArrayFrom(eb.selectFrom('transaction as t').selectAll().whereRef('t.invoiceId', '=', 'i.id')).as( + 'transactions', ), - transactions: knex - .select(knex.raw('json_agg(transactions)')) - .from(knex.select('*').from('transaction AS t').where('t.invoiceId', knex.ref('i.id')).as('transactions')), - }) - .leftOuterJoin('financialYear AS fy', 'i.financialYearId', 'fy.id') - .orderBy('i.invoiceDate') - .where(query) + ]), + baseQuery, + { + where, + limit, + offset, + sort, + }, + ) }, }) @@ -55,25 +55,19 @@ const invoiceRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { method: 'GET', schema: { querystring: z.object({ - year: z.number().optional(), - supplier: z.number().optional(), + supplierId: z.number().optional(), }), + response: { + 200: z.object({ + totalAmount: z.coerce.number(), + }), + }, }, - async handler(req) { - let query: { financialYearId?: number; supplierId?: number } = {} - - if (req.query.year) { - const year = await knex('financialYear').first('*').where('year', req.query.year) - - if (!year) throw new StatusError(404, `Year ${req.query.year} not found.`) - query.financialYearId = year.id - } - - if (req.query.supplier) { - query.supplierId = req.query.supplier - } - - return knex('invoice AS i').first().sum('i.amount AS amount').where(query) + handler(request) { + return applyWhere( + db.selectFrom('invoice').select((eb) => eb.fn.sum('amount').as('totalAmount')), + request.query, + ).executeTakeFirst() }, }) @@ -82,71 +76,29 @@ const invoiceRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { method: 'GET', schema: { params: z.object({ - id: z.number(), + id: z.coerce.number(), }), }, - handler(req) { - return knex('invoice AS i') - .first('i.*', 'fy.year', { - files: knex - .select(knex.raw('json_agg(files)')) - .from( - knex - .select('id', 'filename') - .from('file AS f') - .innerJoin('filesToInvoice AS fi', 'f.id', 'fi.fileId') - .where('fi.invoiceId', knex.ref('i.id')) - .as('files'), - ), - transactions: knex - .select(knex.raw('json_agg(transactions)')) - .from(knex.select('*').from('transaction AS t').where('t.invoiceId', knex.ref('i.id')).as('transactions')), - }) - .leftOuterJoin('financialYear AS fy', 'i.financialYearId', 'fy.id') - .where('i.id', req.params.id) - }, - }) - - fastify.route({ - url: '/by-supplier/:supplier', - method: 'GET', - schema: { - params: z.object({ - supplier: z.number(), - }), - }, - handler(req) { - return knex('invoice AS i') - .select('*', { - files: knex - .select(knex.raw('json_agg(files)')) - .from( - knex - .select('id', 'filename') - .from('file AS f') - .innerJoin('filesToInvoice AS fi', 'f.id', 'fi.fileId') - .where('fi.invoiceId', knex.ref('i.id')) - .as('files'), - ), - }) - .where('supplierId', req.params.supplier) - }, - }) - - fastify.route({ - url: '/by-year/:year', - method: 'GET', - schema: { - params: z.object({ - year: z.number(), - }), - }, - async handler(req) { - const year = await knex('financialYear').first('*').where('year', req.params.year) - - if (!year) throw new StatusError(404, `Year ${req.params.year} not found.`) - - return knex('invoice').select('*').where('financialYearId', year.id) + handler(request) { + return db + .selectFrom('invoice as i') + .leftJoin('financialYear as fy', 'fy.id', 'i.financialYearId') + .selectAll('i') + .select(['fy.year']) + .select((eb) => [ + jsonArrayFrom( + eb + .selectFrom('file as f') + .innerJoin('filesToInvoice as fi', 'f.id', 'fi.fileId') + .select(['id', 'filename']) + .whereRef('fi.invoiceId', '=', 'i.id'), + ).as('files'), + jsonArrayFrom(eb.selectFrom('transaction as t').selectAll().whereRef('t.invoiceId', '=', 'i.id')).as( + 'transactions', + ), + ]) + .where('i.id', '=', request.params.id) + .execute() }, }) diff --git a/server/routes/api/journals.ts b/server/routes/api/journals.ts index 32bf47c..4876782 100644 --- a/server/routes/api/journals.ts +++ b/server/routes/api/journals.ts @@ -1,13 +1,14 @@ import _ from 'lodash' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' const journalRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify + fastify.route({ url: '/', method: 'GET', handler() { - return knex('journal').select('*').orderBy('identifier') + return db.selectFrom('journal').selectAll().orderBy('identifier').execute() }, }) diff --git a/server/routes/api/objects.ts b/server/routes/api/objects.ts index 187cc67..8ad7b4d 100644 --- a/server/routes/api/objects.ts +++ b/server/routes/api/objects.ts @@ -1,39 +1,38 @@ import _ from 'lodash' import * as z from 'zod' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' const objectRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify + fastify.route({ url: '/', method: 'GET', handler() { - return knex('object AS o') - .select('o.id', 'o.number', 'o.name', 'd.number AS dimensionNumber', 'd.name AS dimensionName') - .innerJoin('dimension AS d', function () { - this.on('o.dimensionId', '=', 'd.id') - }) + return db + .selectFrom('object as o') + .innerJoin('dimension as d', 'd.id', 'o.dimensionId') + .select(['o.id', 'o.number', 'o.name', 'd.number as dimensionNumber', 'd.name as dimensionName']) + .execute() }, }) fastify.route({ - url: '/:id', + url: '/:id/transactions', method: 'GET', schema: { params: z.object({ - id: z.number(), + id: z.coerce.number(), }), }, - async handler(req) { - return knex('transaction AS t') - .select('t.entryId', 'e.transactionDate', 't.accountNumber', 't.amount') - .innerJoin('transactions_to_objects AS to', function () { - this.on('t.id', 'to.transactionId') - }) - .innerJoin('entry AS e', function () { - this.on('e.id', '=', 't.entryId') - }) - .where('to.objectId', req.params.id) + async handler(request) { + return db + .selectFrom('transaction as t') + .innerJoin('transactionsToObjects as to', 't.id', 'to.transactionId') + .innerJoin('entry as e', 'e.id', 't.entryId') + .select(['t.entryId', 'e.transactionDate', 't.accountNumber', 't.amount']) + .where('to.objectId', '=', request.params.id) + .execute() }, }) diff --git a/server/routes/api/results.ts b/server/routes/api/results.ts index 1b8bac8..4b53fe7 100644 --- a/server/routes/api/results.ts +++ b/server/routes/api/results.ts @@ -1,69 +1,33 @@ import _ from 'lodash' import * as z from 'zod' import type { FastifyPluginCallbackZod } from 'fastify-type-provider-zod' -import knex from '../../lib/knex.ts' +import { sql } from 'kysely' const resultRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { + const { db } = fastify + fastify.route({ url: '/', method: 'GET', async handler() { - const financialYears = await knex('financialYear').select('*').orderBy('year', 'asc') + const financialYears = await db.selectFrom('financialYear').selectAll().orderBy('year', 'asc').execute() - return knex('transaction AS t') + return db + .selectFrom('transaction as t') + .innerJoin('entry as e', 't.entryId', 'e.id') + .innerJoin('financialYear as fy', 'fy.id', 'e.financialYearId') + .innerJoin('account as a', 't.accountNumber', 'a.number') + .select(['t.accountNumber', 'a.description']) .select( - 't.accountNumber', - 'a.description', - Object.fromEntries( - financialYears.map((fy) => [ - fy.year, - knex.raw(`SUM(CASE WHEN fy.year = ${fy.year} THEN t.amount ELSE 0 END)`), - ]), + financialYears.map((fy) => + sql`SUM(CASE WHEN fy.year = ${fy.year} THEN t.amount ELSE 0 END)`.as(fy.year.toString()), ), ) - .sum('t.amount AS amount') - .innerJoin('entry AS e', function () { - this.on('t.entryId', '=', 'e.id') - }) - .innerJoin('financialYear AS fy', 'fy.id', 'e.financialYearId') - .innerJoin('account AS a', function () { - this.on('t.accountNumber', '=', 'a.number') - }) - .groupBy('t.accountNumber', 'a.description') + .groupBy(['t.accountNumber', 'a.description']) .where('t.accountNumber', '>=', 3000) .orderBy('t.accountNumber') + .execute() }, - // async handler() { - // const years = await knex('financialYear').select('*') - - // const accounts = await knex('account').select('*') - - // return Promise.all( - // years.map((year) => - // knex('account AS a') - // .select('a.number', 'a.description') - // .sum('t.amount as amount') - // .innerJoin('transaction AS t', function () { - // this.on('t.accountNumber', '=', 'a.number') - // }) - // .innerJoin('entry AS e', function () { - // this.on('t.entryId', '=', 'e.id') - // }) - // .groupBy('a.number', 'a.description') - // .where('a.number', '>=', 3000) - // .where('e.financialYearId', year.id) - // .orderBy('a.number') - // .then((result) => ({ - // startDate: year.startDate, - // endDate: year.endDate, - // result, - // })), - // ), - // ).then((years) => ({ - // accounts, - // years, - // })) - // }, }) fastify.route({ @@ -71,27 +35,24 @@ const resultRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { method: 'GET', schema: { params: z.object({ - year: z.number(), + year: z.coerce.number(), }), }, - async handler(req) { - const year = await knex('financialYear').first('*').where('year', req.params.year) - - if (!year) return null - - return knex('transaction AS t') - .select('t.accountNumber', 'a.description') - .sum('t.amount as amount') - .innerJoin('account AS a', function () { - this.on('t.accountNumber', '=', 'a.number') - }) - .innerJoin('entry AS e', function () { - this.on('t.entryId', '=', 'e.id') - }) - .groupBy('t.accountNumber', 'a.description') - .where('t.accountNumber', '>=', 3000) - .where('e.financialYearId', year.id) - .orderBy('t.accountNumber') + async handler(request) { + return ( + db + .selectFrom('transaction as t') + .innerJoin('entry as e', 't.entryId', 'e.id') + .innerJoin('financialYear as fy', 'fy.id', 'e.financialYearId') + .innerJoin('account as a', 't.accountNumber', 'a.number') + .select(['t.accountNumber', 'a.description', (eb) => eb.fn.sum('t.amount').as('amount')]) + // .sum('t.amount AS amount') + .groupBy(['t.accountNumber', 'a.description']) + .where('t.accountNumber', '>=', 3000) + .where('year', '=', request.params.year) + .orderBy('t.accountNumber') + .execute() + ) }, }) diff --git a/server/routes/api/transactions.ts b/server/routes/api/transactions.ts index 9b4b4d9..e21315c 100644 --- a/server/routes/api/transactions.ts +++ b/server/routes/api/transactions.ts @@ -13,20 +13,20 @@ const transactionRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { querystring: z.object({ year: z.optional(z.coerce.number()), accountNumber: z.optional(z.coerce.number()), - limit: z.number().default(2), - sort: z.string().default('t.id'), - offset: z.number().optional(), + limit: z.coerce.number().default(100), + offset: z.coerce.number().optional(), + sort: z.literal(['accountNumber', 'e.transactionDate', 't.id']).default('t.id'), }), }, async handler(request) { - const { offset, limit, sort: _sort, ...where } = request.query + const { offset, limit, sort, ...where } = request.query const baseQuery = db .selectFrom('transaction as t') .innerJoin('entry as e', 't.entryId', 'e.id') .innerJoin('financialYear as fy', 'e.financialYearId', 'fy.id') - const result = await paginate( + return paginate( baseQuery.select([ 't.accountNumber', 'e.transactionDate', @@ -38,14 +38,12 @@ const transactionRoutes: FastifyPluginCallbackZod = (fastify, _, done) => { ]), baseQuery, { - // @ts-ignore where, limit, offset, + sort, }, ) - - return result }, })