Skip to content
Open
Show file tree
Hide file tree
Changes from all 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
54 changes: 53 additions & 1 deletion src/api/routes/v2/addresses.ts
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,6 @@ import {
handleCache,
handleChainTipCache,
handlePrincipalCache,
handlePrincipalMempoolCache,
handleTransactionCache,
} from '../../../api/controllers/cache-controller';
import { AddressParamsSchema, AddressTransactionParamsSchema } from './schemas';
Expand Down Expand Up @@ -86,6 +85,59 @@ export const AddressRoutesV2: FastifyPluginAsync<
}
);

// Adding temporary dual endpoint for maintainer review and testing
// eslint-disable-next-line no-warning-comments
// TODO(iamramtin): Replace V1 after maintainer review and testing
fastify.get(
'/:address/transactions-v2',
{
preHandler: handlePrincipalCache,
schema: {
operationId: 'get_address_transactions_v2',
summary: 'Get address transactions V2',
description: `Retrieves a paginated list of confirmed transactions sent or received by a STX address or Smart Contract ID, alongside the total amount of STX sent or received and the number of STX, FT and NFT transfers contained within each transaction.

More information on Transaction types can be found [here](https://docs.stacks.co/understand-stacks/transactions#types).`,
tags: ['Transactions'],
params: AddressParamsSchema,
querystring: Type.Object({
limit: LimitParam(ResourceType.Tx),
offset: OffsetParam(),
exclude_function_args: ExcludeFunctionArgsParamSchema,
}),
response: {
200: PaginatedResponse(AddressTransactionSchema),
},
},
},
async (req, reply) => {
const params = req.params;
const query = req.query;
const excludeFunctionArgs = req.query.exclude_function_args ?? false;

try {
const { limit, offset, results, total } = await fastify.db.v2.getAddressTransactionsV2({
...params,
...query,
});
const transfers: AddressTransaction[] = results.map(r =>
parseDbTxWithAccountTransferSummary(r, excludeFunctionArgs)
);
await reply.send({
limit,
offset,
total,
results: transfers,
});
} catch (error) {
if (error instanceof InvalidRequestError) {
throw new NotFoundError(error.message);
}
throw error;
}
}
);

