Skip to content

Commit 770aac8

Browse files
authored
Merge pull request #481 from hack-a-chain-software/issue-480
refactor: improved transfers query for accounts with millions of rows
2 parents 523fd69 + 017c064 commit 770aac8

File tree

2 files changed

+93
-33
lines changed

2 files changed

+93
-33
lines changed
Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
'use strict';
2+
3+
/** @type {import('sequelize-cli').Migration} */
4+
module.exports = {
5+
async up(queryInterface) {
6+
// Remove old indexes
7+
await queryInterface.removeIndex('Transfers', 'to_acct_idx');
8+
await queryInterface.removeIndex('Transfers', 'from_acct_idx');
9+
10+
// Drop and recreate existing indexes with INCLUDE columns
11+
await queryInterface.removeIndex('Transfers', 'transfers_from_acct_creationtime_id_idx');
12+
await queryInterface.removeIndex('Transfers', 'transfers_to_acct_creationtime_id_idx');
13+
14+
// Create new indexes with INCLUDE columns using raw SQL
15+
await queryInterface.sequelize.query(`
16+
CREATE INDEX transfers_from_acct_creationtime_id_idx ON "Transfers" USING btree (from_acct, creationtime, id)
17+
INCLUDE (amount, "chainId", "transactionId", to_acct, modulename, modulehash, requestkey, "orderIndex", "tokenId")
18+
`);
19+
20+
await queryInterface.sequelize.query(`
21+
CREATE INDEX transfers_to_acct_creationtime_id_idx ON "Transfers" USING btree (to_acct, creationtime, id)
22+
INCLUDE (amount, "chainId", "transactionId", from_acct, modulename, modulehash, requestkey, "orderIndex", "tokenId")
23+
`);
24+
},
25+
26+
async down(queryInterface) {
27+
// Drop the new indexes
28+
await queryInterface.removeIndex('Transfers', 'transfers_from_acct_creationtime_id_idx');
29+
await queryInterface.removeIndex('Transfers', 'transfers_to_acct_creationtime_id_idx');
30+
31+
// Recreate the original indexes without INCLUDE
32+
await queryInterface.addIndex('Transfers', ['from_acct', 'creationtime', 'id'], {
33+
name: 'transfers_from_acct_creationtime_id_idx',
34+
});
35+
await queryInterface.addIndex('Transfers', ['to_acct', 'creationtime', 'id'], {
36+
name: 'transfers_to_acct_creationtime_id_idx',
37+
});
38+
39+
// Recreate the old simple indexes
40+
await queryInterface.addIndex('Transfers', ['to_acct'], {
41+
name: 'to_acct_idx',
42+
});
43+
await queryInterface.addIndex('Transfers', ['from_acct'], {
44+
name: 'from_acct_idx',
45+
});
46+
},
47+
};

indexer/src/kadena-server/repository/infra/repository/transfer-db-repository.ts

Lines changed: 46 additions & 33 deletions
Original file line numberDiff line numberDiff line change
@@ -96,7 +96,7 @@ export default class TransferDbRepository implements TransferRepository {
9696
if (chainId) {
9797
queryParams.push(chainId);
9898
const op = operator(queryParams.length);
99-
conditions += `\n${op} b."chainId" = $${queryParams.length}`;
99+
conditions += `\n${op} transfers."chainId" = $${queryParams.length}`;
100100
}
101101

102102
if (fungibleName) {
@@ -136,47 +136,60 @@ export default class TransferDbRepository implements TransferRepository {
136136
let query = '';
137137
if (accountName) {
138138
queryParams.push(accountName);
139+
140+
const columns = `
141+
id,
142+
amount as "transferAmount",
143+
"chainId" as "chainId",
144+
"creationtime" as "creationTime",
145+
"transactionId" as "transactionId",
146+
"from_acct" as "senderAccount",
147+
"to_acct" as "receiverAccount",
148+
modulename as "moduleName",
149+
modulehash as "moduleHash",
150+
requestkey as "requestKey",
151+
"orderIndex",
152+
"tokenId",
153+
"hasTokenId"
154+
`;
139155
query = `
140-
WITH filtered_transfers AS(
141-
SELECT *
142-
FROM (
143-
SELECT *
144-
FROM "Transfers"
145-
WHERE "from_acct" = $${queryParams.length}
146-
UNION ALL
147-
SELECT *
148-
FROM "Transfers"
149-
WHERE "to_acct" = $${queryParams.length}
150-
) transfers
156+
WITH from_transfers AS (
157+
SELECT ${columns}
158+
FROM "Transfers" transfers
159+
${conditions}
160+
AND transfers."from_acct" = $${queryParams.length}
151161
ORDER BY transfers."creationtime" ${order}, transfers.id ${order}
162+
LIMIT 100
163+
),
164+
to_transfers AS (
165+
SELECT ${columns}
166+
FROM "Transfers" transfers
167+
${conditions}
168+
AND transfers."to_acct" = $${queryParams.length}
169+
ORDER BY transfers."creationtime" ${order}, transfers.id ${order}
170+
LIMIT 100
152171
)
153-
select transfers.id as id,
154-
transfers.amount as "transferAmount",
155-
b."chainId" as "chainId",
156-
transfers."creationtime" as "creationTime",
157-
t.id as "transactionId",
172+
SELECT
173+
transfers.*,
158174
b.height as "height",
159-
b.hash as "blockHash",
160-
transfers."from_acct" as "senderAccount",
161-
transfers."to_acct" as "receiverAccount",
162-
transfers.modulename as "moduleName",
163-
transfers.modulehash as "moduleHash",
164-
transfers.requestkey as "requestKey",
165-
transfers."orderIndex" as "orderIndex",
166-
transfers."tokenId" as "tokenId"
167-
from filtered_transfers transfers
168-
join "Transactions" t on t.id = transfers."transactionId"
169-
join "Blocks" b on b."id" = t."blockId"
170-
${conditions}
175+
b.hash as "blockHash"
176+
FROM (
177+
SELECT * FROM from_transfers
178+
UNION ALL
179+
SELECT * FROM to_transfers
180+
) transfers
181+
JOIN "Transactions" t on t.id = transfers."transactionId"
182+
JOIN "Blocks" b on b.id = t."blockId"
183+
ORDER BY transfers."creationTime" ${order}, transfers.id ${order}
171184
LIMIT $1
172185
`;
173186
} else {
174187
query = `
175-
select transfers.id as id,
188+
select transfers.id,
176189
transfers.amount as "transferAmount",
177-
b."chainId" as "chainId",
190+
transfers."chainId" as "chainId",
178191
transfers."creationtime" as "creationTime",
179-
t.id as "transactionId",
192+
transfers."transactionId" as "transactionId",
180193
b.height as "height",
181194
b.hash as "blockHash",
182195
transfers."from_acct" as "senderAccount",
@@ -188,7 +201,7 @@ export default class TransferDbRepository implements TransferRepository {
188201
transfers."tokenId" as "tokenId"
189202
from "Transfers" transfers
190203
join "Transactions" t on t.id = transfers."transactionId"
191-
join "Blocks" b on b."id" = t."blockId"
204+
join "Blocks" b on b.id = t."blockId"
192205
${conditions}
193206
ORDER BY transfers.creationtime ${order}, transfers.id ${order}
194207
LIMIT $1

0 commit comments

Comments
 (0)