perf(db): Extend index on cards_properties to cover name and value#51438
Merged
perf(db): Extend index on cards_properties to cover name and value#51438
Conversation
Signed-off-by: Christoph Wurst <christoph@winzerhof-wurst.at>
Member
Author
|
/backport to stable31 |
Member
Author
|
/backport to stable30 |
Member
Author
|
/backport to stable29 |
6 tasks
SebastianKrupinski
approved these changes
Mar 12, 2025
SebastianKrupinski
approved these changes
Apr 24, 2025
Member
Author
|
@ArtificialOwl @skjnldsv @sorbaugh 🏓 for review |
kesselb
approved these changes
Apr 24, 2025
This was referenced Apr 24, 2025
Merged
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
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.
Summary
Search in in addressbooks dispatches a query like
MariaDB picks
card_name_index, which only coversname, and still has to scan 712 index entries and then do a table access.{ "query_optimization": { "r_total_time_ms": 0.144922892 }, "query_block": { "select_id": 1, "cost": 0.6448338, "r_loops": 1, "r_total_time_ms": 1.652976417, "temporary_table": { "nested_loop": [ { "table": { "table_name": "cp", "access_type": "range", "possible_keys": ["card_name_index"], "key": "card_name_index", "key_length": "259", "used_key_parts": ["name"], "loops": 1, "r_loops": 1, "rows": 712, "r_index_rows": 712, "r_rows": 712, "cost": 0.6448338, "r_table_time_ms": 1.404896605, "r_other_time_ms": 0.240330463, "r_engine_stats": { "pages_accessed": 1426 }, "filtered": 100, "r_total_filtered": 0.140449438, "index_condition": "cp.`name` = 'FN'", "r_icp_filtered": 100, "attached_condition": "cp.addressbookid = 18 and cp.`value` collate utf8mb4_general_ci like '%user0%'", "r_filtered": 0.140449438 } } ] } } }Look at the r_rows
With the new query everything but the
cardidis covered. It takes 1 index access and one table access to find the result.{ "query_optimization": { "r_total_time_ms": 0.258566593 }, "query_block": { "select_id": 1, "cost": 0.6448338, "r_loops": 1, "r_total_time_ms": 0.712225566, "temporary_table": { "nested_loop": [ { "table": { "table_name": "cp", "access_type": "range", "possible_keys": ["card_name_index", "cards_prop_abid_name_value"], "key": "cards_prop_abid_name_value", "key_length": "267", "used_key_parts": ["addressbookid", "name"], "loops": 1, "r_loops": 1, "rows": 638, "r_index_rows": 638, "r_rows": 1, "cost": 0.6448338, "r_table_time_ms": 0.672583116, "r_other_time_ms": 0.029195924, "r_engine_stats": { "pages_accessed": 6 }, "filtered": 100, "r_total_filtered": 0.156739812, "index_condition": "cp.addressbookid = 18 and cp.`name` = 'FN' and cp.`value` collate utf8mb4_general_ci like '%user0%'", "r_icp_filtered": 0.156739812, "r_filtered": 100 } } ] } } }I have also experimented with
cardidbut then MariaDB no longer uses the index. This is likely because a custom collation is used onvalue, so query optimizer sees the index as not worthy.TODO
How to test
Checklist