Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Use materialized view for vault pnl data. #2598

Merged
merged 4 commits into from
Nov 22, 2024
Merged
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
@@ -0,0 +1,209 @@
import {
PnlTickInterval,
PnlTicksFromDatabase,
} from '../../src/types';
import * as VaultPnlTicksView from '../../src/stores/vault-pnl-ticks-view';
import * as PnlTicksTable from '../../src/stores/pnl-ticks-table';
import * as BlockTable from '../../src/stores/block-table';
import * as VaultTable from '../../src/stores/vault-table';
import { clearData, migrate, teardown } from '../../src/helpers/db-helpers';
import { seedData } from '../helpers/mock-generators';
import * as WalletTable from '../../src/stores/wallet-table';
import * as SubaccountTable from '../../src/stores/subaccount-table';
import {
defaultSubaccountId,
defaultSubaccountIdWithAlternateAddress,
defaultSubaccountWithAlternateAddress,
defaultWallet2,
defaultVault,
defaultSubaccount,
} from '../helpers/constants';
import { DateTime } from 'luxon';

describe('PnlTicks store', () => {
beforeEach(async () => {
await seedData();
await WalletTable.create(defaultWallet2);
await SubaccountTable.create(defaultSubaccountWithAlternateAddress);
await Promise.all([
VaultTable.create({
...defaultVault,
address: defaultSubaccount.address,
}),
VaultTable.create({
...defaultVault,
address: defaultSubaccountWithAlternateAddress.address,
}),
]);
});

beforeAll(async () => {
await migrate();
});

afterEach(async () => {
await clearData();
});

afterAll(async () => {
await teardown();
});
vincentwschau marked this conversation as resolved.
Show resolved Hide resolved

it.each([
{
description: 'Get hourly pnl ticks',
interval: PnlTickInterval.hour,
},
{
description: 'Get daily pnl ticks',
interval: PnlTickInterval.day,
},
])('$description', async ({
interval,
}: {
interval: PnlTickInterval,
}) => {
const createdTicks: PnlTicksFromDatabase[] = await setupIntervalPnlTicks();
await VaultPnlTicksView.refreshDailyView();
await VaultPnlTicksView.refreshHourlyView();
const pnlTicks: PnlTicksFromDatabase[] = await VaultPnlTicksView.getVaultsPnl(
interval,
7 * 24 * 60 * 60, // 1 week
DateTime.fromISO(createdTicks[8].blockTime).plus({ seconds: 1 }),
);
// See setup function for created ticks.
// Should exclude tick that is within the same hour except the first.
const expectedHourlyTicks: PnlTicksFromDatabase[] = [
createdTicks[7],
createdTicks[5],
createdTicks[2],
createdTicks[0],
];
// Should exclude ticks that is within the same day except for the first.
const expectedDailyTicks: PnlTicksFromDatabase[] = [
createdTicks[7],
createdTicks[2],
];

if (interval === PnlTickInterval.day) {
expect(pnlTicks).toEqual(expectedDailyTicks);
} else if (interval === PnlTickInterval.hour) {
expect(pnlTicks).toEqual(expectedHourlyTicks);
}
});

async function setupIntervalPnlTicks(): Promise<PnlTicksFromDatabase[]> {
const currentTime: DateTime = DateTime.utc().startOf('day');
const tenMinAgo: string = currentTime.minus({ minute: 10 }).toISO();
const almostTenMinAgo: string = currentTime.minus({ second: 603 }).toISO();
const twoHoursAgo: string = currentTime.minus({ hour: 2 }).toISO();
const twoDaysAgo: string = currentTime.minus({ day: 2 }).toISO();
const monthAgo: string = currentTime.minus({ day: 30 }).toISO();
await Promise.all([
BlockTable.create({
blockHeight: '3',
time: monthAgo,
}),
BlockTable.create({
blockHeight: '4',
time: twoDaysAgo,
}),
BlockTable.create({
blockHeight: '6',
time: twoHoursAgo,
}),
BlockTable.create({
blockHeight: '8',
time: almostTenMinAgo,
}),
BlockTable.create({
blockHeight: '10',
time: tenMinAgo,
}),
]);
const createdTicks: PnlTicksFromDatabase[] = await PnlTicksTable.createMany([
{
subaccountId: defaultSubaccountId,
equity: '1100',
createdAt: almostTenMinAgo,
totalPnl: '1200',
netTransfers: '50',
blockHeight: '10',
blockTime: almostTenMinAgo,
},
{
subaccountId: defaultSubaccountId,
equity: '1090',
createdAt: tenMinAgo,
totalPnl: '1190',
netTransfers: '50',
blockHeight: '8',
blockTime: tenMinAgo,
},
{
subaccountId: defaultSubaccountId,
equity: '1080',
createdAt: twoHoursAgo,
totalPnl: '1180',
netTransfers: '50',
blockHeight: '6',
blockTime: twoHoursAgo,
},
{
subaccountId: defaultSubaccountId,
equity: '1070',
createdAt: twoDaysAgo,
totalPnl: '1170',
netTransfers: '50',
blockHeight: '4',
blockTime: twoDaysAgo,
},
{
subaccountId: defaultSubaccountId,
equity: '1200',
createdAt: monthAgo,
totalPnl: '1170',
netTransfers: '50',
blockHeight: '3',
blockTime: monthAgo,
},
{
subaccountId: defaultSubaccountIdWithAlternateAddress,
equity: '200',
createdAt: almostTenMinAgo,
totalPnl: '300',
netTransfers: '50',
blockHeight: '10',
blockTime: almostTenMinAgo,
},
{
subaccountId: defaultSubaccountIdWithAlternateAddress,
equity: '210',
createdAt: tenMinAgo,
totalPnl: '310',
netTransfers: '50',
blockHeight: '8',
blockTime: tenMinAgo,
},
{
subaccountId: defaultSubaccountIdWithAlternateAddress,
equity: '220',
createdAt: twoHoursAgo,
totalPnl: '320',
netTransfers: '50',
blockHeight: '6',
blockTime: twoHoursAgo,
},
{
subaccountId: defaultSubaccountIdWithAlternateAddress,
equity: '230',
createdAt: twoDaysAgo,
totalPnl: '330',
netTransfers: '50',
blockHeight: '4',
blockTime: twoDaysAgo,
},
]);
return createdTicks;
}
});
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
import * as Knex from 'knex';

