Feature/add unique constraint to account balance database schema (#3315)

* Add accountId and date as unique constraint to AccountBalance schema

* Update changelog
pull/3316/head
Thomas Kaul 4 weeks ago committed by GitHub
parent 2d70b18593
commit 1132dc9bdd
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194

@ -7,6 +7,10 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0
## Unreleased
### Added
- Added `accountId` and `date` as a unique constraint to the `AccountBalance` database schema
### Fixed
- Fixed an issue with `totalValueInBaseCurrency` in the value redaction interceptor for the impersonation mode

@ -1,6 +1,7 @@
import { AccountService } from '@ghostfolio/api/app/account/account.service';
import { HasPermission } from '@ghostfolio/api/decorators/has-permission.decorator';
import { HasPermissionGuard } from '@ghostfolio/api/guards/has-permission.guard';
import { resetHours } from '@ghostfolio/common/helper';
import { permissions } from '@ghostfolio/common/permissions';
import type { RequestWithUser } from '@ghostfolio/common/types';
@ -17,6 +18,7 @@ import {
import { REQUEST } from '@nestjs/core';
import { AuthGuard } from '@nestjs/passport';
import { AccountBalance } from '@prisma/client';
import { parseISO } from 'date-fns';
import { StatusCodes, getReasonPhrase } from 'http-status-codes';
import { AccountBalanceService } from './account-balance.service';
@ -50,17 +52,11 @@ export class AccountBalanceController {
);
}
return this.accountBalanceService.createAccountBalance({
Account: {
connect: {
id_userId: {
id: account.id,
userId: account.userId
}
}
},
return this.accountBalanceService.createOrUpdateAccountBalance({
accountId: account.id,
balance: data.balance,
date: data.date,
value: data.balance
userId: account.userId
});
}

@ -1,10 +1,14 @@
import { ExchangeRateDataService } from '@ghostfolio/api/services/exchange-rate-data/exchange-rate-data.service';
import { PrismaService } from '@ghostfolio/api/services/prisma/prisma.service';
import { resetHours } from '@ghostfolio/common/helper';
import { AccountBalancesResponse, Filter } from '@ghostfolio/common/interfaces';
import { UserWithSettings } from '@ghostfolio/common/types';
import { Injectable } from '@nestjs/common';
import { AccountBalance, Prisma } from '@prisma/client';
import { parseISO } from 'date-fns';
import { CreateAccountBalanceDto } from './create-account-balance.dto';
@Injectable()
export class AccountBalanceService {
@ -24,11 +28,36 @@ export class AccountBalanceService {
});
}
public async createAccountBalance(
data: Prisma.AccountBalanceCreateInput
): Promise<AccountBalance> {
return this.prismaService.accountBalance.create({
data
public async createOrUpdateAccountBalance({
accountId,
balance,
date,
userId
}: CreateAccountBalanceDto & {
userId: string;
}): Promise<AccountBalance> {
return this.prismaService.accountBalance.upsert({
create: {
Account: {
connect: {
id_userId: {
userId,
id: accountId
}
}
},
date: resetHours(parseISO(date)),
value: balance
},
update: {
value: balance
},
where: {
accountId_date: {
accountId,
date: resetHours(parseISO(date))
}
}
});
}

@ -6,6 +6,7 @@ import { Filter } from '@ghostfolio/common/interfaces';
import { Injectable } from '@nestjs/common';
import { Account, Order, Platform, Prisma } from '@prisma/client';
import { Big } from 'big.js';
import { parseISO } from 'date-fns';
import { groupBy } from 'lodash';
import { CashDetails } from './interfaces/cash-details.interface';
@ -242,17 +243,11 @@ export class AccountService {
);
if (amountInCurrencyOfAccount) {
await this.accountBalanceService.createAccountBalance({
date,
Account: {
connect: {
id_userId: {
userId,
id: accountId
}
}
},
value: new Big(balance).plus(amountInCurrencyOfAccount).toNumber()
await this.accountBalanceService.createOrUpdateAccountBalance({
accountId,
userId,
balance: new Big(balance).plus(amountInCurrencyOfAccount).toNumber(),
date: date.toISOString()
});
}
}

@ -0,0 +1,29 @@
-- Only keep the newest AccountBalance entry for each account / day
WITH entries_to_keep AS (
SELECT
id,
"accountId",
date,
ROW_NUMBER() OVER (PARTITION BY "accountId", DATE(date) ORDER BY date DESC) AS row_num
FROM
"AccountBalance"
),
entries_to_delete AS (
SELECT
id
FROM
entries_to_keep
WHERE
row_num > 1
)
DELETE FROM
"AccountBalance"
WHERE
id IN (SELECT id FROM entries_to_delete);
-- Reset time part of the date
UPDATE "AccountBalance"
SET date = DATE_TRUNC('day', date);
-- CreateIndex
CREATE UNIQUE INDEX "AccountBalance_accountId_date_key" ON "AccountBalance"("accountId", "date");

@ -59,6 +59,7 @@ model AccountBalance {
value Float
Account Account @relation(fields: [accountId, userId], onDelete: Cascade, references: [id, userId])
@@unique([accountId, date])
@@index([accountId])
@@index([date])
}

Loading…
Cancel
Save