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

[db] add index to improve /status queries #481

Merged
merged 1 commit into from
Jul 10, 2023
Merged

Conversation

Andrew7234
Copy link
Collaborator

Noticed that the queries to /v1/ and /v1/{runtime}/status were slow during the load tests.

Within the staging db:

oasisindexer=> explain analyze SELECT height, processed_time
                        FROM analysis.processed_blocks
                        WHERE analyzer='consensus' AND processed_time IS NOT NULL
                ORDER BY processed_time DESC
                LIMIT 1;
                                                                       QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=122859.34..122859.46 rows=1 width=16) (actual time=1532.263..1533.708 rows=1 loops=1)
   ->  Gather Merge  (cost=122859.34..389035.66 rows=2281352 width=16) (actual time=1532.261..1533.704 rows=1 loops=1)
         Workers Planned: 2
         Workers Launched: 2
         ->  Sort  (cost=121859.32..124711.01 rows=1140676 width=16) (actual time=1510.410..1510.411 rows=1 loops=3)
               Sort Key: processed_time 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
               ->  Parallel Seq Scan on processed_blocks  (cost=0.00..116155.94 rows=1140676 width=16) (actual time=0.031..1178.207 rows=910748 loops=3)
                     Filter: ((processed_time IS NOT NULL) AND (analyzer = 'consensus'::text))
                     Rows Removed by Filter: 1758780
 Planning Time: 0.147 ms
 Execution Time: 1533.740 ms
(14 rows)

Adding the index fixed the performance:

oasisindexer=> explain analyze SELECT height, processed_time
                        FROM analysis.processed_blocks
                        WHERE analyzer='consensus' AND processed_time IS NOT NULL
                ORDER BY processed_time DESC
                LIMIT 1;
                                                                                     QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=0.56..0.70 rows=1 width=16) (actual time=0.036..0.036 rows=1 loops=1)
   ->  Index Scan Backward using ix_processed_blocks_analyzer_processed on processed_blocks  (cost=0.56..384588.48 rows=2746007 width=16) (actual time=0.035..0.035 rows=1 loops=1)
         Index Cond: (analyzer = 'consensus'::text)
 Planning Time: 0.149 ms
 Execution Time: 0.050 ms
(5 rows)

@ptrus
Copy link
Member

ptrus commented Jul 7, 2023

Nice find 👍

I think that an alternative fix would be to change the ORDER BY processed_time DESC to ORDER BY height DESC. That way, I think that the existing ix_processed_blocks_analyzer_height_locked_processed index would be used. Can you try out that query quickly on the staging db?

In the vast majority of cases, in case of normal operations, the query should return the same results as the current query. The only case where the query would return different results is during the "fast-sync" where block processing in order is not guaranteed. But maybe returning the highest processed block in that case does make sense as well.

The analysis.processed_blocks is quite big, so maybe it would be nice not adding more indexed to it, where we can avoid it. I have no strong feelings either way though and am fine with the current fix as well.

@pro-wh
Copy link
Collaborator

pro-wh commented Jul 7, 2023

I'd be in favor of the ORDER BY height DESC idea. that's the one we want anyway right?

@Andrew7234
Copy link
Collaborator Author

Good point; ORDER BY height DESC works well:

oasisindexer=> explain analyze SELECT height, processed_time
                        FROM analysis.processed_blocks
                        WHERE analyzer='consensus' AND processed_time IS NOT NULL
                ORDER BY height DESC
                LIMIT 1;
                                                                                              QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=0.56..0.62 rows=1 width=16) (actual time=0.097..0.098 rows=1 loops=1)
   ->  Index Only Scan Backward using ix_processed_blocks_analyzer_height_locked_processed on processed_blocks  (cost=0.56..171318.29 rows=3041032 width=16) (actual time=0.096..0.096 rows=1 loops=1)
         Index Cond: (analyzer = 'consensus'::text)
         Heap Fetches: 1
 Planning Time: 0.194 ms
 Execution Time: 0.126 ms
(6 rows)

Will update the PR

[db] add index to improve /status queries
@Andrew7234 Andrew7234 merged commit 102b995 into main Jul 10, 2023
6 checks passed
@Andrew7234 Andrew7234 deleted the andrew7234/optimization branch July 10, 2023 15:17
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

3 participants