const RAW_VAULTS_PNL_HOURLY_QUERY: string = `
CREATE MATERIALIZED VIEW IF NOT EXISTS vaults_hourly_pnl AS WITH vault_subaccounts AS
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

niiice

(
SELECT subaccounts.id
FROM vaults,
subaccounts
WHERE vaults.address = subaccounts.address
AND subaccounts."subaccountNumber" = 0), pnl_subaccounts AS
(
SELECT *
FROM vault_subaccounts
UNION
SELECT id
FROM subaccounts
WHERE address = 'dydx18tkxrnrkqc2t0lr3zxr5g6a4hdvqksylxqje4r'
AND "subaccountNumber" = 0)
vincentwschau marked this conversation as resolved.
Show resolved Hide resolved
SELECT "id",
"subaccountId",
"equity",
"totalPnl",
"netTransfers",
"createdAt",
"blockHeight",
"blockTime"
FROM (
SELECT pnl_ticks.*,
ROW_NUMBER() OVER ( partition BY "subaccountId", DATE_TRUNC( 'hour', "blockTime" ) ORDER BY "blockTime" ) AS r
FROM pnl_ticks
WHERE "subaccountId" IN
(
SELECT *
FROM pnl_subaccounts)
AND "blockTime" >= NOW() - interval '604800 second' ) AS pnl_intervals
WHERE r = 1
ORDER BY "subaccountId";
`;

export async function up(knex: Knex): Promise<void> {
await knex.raw(RAW_VAULTS_PNL_HOURLY_QUERY);
await knex.raw('CREATE UNIQUE INDEX ON vaults_hourly_pnl (id);');
}

