Use blocks table, not header_cids, for getBlockNumber() #232

Merged
telackey merged 1 commits from telackey/blocks into v4 2023-03-10 02:03:41 +00:00
Member

On our machines, the single most expensive query is:

SELECT block_number FROM eth.header_cids ORDER BY block_number DESC LIMIT 1

This query touches gazillions of rows, almost certainly as a consequence of only having a BRIN index on header_cids.block_number.

Even using gibbon (which has a comparatively small DB vs rhino or vulture) the comparison is significant:

OLD:

"Limit  (cost=28471.11..28471.24 rows=1 width=8) (actual time=182.739..249.251 rows=1 loops=1)"
"  ->  Gather Merge  (cost=28471.11..102315.06 rows=610660 width=8) (actual time=182.738..249.249 rows=1 loops=1)"
"        Workers Planned: 5"
"        Workers Launched: 5"
"        ->  Sort  (cost=27471.04..27776.37 rows=122132 width=8) (actual time=164.437..164.437 rows=1 loops=6)"
"              Sort Key: block_number DESC"
"              Sort Method: top-N heapsort  Memory: 25kB"
"              Worker 0:  Sort Method: top-N heapsort  Memory: 25kB"
"              Worker 1:  Sort Method: top-N heapsort  Memory: 25kB"
"              Worker 2:  Sort Method: top-N heapsort  Memory: 25kB"
"              Worker 3:  Sort Method: top-N heapsort  Memory: 25kB"
"              Worker 4:  Sort Method: top-N heapsort  Memory: 25kB"
"              ->  Parallel Index Only Scan using header_cid_index on header_cids  (cost=0.55..26860.38 rows=122132 width=8) (actual time=0.069..155.067 rows=101663 loops=6)"
"                    Heap Fetches: 87419"
"Planning Time: 4.875 ms"
"Execution Time: 249.310 ms"

NEW:

"Limit  (cost=0.58..0.60 rows=1 width=8) (actual time=0.028..0.029 rows=1 loops=1)"
"  ->  Index Only Scan using blocks_block_number_idx on blocks  (cost=0.58..67751347.29 rows=2837035909 width=8) (actual time=0.028..0.028 rows=1 loops=1)"
"        Heap Fetches: 1"
"Planning Time: 0.091 ms"
"Execution Time: 0.047 ms"
On our machines, the single most expensive query is: ``` SELECT block_number FROM eth.header_cids ORDER BY block_number DESC LIMIT 1 ``` This query touches gazillions of rows, almost certainly as a consequence of only having a BRIN index on header_cids.block_number. Even using gibbon (which has a comparatively small DB vs rhino or vulture) the comparison is significant: OLD: ``` "Limit (cost=28471.11..28471.24 rows=1 width=8) (actual time=182.739..249.251 rows=1 loops=1)" " -> Gather Merge (cost=28471.11..102315.06 rows=610660 width=8) (actual time=182.738..249.249 rows=1 loops=1)" " Workers Planned: 5" " Workers Launched: 5" " -> Sort (cost=27471.04..27776.37 rows=122132 width=8) (actual time=164.437..164.437 rows=1 loops=6)" " Sort Key: block_number DESC" " Sort Method: top-N heapsort Memory: 25kB" " Worker 0: Sort Method: top-N heapsort Memory: 25kB" " Worker 1: Sort Method: top-N heapsort Memory: 25kB" " Worker 2: Sort Method: top-N heapsort Memory: 25kB" " Worker 3: Sort Method: top-N heapsort Memory: 25kB" " Worker 4: Sort Method: top-N heapsort Memory: 25kB" " -> Parallel Index Only Scan using header_cid_index on header_cids (cost=0.55..26860.38 rows=122132 width=8) (actual time=0.069..155.067 rows=101663 loops=6)" " Heap Fetches: 87419" "Planning Time: 4.875 ms" "Execution Time: 249.310 ms" ``` NEW: ``` "Limit (cost=0.58..0.60 rows=1 width=8) (actual time=0.028..0.029 rows=1 loops=1)" " -> Index Only Scan using blocks_block_number_idx on blocks (cost=0.58..67751347.29 rows=2837035909 width=8) (actual time=0.028..0.028 rows=1 loops=1)" " Heap Fetches: 1" "Planning Time: 0.091 ms" "Execution Time: 0.047 ms" ```
dboreham reviewed 2023-03-09 22:11:50 +00:00
i-norden approved these changes 2023-03-10 01:49:54 +00:00
i-norden left a comment
Member

LGTM! Is the poor performance due to a combination of timescaleDB partitioning by block_number + using BRIN to index block_number, or is this a more general issue when doing ORDER BY BRIN indexed columns?

Note: we're also changing the BRIN => BTREE in v5 (due to this finding, previously mentioned by David). Once that is done, should we revert to querying eth.header_cids since it is a much smaller table?

LGTM! Is the poor performance due to a combination of timescaleDB partitioning by `block_number` + using BRIN to index `block_number`, or is this a more general issue when doing `ORDER BY` BRIN indexed columns? Note: we're also changing the BRIN => BTREE in v5 (due to this finding, previously mentioned by David). Once that is done, should we revert to querying `eth.header_cids` since it is a much smaller table?
Owner

LGTM! Is the poor performance due to a combination of timescaleDB partitioning by block_number + using BRIN to index block_number, or is this a more general issue when doing ORDER BY BRIN indexed columns?

Note: we're also changing the brin => btree in v5 (due to this finding, previously mentioned by David). Once that is done, should we revert to querying eth.header_cids since it is a much smaller table?

It's both. The lack of a b-tree index seems to lobotomize Timescale's query planner such that it looks in all partitions when only the highest block number range one would do. Then it also takes longer to scan each partition.

I'm not sure the size of the table matters. When executed efficiently this query will be very fast regardless of the size because it will only do one seek on the index.

> LGTM! Is the poor performance due to a combination of timescaleDB partitioning by `block_number` + using BRIN to index `block_number`, or is this a more general issue when doing `ORDER BY` BRIN indexed columns? > > Note: we're also changing the brin => btree in v5 (due to this finding, previously mentioned by David). Once that is done, should we revert to querying `eth.header_cids` since it is a much smaller table? It's both. The lack of a b-tree index seems to lobotomize Timescale's query planner such that it looks in all partitions when only the highest block number range one would do. Then it also takes longer to scan each partition. I'm not sure the size of the table matters. When executed efficiently this query will be very fast regardless of the size because it will only do one seek on the index.
Sign in to join this conversation.
No reviewers
No Milestone
No project
No Assignees
3 Participants
Notifications
Due Date
The due date is invalid or out of range. Please use the format 'yyyy-mm-dd'.

No due date set.

Dependencies

No dependencies set.

Reference: cerc-io/ipld-eth-server#232
No description provided.