Skip to content

Commit

Permalink
indexer: optimize idx.BlockList performance
Browse files Browse the repository at this point in the history
turns out, a unified query with `COUNT(*) OVER() AS total_count` is 10x slower
than two separate queries `SELECT *` and `SELECT COUNT(*)`

also, optimize even further (~1000x) for the most common query:
when listing all blocks without filters, don't even count, just return last height
  • Loading branch information
altergui committed Sep 9, 2024
1 parent 420aee2 commit 631f45d
Show file tree
Hide file tree
Showing 5 changed files with 103 additions and 17 deletions.
28 changes: 18 additions & 10 deletions vochain/indexer/block.go
Original file line number Diff line number Diff line change
Expand Up @@ -71,22 +71,30 @@ func (idx *Indexer) BlockList(limit, offset int, chainID, hash, proposerAddress
for _, row := range results {
list = append(list, indexertypes.BlockFromDBRow(&row))
}
if len(results) == 0 {
return list, 0, nil
count, err := idx.CountBlocks(chainID, hash, proposerAddress)
if err != nil {
return nil, 0, err
}
return list, uint64(results[0].TotalCount), nil
return list, count, nil
}

// CountBlocks returns how many blocks are indexed.
func (idx *Indexer) CountBlocks() (uint64, error) {
results, err := idx.readOnlyQuery.SearchBlocks(context.TODO(), indexerdb.SearchBlocksParams{
Limit: 1,
// If all args passed are empty ("") it will return the last block height, as an optimization.
func (idx *Indexer) CountBlocks(chainID, hash, proposerAddress string) (uint64, error) {
if chainID == "" && hash == "" && proposerAddress == "" {
count, err := idx.readOnlyQuery.LastBlockHeight(context.TODO())
if err != nil {
return 0, err
}
return uint64(count), nil
}
count, err := idx.readOnlyQuery.CountBlocks(context.TODO(), indexerdb.CountBlocksParams{
ChainID: chainID,
HashSubstr: hash,
ProposerAddress: proposerAddress,
})
if err != nil {
return 0, err
}
if len(results) == 0 {
return 0, nil
}
return uint64(results[0].TotalCount), nil
return uint64(count), nil
}
47 changes: 43 additions & 4 deletions vochain/indexer/db/blocks.sql.go

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

20 changes: 20 additions & 0 deletions vochain/indexer/db/db.go

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

2 changes: 1 addition & 1 deletion vochain/indexer/indexer.go
Original file line number Diff line number Diff line change
Expand Up @@ -444,7 +444,7 @@ func (idx *Indexer) ReindexBlocks(inTest bool) {
return
}

idxBlockCount, err := idx.CountBlocks()
idxBlockCount, err := idx.CountBlocks("", "", "")
if err != nil {
log.Warnf("indexer CountBlocks returned error: %s", err)
}
Expand Down
23 changes: 21 additions & 2 deletions vochain/indexer/queries/blocks.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,11 +21,15 @@ SELECT * FROM blocks
WHERE hash = ?
LIMIT 1;

-- name: LastBlockHeight :one
SELECT height FROM blocks
ORDER BY height DESC
LIMIT 1;

-- name: SearchBlocks :many
SELECT
b.*,
COUNT(t.block_index) AS tx_count,
COUNT(*) OVER() AS total_count
COUNT(t.block_index) AS tx_count
FROM blocks AS b
LEFT JOIN transactions AS t
ON b.height = t.block_height
Expand All @@ -44,3 +48,18 @@ GROUP BY b.height
ORDER BY b.height DESC
LIMIT sqlc.arg(limit)
OFFSET sqlc.arg(offset);

-- name: CountBlocks :one
SELECT COUNT(*)
FROM blocks AS b
WHERE (
(sqlc.arg(chain_id) = '' OR b.chain_id = sqlc.arg(chain_id))
AND LENGTH(sqlc.arg(hash_substr)) <= 64 -- if passed arg is longer, then just abort the query
AND (
sqlc.arg(hash_substr) = ''
OR (LENGTH(sqlc.arg(hash_substr)) = 64 AND LOWER(HEX(b.hash)) = LOWER(sqlc.arg(hash_substr)))
OR (LENGTH(sqlc.arg(hash_substr)) < 64 AND INSTR(LOWER(HEX(b.hash)), LOWER(sqlc.arg(hash_substr))) > 0)
-- TODO: consider keeping an hash_hex column for faster searches
)
AND (sqlc.arg(proposer_address) = '' OR LOWER(HEX(b.proposer_address)) = LOWER(sqlc.arg(proposer_address)))
);

0 comments on commit 631f45d

Please sign in to comment.