fastify.get(
'/:address/transactions/:tx_id/events',
{
Expand Down
127 changes: 127 additions & 0 deletions src/datastore/address-transactions-indexes.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,127 @@
-- =============================================================================
-- MIGRATION SCRIPT: getAddressTransactions Optimization
-- Eliminates query timeouts for high-transaction addresses
-- =============================================================================

-- Verify no conflicting indexes exist (something like this)
SELECT schemaname, tablename, indexname
FROM pg_indexes
WHERE indexname LIKE '%_canonical_optimized'
OR indexname LIKE '%_subquery_optimized'
ORDER BY tablename, indexname;

-- =============================================================================
-- CANONICAL TRANSACTION FILTERING
-- =============================================================================
-- Problem: The query joins txs table for every transaction to check canonical = TRUE
-- and microblock_canonical = TRUE. This creates expensive nested loops that scan
-- thousands of transactions, applying filters after the join.
--
-- Solution: Create partial index containing only canonical transactions with
-- built-in ordering. This eliminates the filter step entirely and supports
-- efficient sorting without additional operations
--
-- Trade-off: Additional storage on txs table to get significant query speedup.
-- But index only contains canonical transactions which should reduce overall size

CREATE INDEX CONCURRENTLY idx_txs_canonical_optimized
ON txs (tx_id, index_block_hash, microblock_hash, block_height DESC, microblock_sequence DESC, tx_index DESC)
WHERE canonical = TRUE AND microblock_canonical = TRUE;

-- Optional index `address_txs` CTE if it were materialized as its own table
-- CREATE INDEX CONCURRENTLY idx_address_txs_dedupe
-- ON address_txs (tx_id, index_block_hash, microblock_hash);

ANALYZE txs;

-- =============================================================================
-- EVENT TABLE SUBQUERIES
-- =============================================================================
-- Problem: Each transaction requires 11 correlated subqueries that scan event tables
-- using expensive bitmap operations. For 50 returned transactions, this means 550
-- separate bitmap scans combining tx_id and index_block_hash lookups
--
-- Solution: Create compound indexes that cover all subquery conditions in a single
-- lookup. The INCLUDE clause adds frequently accessed columns without increasing
-- the index key size, enabling index-only scans
--
-- Trade-off: Additional storage per event table to remov bitmap
-- operations and heap lookups in subqueries

-- STX Events: used in 5 subqueries per transaction
CREATE INDEX CONCURRENTLY idx_stx_events_subquery_optimized
ON stx_events (tx_id, index_block_hash, microblock_hash, asset_event_type_id)
INCLUDE (amount, sender, recipient);

-- FT Events: used in 3 subqueries per transaction
CREATE INDEX CONCURRENTLY idx_ft_events_subquery_optimized
ON ft_events (tx_id, index_block_hash, microblock_hash, asset_event_type_id)
INCLUDE (sender, recipient);

-- NFT Events: used in 3 subqueries
CREATE INDEX CONCURRENTLY idx_nft_events_subquery_optimized
ON nft_events (tx_id, index_block_hash, microblock_hash, asset_event_type_id)
INCLUDE (sender, recipient);

ANALYZE stx_events, ft_events, nft_events;

-- =============================================================================
-- MONITORING / VERIFICATION
-- =============================================================================

-- Ensure all indexes were created successfully and are valid
SELECT
psi.schemaname,
psi.relname as tablename,
psi.indexrelname,
pi.indisvalid as is_valid,
pi.indisready as is_ready,
pg_size_pretty(pg_relation_size(psi.indexrelid)) as index_size
FROM pg_stat_user_indexes psi
JOIN pg_index pi ON psi.indexrelid = pi.indexrelid
WHERE psi.indexrelname LIKE '%_canonical_optimized'
OR psi.indexrelname LIKE '%_subquery_optimized'
ORDER BY psi.relname, psi.indexrelname;

-- Create view to monitor ongoing performance tracking
CREATE OR REPLACE VIEW address_transactions_performance AS
SELECT
schemaname,
relname as tablename,
pg_stat_user_indexes.indexrelname,
idx_scan as times_used,
pg_size_pretty(pg_relation_size(indexrelid)) as index_size,
CASE
WHEN idx_scan = 0 THEN 'Not yet used'
WHEN idx_scan < 100 THEN 'Low usage'
ELSE 'Active'
END as status
FROM pg_stat_user_indexes
WHERE pg_stat_user_indexes.indexrelname LIKE '%_canonical_optimized'
OR pg_stat_user_indexes.indexrelname LIKE '%_subquery_optimized'
ORDER BY idx_scan DESC;

SELECT * FROM address_transactions_performance;

-- Verify all indexes are valid and being used
SELECT
schemaname, relname, pg_stat_user_indexes.indexrelname, idx_scan,
CASE
WHEN idx_scan = 0 THEN 'INDEX NOT USED - INVESTIGATE'
ELSE 'OK'
END as health_status
FROM pg_stat_user_indexes
WHERE pg_stat_user_indexes.indexrelname LIKE '%_optimized'
ORDER BY idx_scan DESC;

/*
-- Rollback:
DROP INDEX CONCURRENTLY IF EXISTS idx_stx_events_subquery_optimized;
DROP INDEX CONCURRENTLY IF EXISTS idx_ft_events_subquery_optimized;
DROP INDEX CONCURRENTLY IF EXISTS idx_nft_events_subquery_optimized;
DROP INDEX CONCURRENTLY IF EXISTS idx_txs_canonical_optimized;

ANALYZE txs, stx_events, ft_events, nft_events;

DROP VIEW IF EXISTS address_transactions_performance;
*/
174 changes: 174 additions & 0 deletions src/datastore/pg-store-v2.ts
Original file line number Diff line number Diff line change
Expand Up @@ -526,6 +526,7 @@ export class PgStoreV2 extends BasePgStoreModule {
});
}

// Original implementation - kept for comparison during optimization review
async getAddressTransactions(
args: AddressParams & TransactionPaginationQueryParams
): Promise<DbPaginatedResult<DbTxWithAddressTransfers>> {
Expand Down Expand Up @@ -645,6 +646,179 @@ export class PgStoreV2 extends BasePgStoreModule {
});
}

