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

Adjust chain.runtime_events indexes #500

Merged
merged 1 commit into from
Aug 17, 2023

Conversation

Andrew7234
Copy link
Collaborator

@Andrew7234 Andrew7234 commented Aug 11, 2023

@lukaw3d found that the /events endpoint was slow when a related account was not specified in the query (rel=oasis12345). The explain analyze of the query:

oasisindexer=*> explain analyze SELECT
            evs.round,
            evs.tx_index,
            evs.tx_hash,
            evs.tx_eth_hash,
            evs.timestamp,
            evs.type,
            evs.body,
            evs.evm_log_name,
            evs.evm_log_params,
            tokens.symbol,
            CASE -- NOTE: There are three queries that use this CASE via copy-paste; edit both if changing.
                WHEN tokens.token_type = 20 THEN 'ERC20'
                WHEN tokens.token_type = 721 THEN 'ERC721'
                ELSE NULL -- Our openapi spec doesn't allow us to output this, but better this than a null value (which causes nil dereference)
            END AS token_type,
            tokens.decimals
        FROM chain.runtime_events as evs
        -- Look up the oasis-style address derived from evs.body.address.
        -- The derivation is just a keccak hash and we could theoretically compute it instead of looking it up,
        -- but the implementing/importing the right hash function in postgres would take some work.
        LEFT JOIN chain.address_preimages AS preimages ON
            DECODE(evs.body ->> 'address', 'base64')=preimages.address_data AND
            preimages.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND
            preimages.context_version = 0
        LEFT JOIN chain.evm_tokens as tokens ON
            (evs.runtime=tokens.runtime) AND
            (preimages.address=tokens.token_address)
        WHERE evs.runtime='sapphire' and evs.evm_log_signature=decode('ddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef', 'hex') order by evs.round desc, evs.tx_index, evs.type, evs.body::text limit 1000 offset 0;