export async function down(knex: Knex): Promise<void> {
await knex.raw('DROP MATERIALIZED VIEW IF EXISTS vaults_hourly_pnl;');
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
import * as Knex from 'knex';

const RAW_VAULTS_PNL_DAILY_QUERY: string = `
CREATE MATERIALIZED VIEW IF NOT EXISTS vaults_daily_pnl AS WITH vault_subaccounts AS
(
SELECT subaccounts.id
FROM vaults,
subaccounts
WHERE vaults.address = subaccounts.address
AND subaccounts."subaccountNumber" = 0), pnl_subaccounts AS
(
SELECT *
FROM vault_subaccounts
UNION
SELECT id
FROM subaccounts
WHERE address = 'dydx18tkxrnrkqc2t0lr3zxr5g6a4hdvqksylxqje4r'
vincentwschau marked this conversation as resolved.
Show resolved Hide resolved
AND "subaccountNumber" = 0)
SELECT "id",
"subaccountId",
"equity",
"totalPnl",
"netTransfers",
"createdAt",
"blockHeight",
"blockTime"
FROM (
SELECT pnl_ticks.*,
ROW_NUMBER() OVER ( partition BY "subaccountId", DATE_TRUNC( 'day', "blockTime" ) ORDER BY "blockTime" ) AS r
FROM pnl_ticks
WHERE "subaccountId" IN
(
SELECT *
FROM pnl_subaccounts)
AND "blockTime" >= NOW() - interval '7776000 second' ) AS pnl_intervals
vincentwschau marked this conversation as resolved.
Show resolved Hide resolved
WHERE r = 1
ORDER BY "subaccountId";
`;

export async function up(knex: Knex): Promise<void> {
await knex.raw(RAW_VAULTS_PNL_DAILY_QUERY);
await knex.raw('CREATE UNIQUE INDEX ON vaults_daily_pnl (id);');
}

export async function down(knex: Knex): Promise<void> {
await knex.raw('DROP MATERIALIZED VIEW IF EXISTS vaults_daily_pnl;');
}
1 change: 1 addition & 0 deletions indexer/packages/postgres/src/index.ts
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,7 @@ export * as AffiliateReferredUsersTable from './stores/affiliate-referred-users-
export * as FirebaseNotificationTokenTable from './stores/firebase-notification-token-table';
export * as AffiliateInfoTable from './stores/affiliate-info-table';
export * as VaultTable from './stores/vault-table';
export * as VaultPnlTicksView from './stores/vault-pnl-ticks-view';

export * as perpetualMarketRefresher from './loops/perpetual-market-refresher';
export * as assetRefresher from './loops/asset-refresher';
Expand Down
64 changes: 64 additions & 0 deletions indexer/packages/postgres/src/stores/vault-pnl-ticks-view.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
import { DateTime } from 'luxon';

import { knexReadReplica } from '../helpers/knex';
import { rawQuery } from '../helpers/stores-helpers';
import {
PnlTickInterval,
PnlTicksFromDatabase,
} from '../types';

const VAULT_HOURLY_PNL_VIEW: string = 'vaults_hourly_pnl';
const VAULT_DAILY_PNL_VIEW: string = 'vaults_daily_pnl';

export async function refreshHourlyView(): Promise<void> {
await rawQuery(
`REFRESH MATERIALIZED VIEW CONCURRENTLY ${VAULT_HOURLY_PNL_VIEW}`,
{
readReplica: false,
},
);
}

export async function refreshDailyView(): Promise<void> {
await rawQuery(
`REFRESH MATERIALIZED VIEW CONCURRENTLY ${VAULT_DAILY_PNL_VIEW}`,
{
readReplica: false,
},
);
}

export async function getVaultsPnl(
interval: PnlTickInterval,
timeWindowSeconds: number,
earliestDate: DateTime,
): Promise<PnlTicksFromDatabase[]> {
let viewName: string = VAULT_DAILY_PNL_VIEW;
if (interval === PnlTickInterval.hour) {
viewName = VAULT_HOURLY_PNL_VIEW;
}
const result: {
rows: PnlTicksFromDatabase[],
} = await knexReadReplica.getConnection().raw(
`
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

sql!!

SELECT
"id",
"subaccountId",
"equity",
"totalPnl",
"netTransfers",
"createdAt",
"blockHeight",
"blockTime"
FROM ${viewName}
WHERE
"blockTime" >= '${earliestDate.toUTC().toISO()}'::timestamp AND
"blockTime" > NOW() - INTERVAL '${timeWindowSeconds} second'
ORDER BY "subaccountId", "blockTime";
`,
) as unknown as {
rows: PnlTicksFromDatabase[],
};

return result.rows;
}
Loading
Loading