// Optimized implementation
// Key optimizations: early canonical filtering, efficient HashAggregate counting, parallel execution
// eslint-disable-next-line no-warning-comments
// TODO(iamramtin): Replace V1 after maintainer review and testing
async getAddressTransactionsV2(
args: AddressParams & TransactionPaginationQueryParams
): Promise<DbPaginatedResult<DbTxWithAddressTransfers>> {
return await this.sqlTransaction(async sql => {
const limit = args.limit ?? TransactionLimitParamSchema.default;
const offset = args.offset ?? 0;

const eventCond = sql`
tx_id = limited_txs.tx_id
AND index_block_hash = limited_txs.index_block_hash
AND microblock_hash = limited_txs.microblock_hash
`;

const eventAcctCond = sql`
${eventCond} AND (sender = ${args.address} OR recipient = ${args.address})
`;

const resultQuery = await sql<(AddressTransfersTxQueryResult & { count: number })[]>`
WITH address_txs AS (
(
SELECT
t.tx_id,
t.index_block_hash,
t.microblock_hash,
t.block_height AS sort_block_height,
t.microblock_sequence AS sort_microblock_sequence,
t.tx_index AS sort_tx_index
FROM principal_stx_txs p
INNER JOIN txs t USING (tx_id, index_block_hash, microblock_hash)
WHERE p.principal = ${args.address}
AND t.canonical = TRUE
AND t.microblock_canonical = TRUE
)
UNION ALL
(
SELECT
t.tx_id,
t.index_block_hash,
t.microblock_hash,
t.block_height AS sort_block_height,
t.microblock_sequence AS sort_microblock_sequence,
t.tx_index AS sort_tx_index
FROM stx_events se
INNER JOIN txs t USING (tx_id, index_block_hash, microblock_hash)
WHERE (se.sender = ${args.address} OR se.recipient = ${args.address})
AND t.canonical = TRUE
AND t.microblock_canonical = TRUE
)
UNION ALL
(
SELECT
t.tx_id,
t.index_block_hash,
t.microblock_hash,
t.block_height AS sort_block_height,
t.microblock_sequence AS sort_microblock_sequence,
t.tx_index AS sort_tx_index
FROM ft_events fe
INNER JOIN txs t USING (tx_id, index_block_hash, microblock_hash)
WHERE (fe.sender = ${args.address} OR fe.recipient = ${args.address})
AND t.canonical = TRUE
AND t.microblock_canonical = TRUE
)
UNION ALL
(
SELECT
t.tx_id,
t.index_block_hash,
t.microblock_hash,
t.block_height AS sort_block_height,
t.microblock_sequence AS sort_microblock_sequence,
t.tx_index AS sort_tx_index
FROM nft_events ne
INNER JOIN txs t USING (tx_id, index_block_hash, microblock_hash)
WHERE (ne.sender = ${args.address} OR ne.recipient = ${args.address})
AND t.canonical = TRUE
AND t.microblock_canonical = TRUE
)
),
deduped_txs AS (
SELECT DISTINCT
tx_id,
index_block_hash,
microblock_hash,
sort_block_height,
sort_microblock_sequence,
sort_tx_index
FROM address_txs
),
limited_txs AS (
SELECT *
FROM deduped_txs
ORDER BY sort_block_height DESC, sort_microblock_sequence DESC, sort_tx_index DESC
LIMIT ${limit}
OFFSET ${offset}
)
SELECT
${sql(TX_COLUMNS)},
(
SELECT COALESCE(SUM(amount), 0)
FROM stx_events
WHERE ${eventCond} AND sender = ${args.address}
) +
CASE
WHEN (txs.sponsored = false AND txs.sender_address = ${args.address})
OR (txs.sponsored = true AND txs.sponsor_address = ${args.address})
THEN txs.fee_rate ELSE 0
END AS stx_sent,
(
SELECT COALESCE(SUM(amount), 0)
FROM stx_events
WHERE ${eventCond} AND recipient = ${args.address}
) AS stx_received,
(
SELECT COUNT(*)::int FROM stx_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Transfer}
) AS stx_transfer,
(
SELECT COUNT(*)::int FROM stx_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Mint}
) AS stx_mint,
(
SELECT COUNT(*)::int FROM stx_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Burn}
) AS stx_burn,
(
SELECT COUNT(*)::int FROM ft_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Transfer}
) AS ft_transfer,
(
SELECT COUNT(*)::int FROM ft_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Mint}
) AS ft_mint,
(
SELECT COUNT(*)::int FROM ft_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Burn}
) AS ft_burn,
(
SELECT COUNT(*)::int FROM nft_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Transfer}
) AS nft_transfer,
(
SELECT COUNT(*)::int FROM nft_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Mint}
) AS nft_mint,
(
SELECT COUNT(*)::int FROM nft_events
WHERE ${eventAcctCond} AND asset_event_type_id = ${DbAssetEventTypeId.Burn}
) AS nft_burn,
(
SELECT COUNT(*)::int FROM deduped_txs
) AS count
FROM limited_txs
INNER JOIN txs USING (tx_id, index_block_hash, microblock_hash)
ORDER BY block_height DESC, microblock_sequence DESC, tx_index DESC
`;

const total = resultQuery.length > 0 ? resultQuery[0].count : 0;
const parsed = resultQuery.map(r => parseAccountTransferSummaryTxQueryResult(r));

return {
total,
limit,
offset,
results: parsed,
};
});
}

async getAddressTransactionEvents(args: {
limit: number;
offset: number;
Expand Down