2
0
mirror of https://github.com/frappe/books.git synced 2024-12-23 19:39:07 +00:00
books/backend/database/bespoke.ts

Ignoring revisions in .git-blame-ignore-revs. Click here to bypass and see the normal blame view.

123 lines
3.2 KiB
TypeScript
Raw Normal View History

import DatabaseCore from './core';
import { BespokeFunction } from './types';
export class BespokeQueries {
[key: string]: BespokeFunction;
static async getLastInserted(
db: DatabaseCore,
schemaName: string
): Promise<number> {
const lastInserted = (await db.knex!.raw(
'select cast(name as int) as num from ?? order by num desc limit 1',
[schemaName]
)) as { num: number }[];
const num = lastInserted?.[0]?.num;
if (num === undefined) {
return 0;
}
return num;
}
static async getTopExpenses(
db: DatabaseCore,
fromDate: string,
toDate: string
) {
const expenseAccounts = db
.knex!.select('name')
.from('Account')
.where('rootType', 'Expense');
const topExpenses = await db
.knex!.select({
2022-05-17 08:08:12 +00:00
total: db.knex!.raw('sum(cast(debit as real) - cast(credit as real))'),
})
.select('account')
.from('AccountingLedgerEntry')
2022-05-17 08:08:12 +00:00
.where('reverted', false)
.where('account', 'in', expenseAccounts)
.whereBetween('date', [fromDate, toDate])
.groupBy('account')
.orderBy('total', 'desc')
.limit(5);
return topExpenses;
}
static async getTotalOutstanding(
db: DatabaseCore,
schemaName: string,
fromDate: string,
toDate: string
) {
return await db.knex!(schemaName)
.sum({ total: 'baseGrandTotal' })
.sum({ outstanding: 'outstandingAmount' })
.where('submitted', true)
.where('cancelled', false)
.whereBetween('date', [fromDate, toDate])
.first();
}
static async getCashflow(db: DatabaseCore, fromDate: string, toDate: string) {
const cashAndBankAccounts = db.knex!('Account')
.select('name')
.where('accountType', 'in', ['Cash', 'Bank'])
.andWhere('isGroup', false);
2022-05-20 11:12:32 +00:00
const dateAsMonthYear = db.knex!.raw(`strftime('%Y-%m', ??)`, 'date');
return await db.knex!('AccountingLedgerEntry')
.where('reverted', false)
.sum({
inflow: 'debit',
outflow: 'credit',
})
.select({
yearmonth: dateAsMonthYear,
})
.where('account', 'in', cashAndBankAccounts)
.whereBetween('date', [fromDate, toDate])
.groupBy(dateAsMonthYear);
}
static async getIncomeAndExpenses(
db: DatabaseCore,
fromDate: string,
toDate: string
) {
const income = await db.knex!.raw(
`
2022-05-17 08:08:12 +00:00
select sum(cast(credit as real) - cast(debit as real)) as balance, strftime('%Y-%m', date) as yearmonth
from AccountingLedgerEntry
where
reverted = false and
date between date(?) and date(?) and
account in (
select name
from Account
where rootType = 'Income'
)
group by yearmonth`,
[fromDate, toDate]
);
const expense = await db.knex!.raw(
`
2022-05-17 08:08:12 +00:00
select sum(cast(debit as real) - cast(credit as real)) as balance, strftime('%Y-%m', date) as yearmonth
from AccountingLedgerEntry
where
reverted = false and
date between date(?) and date(?) and
account in (
select name
from Account
where rootType = 'Expense'
)
group by yearmonth`,
[fromDate, toDate]
);
return { income, expense };
}
}