Limit  (cost=1075.95..10567.32 rows=1000 width=723) (actual time=23671.368..23673.820 rows=85 loops=1)
   ->  Nested Loop Left Join  (cost=1075.95..2688767.17 rows=283172 width=723) (actual time=23671.366..23673.808 rows=85 loops=1)
         Join Filter: ((evs.runtime = tokens.runtime) AND ((preimages.address)::text = (tokens.token_address)::text))
         ->  Gather Merge  (cost=1075.68..2680973.89 rows=283172 width=699) (actual time=23671.305..23673.486 rows=85 loops=1)
               Workers Planned: 2
               Workers Launched: 2
               ->  Incremental Sort  (cost=75.65..2647288.79 rows=117988 width=699) (actual time=22244.970..23642.661 rows=28 loops=3)
                     Sort Key: evs.round DESC, evs.tx_index, evs.type, ((evs.body)::text)
                     Presorted Key: evs.round
                     Full-sort Groups: 1  Sort Method: quicksort  Average Memory: 85kB  Peak Memory: 85kB
                     Worker 0:  Full-sort Groups: 2  Sort Method: quicksort  Average Memory: 89kB  Peak Memory: 89kB
                     Worker 1:  Full-sort Groups: 1  Sort Method: quicksort  Average Memory: 67kB  Peak Memory: 67kB
                     ->  Nested Loop Left Join  (cost=0.98..2642904.24 rows=117988 width=699) (actual time=719.131..23641.814 rows=28 loops=3)
                           ->  Parallel Index Scan Backward using ix_runtime_events_round on runtime_events evs  (cost=0.56..1782310.29 rows=117988 width=652) (actual time=717.539..23635.467 rows=28 loops=3)
                                 Index Cond: (runtime = 'sapphire'::runtime)
                                 Filter: (evm_log_signature = '\xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'::bytea)
                                 Rows Removed by Filter: 372147
                           ->  Index Scan using ix_address_preimages_address_data on address_preimages preimages  (cost=0.42..7.28 rows=1 width=69) (actual time=0.206..0.207 rows=1 loops=85)
                                 Index Cond: (address_data = decode((evs.body ->> 'address'::text), 'base64'::text))
                                 Filter: ((context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'::text) AND ((context_version)::integer = 0))
         ->  Materialize  (cost=0.28..6.05 rows=1 width=66) (actual time=0.001..0.001 rows=0 loops=85)
               ->  Index Scan using evm_tokens_pkey on evm_tokens tokens  (cost=0.28..6.04 rows=1 width=66) (actual time=0.045..0.045 rows=0 loops=1)
                     Index Cond: (runtime = 'sapphire'::runtime)
 Planning Time: 4.599 ms
 Execution Time: 23674.186 ms

The issue is that postgres is scanning backwards by round and filtering by evm_log_signature, and is not using the existing index on evm_log_signature because of the order by round desc. This PR updates the index to be more useful to the query. No other queries use this index.

New timings

 Limit  (cost=1063.44..6580.68 rows=1000 width=686) (actual time=63.622..219.231 rows=348 loops=1)
   ->  Nested Loop Left Join  (cost=1063.44..1529621.18 rows=277051 width=686) (actual time=63.620..219.173 rows=348 loops=1)
         Join Filter: ((evs.runtime = tokens.runtime) AND ((preimages.address)::text = (tokens.token_address)::text))
         Rows Removed by Join Filter: 3757
         ->  Gather Merge  (cost=1058.94..1391053.60 rows=277051 width=663) (actual time=63.521..216.633 rows=348 loops=1)
               Workers Planned: 2
               Workers Launched: 2
               ->  Incremental Sort  (cost=58.92..1358075.02 rows=115438 width=663) (actual time=35.149..95.806 rows=116 loops=3)
                     Sort Key: evs.round DESC, evs.tx_index, evs.type, ((evs.body)::text)
                     Presorted Key: evs.round
                     Full-sort Groups: 3  Sort Method: quicksort  Average Memory: 91kB  Peak Memory: 91kB
                     Worker 0:  Full-sort Groups: 5  Sort Method: quicksort  Average Memory: 123kB  Peak Memory: 132kB
                       Pre-sorted Groups: 9  Sort Method: quicksort  Average Memory: 54kB  Peak Memory: 277kB
                     Worker 1:  Full-sort Groups: 1  Sort Method: quicksort  Average Memory: 27kB  Peak Memory: 27kB
                     ->  Nested Loop Left Join  (cost=1.00..1353520.19 rows=115438 width=663) (actual time=4.419..91.201 rows=116 loops=3)
                           ->  Parallel Index Scan Backward using ix_runtime_events_evm_log_signature on runtime_events evs  (cost=0.56..525875.96 rows=115438 width=616) (actual time=1.611..69.041 rows=116 loops=3)
                                 Index Cond: ((runtime = 'sapphire'::runtime) AND (evm_log_signature = '\xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'::bytea))
                           ->  Index Scan using ix_address_preimages_address_data on address_preimages preimages  (cost=0.43..7.16 rows=1 width=68) (actual time=0.182..0.182 rows=1 loops=348)
                                 Index Cond: (address_data = decode((evs.body ->> 'address'::text), 'base64'::text))
                                 Filter: ((context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'::text) AND ((context_version)::integer = 0))
         ->  Materialize  (cost=4.49..42.15 rows=28 width=65) (actual time=0.000..0.001 rows=12 loops=348)
               ->  Bitmap Heap Scan on evm_tokens tokens  (cost=4.49..42.01 rows=28 width=65) (actual time=0.041..0.073 rows=28 loops=1)
                     Recheck Cond: (runtime = 'sapphire'::runtime)
                     Heap Blocks: exact=4
                     ->  Bitmap Index Scan on evm_tokens_pkey  (cost=0.00..4.49 rows=28 width=0) (actual time=0.029..0.031 rows=28 loops=1)
                           Index Cond: (runtime = 'sapphire'::runtime)
 Planning Time: 3.607 ms
 Execution Time: 219.412 ms
(28 rows)

I also updated the tx_hash and eth_tx_hash indexes to better match the ones in chain.runtime_transactions

@@ -0,0 +1,13 @@
BEGIN;

DROP INDEX chain.ix_runtime_related_transactions_address; -- This index is a prefix of an existing index and therefore unnecessary
Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@@ -129,10 +129,10 @@ CREATE TABLE chain.runtime_events
evm_log_signature BYTEA CHECK (octet_length(evm_log_signature) = 32)
);
CREATE INDEX ix_runtime_events_round ON chain.runtime_events(runtime, round); -- for sorting by round, when there are no filters applied
CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events(tx_hash);
CREATE INDEX ix_runtime_events_tx_eth_hash ON chain.runtime_events(tx_eth_hash);
CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events/*USING hash */(tx_hash); -- updated in 13_runtime_indexes.up.sql
Copy link
Collaborator

@pro-wh pro-wh Aug 11, 2023

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

is this the first we're using /* ... */ comments? is this postgresql specific syntax?

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

tests don't complain about it 💁

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

huh TIL about /* */

Copy link
Collaborator

@pro-wh pro-wh left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

yup for filtering by evm log signature

huh, we do this on the signature field instead of topics[0]

extra-huh, the signature field actually has the hash of the signature

Copy link
Contributor

@mitjat mitjat left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Thank you for the informative PR description!

The new query plan still looked somewhat convoluted, and the timing somewhat slow. I don't understand why that Gather merge is taking so long; in my understanding it's a merge sort of 348 rows, but looks like my understanding is off :/

Anyway, it made me think of this uglier but much faster query. The outer SELECT is a copy paste of the old query. The main trick is in the comment of the subselect, which is a copy paste of the old query but limited to the events table:

explain analyze SELECT 
            evs.round,
            evs.tx_index,
            evs.tx_hash,
            evs.tx_eth_hash,
            evs.timestamp,
            evs.type,
            evs.body,
            evs.evm_log_name,
            evs.evm_log_params,
            tokens.symbol,
            CASE -- NOTE: There are three queries that use this CASE via copy-paste; edit both if changing.
                WHEN tokens.token_type = 20 THEN 'ERC20'
                WHEN tokens.token_type = 721 THEN 'ERC721'
                ELSE NULL -- Our openapi spec doesn't allow us to output this, but better this than a null value (which causes nil dereference)
            END AS token_type,
            tokens.decimals
FROM
       -- This subselect selects all appropriate events AND APPLIES SORTING AND LIMITING. Sorting and limiting now, rather than after the joins,
       -- is much more efficient. It is valid because the subsequent joins will keep the number of rows unchanged, but Postgres cannot know this,
       -- so we force the execution plan with this subselect.
       (SELECT
            evs.round,
            evs.tx_index,
            evs.tx_hash,
            evs.tx_eth_hash,
            evs.timestamp,
            evs.type,
            evs.body,
            evs.evm_log_name,
            evs.evm_log_params
        FROM chain.runtime_events as evs
        WHERE evs.runtime='sapphire' and evs.evm_log_signature=decode('ddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef', 'hex') order by evs.round desc, evs.tx_index, evs.type, evs.body::text limit 1000 offset 0
        ) evs
        -- Look up the oasis-style address derived from evs.body.address.
        -- The derivation is just a keccak hash and we could theoretically compute it instead of looking it up,
        -- but the implementing/importing the right hash function in postgres would take some work.
        LEFT JOIN chain.address_preimages AS preimages ON
            DECODE(evs.body ->> 'address', 'base64')=preimages.address_data AND
            preimages.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND
            preimages.context_version = 0
        LEFT JOIN chain.evm_tokens as tokens ON
            ('sapphire'=tokens.runtime) AND  --------- !!!!!!!!!!!!!!! CHANGE from orig query: hardcoded runtime because we don't have access to evs.runtime. We could, but there's no point in passing it through from the subquery.
            (preimages.address=tokens.token_address);

Here's the query plan:

 Hash Left Join  (cost=1928.05..1964.40 rows=1000 width=556) (actual time=40.071..42.296 rows=1000 loops=1)
   Hash Cond: ((preimages.address)::text = (tokens.token_address)::text)
   ->  Hash Left Join  (cost=1917.67..1946.40 rows=1000 width=565) (actual time=39.902..41.567 rows=1000 loops=1)
         Hash Cond: (decode((evs.body ->> 'address'::text), 'base64'::text) = preimages.address_data)
         ->  Limit  (cost=1474.21..1476.71 rows=1000 width=550) (actual time=34.454..34.748 rows=1000 loops=1)
               ->  Sort  (cost=1474.21..1492.18 rows=7190 width=550) (actual time=34.452..34.640 rows=1000 loops=1)
                     Sort Key: evs.round DESC, evs.tx_index, evs.type, ((evs.body)::text)
                     Sort Method: top-N heapsort  Memory: 1778kB
                     ->  Index Scan using ix_runtime_events_evm_log_signature on runtime_events evs  (cost=0.43..1079.99 rows=7190 width=550) (actual time=0.027..25.520 rows=6626 loops=1)
                           Index Cond: (evm_log_signature = '\xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'::bytea)
                           Filter: (runtime = 'sapphire'::runtime)
         ->  Hash  (cost=325.22..325.22 rows=9460 width=68) (actual time=5.313..5.314 rows=9385 loops=1)
               Buckets: 16384  Batches: 1  Memory Usage: 1045kB
               ->  Seq Scan on address_preimages preimages  (cost=0.00..325.22 rows=9460 width=68) (actual time=0.021..3.422 rows=9385 loops=1)
                     Filter: ((context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'::text) AND ((context_version)::integer = 0))
                     Rows Removed by Filter: 20
   ->  Hash  (cost=7.19..7.19 rows=255 width=57) (actual time=0.147..0.147 rows=260 loops=1)
         Buckets: 1024  Batches: 1  Memory Usage: 32kB
         ->  Seq Scan on evm_tokens tokens  (cost=0.00..7.19 rows=255 width=57) (actual time=0.012..0.086 rows=260 loops=1)
               Filter: ('sapphire'::runtime = runtime)
 Planning Time: 0.592 ms
 Execution Time: 42.448 ms
(22 rows)

This was on staging testnet, which doesn't have your new ix_runtime_events_evm_log_signature yet; presumably, the new index should make it only faster still?

Uh oh ... alarmingly, on prod mainnet, both my query and the original query take forever; I interrupted the EXPLAIN after a minute. This shouldn't happen regardless of whether the new index is here, I thought?

I was going to suggest that if you'd rather keep this PR's scope limited, let's go ahead and merge in these new indexes: they LGTM, thank you for them, and as discussed above, they should be helpful regardless of which of the two query variants we use.
But in the view of those super long queries in prod mainnet, I think this deserves another more holistic look before pushing a partial solution, because we seem to not understand what's going on so the partial solution might actually be harmful.
Still your call on whether the revised query belongs in this PR or a separate one, and if the latter, whether you'd prefer me to push it out or if you're happy to do it yourself.

Edit edit: In prod mainnet, the same query went from 3 minutes to 1 second after rerunning a few times 😖 . And both my and original query need 1 second because they don't use the evm_signature filter. I don't know why. I'll stop here.

@@ -129,10 +129,10 @@ CREATE TABLE chain.runtime_events
evm_log_signature BYTEA CHECK (octet_length(evm_log_signature) = 32)
);
CREATE INDEX ix_runtime_events_round ON chain.runtime_events(runtime, round); -- for sorting by round, when there are no filters applied
CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events(tx_hash);
CREATE INDEX ix_runtime_events_tx_eth_hash ON chain.runtime_events(tx_eth_hash);
CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events/*USING hash */(tx_hash); -- updated in 13_runtime_indexes.up.sql
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

huh TIL about /* */

storage/migrations/02_runtimes.up.sql Show resolved Hide resolved
storage/migrations/13_runtime_indexes.up.sql Show resolved Hide resolved
@pro-wh
Copy link
Collaborator

pro-wh commented Aug 15, 2023

oh it's because the query wants some quite sophisticated ordering. the index is only sorted down to round, so it doesn't know about how the tx_index and event type are ordered within that. so it's sorting all matching events, ever

@mitjat
Copy link
Contributor

mitjat commented Aug 15, 2023

oh it's because the query wants some quite sophisticated ordering. the index is only sorted down to round, so it doesn't know about how the tx_index and event type are ordered within that. so it's sorting all matching events, ever

But "all matching events" in this case is ... only 348 of them (rows=348), no? And it takes about 150ms (actual time=63.521..216.633) to sort them, somehow. I must be reading something wrong :)

@pro-wh
Copy link
Collaborator

pro-wh commented Aug 16, 2023

no it's this one from the events side of the join

               ->  Incremental Sort  (cost=58.92..1358075.02 rows=115438 width=663) (actual time=35.149..95.806 rows=116 loops=3)
                     Sort Key: evs.round DESC, evs.tx_index, evs.type, ((evs.body)::text)
                     Presorted Key: evs.round

@Andrew7234
Copy link
Collaborator Author

Andrew7234 commented Aug 17, 2023

Thanks for the thorough testing!

on prod mainnet, both my query and the original query take forever

Hm the index wasn't applied to either production or staging yet, so it makes sense that the original query is slow. Seems like your optimized query would also benefit from the index, so I tested it out.

Original (current) query with new (runtime, evm_log_signature, round) index:

                                                                                                      QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=1048.62..6507.85 rows=1000 width=698) (actual time=27.270..125.575 rows=349 loops=1)
   ->  Nested Loop Left Join  (cost=1048.62..1720913.73 rows=315038 width=698) (actual time=27.268..125.473 rows=349 loops=1)
         Join Filter: ((evs.runtime = tokens.runtime) AND ((preimages.address)::text = (tokens.token_address)::text))
         Rows Removed by Join Filter: 3794
         ->  Gather Merge  (cost=1044.11..1557825.06 rows=315038 width=675) (actual time=27.169..121.557 rows=349 loops=1)
               Workers Planned: 2
               Workers Launched: 2
               ->  Incremental Sort  (cost=44.09..1520461.83 rows=131266 width=675) (actual time=0.693..17.134 rows=116 loops=3)
                     Sort Key: evs.round DESC, evs.tx_index, evs.type, ((evs.body)::text)
                     Presorted Key: evs.round
                     Full-sort Groups: 2  Sort Method: quicksort  Average Memory: 89kB  Peak Memory: 89kB
                     Worker 0:  Full-sort Groups: 2  Sort Method: quicksort  Average Memory: 89kB  Peak Memory: 89kB
                     Worker 1:  Full-sort Groups: 4  Sort Method: quicksort  Average Memory: 110kB  Peak Memory: 132kB
                       Pre-sorted Groups: 27  Sort Method: quicksort  Average Memory: 36kB  Peak Memory: 277kB
                     ->  Nested Loop Left Join  (cost=1.00..1515508.20 rows=131266 width=675) (actual time=0.073..1.306 rows=116 loops=3)
                           ->  Parallel Index Scan Backward using ix_runtime_events_evm_log_signature on runtime_events evs  (cost=0.56..569171.72 rows=131266 width=628) (actual time=0.027..0.142 rows=116 loops=3)
                                 Index Cond: ((runtime = 'sapphire'::runtime) AND (evm_log_signature = '\xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'::bytea))
                           ->  Index Scan using ix_address_preimages_address_data on address_preimages preimages  (cost=0.43..7.20 rows=1 width=68) (actual time=0.004..0.004 rows=1 loops=349)
                                 Index Cond: (address_data = decode((evs.body ->> 'address'::text), 'base64'::text))
                                 Filter: ((context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'::text) AND ((context_version)::integer = 0))
         ->  Materialize  (cost=4.50..56.57 rows=29 width=65) (actual time=0.000..0.002 rows=12 loops=349)
               ->  Bitmap Heap Scan on evm_tokens tokens  (cost=4.50..56.43 rows=29 width=65) (actual time=0.041..0.062 rows=29 loops=1)
                     Recheck Cond: (runtime = 'sapphire'::runtime)
                     Heap Blocks: exact=5
                     ->  Bitmap Index Scan on evm_tokens_pkey  (cost=0.00..4.50 rows=29 width=0) (actual time=0.029..0.029 rows=29 loops=1)
                           Index Cond: (runtime = 'sapphire'::runtime)
 Planning Time: 0.609 ms
 Execution Time: 125.859 ms
(28 rows)

Optimized query with index:

                                                                                              QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Hash Left Join  (cost=71.89..10167.61 rows=1000 width=666) (actual time=0.320..21.870 rows=349 loops=1)
   Hash Cond: ((preimages.address)::text = (tokens.token_address)::text)
   ->  Nested Loop Left Join  (cost=17.50..10105.60 rows=1000 width=671) (actual time=0.261..21.508 rows=349 loops=1)
         ->  Limit  (cost=17.07..1878.60 rows=1000 width=656) (actual time=0.242..19.379 rows=349 loops=1)
               ->  Incremental Sort  (cost=17.07..586471.23 rows=315038 width=656) (actual time=0.241..19.320 rows=349 loops=1)
                     Sort Key: evs.round DESC, evs.tx_index, evs.type, ((evs.body)::text)
                     Presorted Key: evs.round
                     Full-sort Groups: 8  Sort Method: quicksort  Average Memory: 62kB  Peak Memory: 67kB
                     Pre-sorted Groups: 9  Sort Method: quicksort  Average Memory: 38kB  Peak Memory: 140kB
                     ->  Index Scan Backward using ix_runtime_events_evm_log_signature on runtime_events evs  (cost=0.56..572584.63 rows=315038 width=656) (actual time=0.030..3.430 rows=349 loops=1)
                           Index Cond: ((runtime = 'sapphire'::runtime) AND (evm_log_signature = '\xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'::bytea))
         ->  Index Scan using ix_address_preimages_address_data on address_preimages preimages  (cost=0.43..8.21 rows=1 width=68) (actual time=0.004..0.004 rows=1 loops=349)
               Index Cond: (address_data = decode((evs.body ->> 'address'::text), 'base64'::text))
               Filter: ((context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'::text) AND ((context_version)::integer = 0))
   ->  Hash  (cost=54.02..54.02 rows=29 width=61) (actual time=0.051..0.053 rows=29 loops=1)
         Buckets: 1024  Batches: 1  Memory Usage: 11kB
         ->  Index Scan using evm_tokens_pkey on evm_tokens tokens  (cost=0.28..54.02 rows=29 width=61) (actual time=0.010..0.036 rows=29 loops=1)
               Index Cond: (runtime = 'sapphire'::runtime)
 Planning Time: 0.643 ms
 Execution Time: 21.993 ms
(20 rows)

The optimized query(20-40ms) is consistently faster than the original (90-120ms), so I think overall I'm leaning towards adding it, just not in this PR. The optimized query is more complex but the performance speedup certainly seems worth it.

same query went from 3 minutes to 1 second after rerunning a few times

Probably the postgres cache. I confirmed that both queries slow significantly (> 1min) after removing the index.

remove extraneous index

add comments
@Andrew7234 Andrew7234 force-pushed the andrew7234/runtime-events-api-speedup branch from 3782435 to 9994acf Compare August 17, 2023 16:11
@Andrew7234 Andrew7234 enabled auto-merge August 17, 2023 16:12
@Andrew7234 Andrew7234 merged commit 087ac66 into main Aug 17, 2023
@Andrew7234 Andrew7234 deleted the andrew7234/runtime-events-api-speedup branch August 17, 2023 16: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.

4 participants