database: Add composite index on paused #8452
Open
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
Add a composite index on the paused table to speed up CheckIdentifiersPaused() and GetPausedIdentifiers(). Use (registrationID, unpausedAt, identifierType, identifierValue) so the planner can apply an index condition on registrationID and unpausedAt IS NULL and return identifierType and identifierValue from the same covering index. For a table with a few hundred thousand rows, the size of this new index is projected to be ~50 MB.
Note
I am not a DBA; the following change is based on my best understanding of how the query planner is behaving. It is intended to address queries observed in CI runs with
log_queries_not_using_indexesenabled. I cannot guarantee that this change is strictly optimal but I have provided some rationale, the relevant EXPLAINS, and directions for reproducing these results yourself. I would greatly appreciate feedback from someone with deeper database expertise.I have injected fake data on the order of 100s of 1000s of rows, with pretty poor cardinality. This means that the provided results may not be reflective of how the query planner will behave on a larger machine with a larger and more varied dataset.
docker compose exec -it bmysql mysql -urootAdd 300,000 rows to the
pausedtable for testing purposes:Run an EXPLAIN on our query before adding the index:
{ "query_block": { "select_id": 1, "nested_loop": [ { "table": { "table_name": "paused", "access_type": "ref", "possible_keys": ["PRIMARY"], "key": "PRIMARY", "key_length": "8", "used_key_parts": ["registrationID"], "ref": ["const"], "rows": 144626, "filtered": 100, "attached_condition": "paused.unpausedAt is null" } } ] } }Add the new composite index:
Running a new EXPLAIN shows the query using the new index:
{ "query_block": { "select_id": 1, "nested_loop": [ { "table": { "table_name": "paused", "access_type": "ref", "possible_keys": [ "PRIMARY", "paused_regID_unpausedAt_identifierType_identifierValue_idx" ], "key": "paused_regID_unpausedAt_identifierType_identifierValue_idx", "key_length": "14", "used_key_parts": ["registrationID", "unpausedAt"], "ref": ["const", "const"], "rows": 20688, "filtered": 100, "attached_condition": "paused.unpausedAt is null", "using_index": true } } ] } }