EmergencyEMERGENCY? Get 24/7 Help Now!

used_key_parts: EXPLAIN FORMAT=JSON provides insight into which part of multiple-column key is used

 | December 17, 2015 |  Posted In: EXPLAIN, EXPLAIN FORMAT=JSON is cool!, JSON, MySQL

PREVIOUS POST
NEXT POST

multiple-columnIn the previous post for this ongoing “EXPLAIN FORMAT=JSON is Cool!” series, we discussed covered indexes and how the  used_columns  array can help to choose them wisely. There is one more type of multiple-column indexes: composite indexes. Composite indexes are just indexes on multiple columns. Covered indexes are a subgroup of the larger set “composite indexes.” In this post we’ll discuss how “used_key_parts” can help show which part of a multiple column key is being used.

You should prioritize using composite indexes when you have queries that search on both a set of multiple columns and a single column. For example, if you run queries like:

It would be better to have a single index on the  first_name, last_name  and hire_date  columns rather than three indexes on first_name, a composite on (first_name, last_name) and a composite on (first_name, last_name, hire_date). But what is the best method of testing the effectiveness of the new index?

Once again, the answer is EXPLAIN FORMAT=JSON.

To illustrate this idea, let’s add a composite index on (first_name, last_name, hire_date) to the table “employees” from the standard employees database:

Now lets check if this index is used to resolve our queries:

It is used in all queries, and key_len is increasing – which shows that each query is  using more parts of the index. But which part of index was actually used to resolve the  WHERE  condition, and which was used to retrieve rows?

EXPLAIN FORMAT=JSON  stores this information in the used_key_parts  member.

For the first two queries, the following result is shown:

Only the  first_name  field of the index was used for the query with the  WHERE first_name='Steve' condition.

And two fields,  first_name and last_name , were used for the second query.

But surprisingly the same result happens for the last query, although it queries column hire_date  too:

This is most likely because there are too many values in the hire_date  column that satisfy the conditions, so it is easier to retrieve a data set using part of the index and then check  the condition for the hire_date column.

This means what since we don’t retrieve hire_date, we can drop it from the index. We might be a bit leary as to what table rows will be accessed to perform final comparison with hire_date  column, but in this case it’s fine:

As you see, the  Handler_*  variables are same for both indexes. The reason for this is that in this case the optimizer can use index condition pushdown optimization:

In the output above we don’t have a member:

But there is information about index condition:

However,  query_cost  is higher in this case: 12.21 against 4.24 for the composite index of the three fields.

Conclusion: The used_key_parts field of the EXPLAIN FORMAT=JSON  output can help us to identify how effective our composite indexes are.

PREVIOUS POST
NEXT POST
Sveta Smirnova

Sveta joined Percona in 2015. Her main professional interests are problem solving, working with tricky issues, bugs, finding patterns that can solve typical issues quicker and teaching others how to deal with MySQL issues, bugs and gotchas effectively. Before joining Percona Sveta worked as a Support Engineer in the MySQL Bugs Analysis Support Group in MySQL AB-Sun-Oracle. She is the author of the book "MySQL Troubleshooting" and JSON UDF functions for MySQL.

One Comment

  • EXPLAIN FORMAT=json SELECT artist.ID, CONCAT_WS(”, artist.post_title, CONCAT(‘(‘,post.post_title,’)’)) AS TEXT, postmeta.meta_value FROM M8t7_posts artist
    LEFT JOIN M8t7_relationships rea ON rea.meta_value = artist.ID AND posttype = ‘movie’
    LEFT JOIN M8t7_posts post ON post.ID = rea.post_id AND post.post_type=’movie’
    LEFT JOIN M8t7_postmeta postmeta ON post.ID = postmeta.post_id AND post.post_type=’movie’ AND postmeta.meta_key = ‘wpcf-date-of-release’
    WHERE artist.post_title LIKE ‘salman%’ AND artist.post_type=’artiste’ AND artist.post_status=’publish’
    ORDER BY CAST(postmeta.meta_value AS SIGNED) DESC

    I have used above query and columns in where conditions(post_title, post_type and post_status) have the indexed. However, they are not shown in the key and thats reason query cost becomes very huge. can you please help me why it is not taking index.

    {
    “query_block”: {
    “select_id”: 1,
    “cost_info”: {
    “query_cost”: “70836460.54”
    },
    “grouping_operation”: {
    “using_filesort”: false,
    “nested_loop”: [
    {
    “table”: {
    “table_name”: “artist”,
    “access_type”: “index”,
    “possible_keys”: [
    “PRIMARY”,
    “post_type”,
    “old_id”,
    “post_title”,
    “post_name”,
    “post_parent”,
    “post_author”,
    “type_status_date”,
    “post_type_mime_type”
    ],
    “key”: “PRIMARY”,
    “used_key_parts”: [
    “ID”
    ],
    “key_length”: “8”,
    “rows_examined_per_scan”: 491846,
    “rows_produced_per_join”: 46,
    “filtered”: “0.01”,
    “cost_info”: {
    “read_cost”: “2076.28”,
    “eval_cost”: “9.33”,
    “prefix_cost”: “2085.61”,
    “data_read_per_join”: “126K”
    },
    “used_columns”: [
    “ID”,
    “post_title”,
    “post_status”,
    “post_type”
    ],
    “attached_condition”: “((movie_mysql.artist.post_title like ‘salman%’) and (movie_mysql.artist.post_type = ‘artiste’) and (movie_mysql.artist.post_status = ‘publish’))”
    }
    },
    {
    “table”: {
    “table_name”: “rea”,
    “access_type”: “ref”,
    “possible_keys”: [
    “post_type”
    ],
    “key”: “post_type”,
    “used_key_parts”: [
    “posttype”
    ],
    “key_length”: “502”,
    “ref”: [
    “const”
    ],
    “rows_examined_per_scan”: 184269,
    “rows_produced_per_join”: 8591678,
    “filtered”: “100.00”,
    “using_index”: true,
    “cost_info”: {
    “read_cost”: “1718373.09”,
    “eval_cost”: “1718335.79”,
    “prefix_cost”: “3438794.48”,
    “data_read_per_join”: “12G”
    },
    “used_columns”: [
    “post_id”,
    “meta_key”,
    “meta_value”,
    “posttype”
    ],
    “attached_condition”: “(is_not_null_compl(rea), (movie_mysql.rea.meta_value = movie_mysql.artist.ID), true)”
    }
    },
    {
    “table”: {
    “table_name”: “post”,
    “access_type”: “eq_ref”,
    “possible_keys”: [
    “PRIMARY”,
    “post_type”,
    “type_status_date”,
    “post_type_mime_type”
    ],
    “key”: “PRIMARY”,
    “used_key_parts”: [
    “ID”
    ],
    “key_length”: “8”,
    “ref”: [
    “movie_mysql.rea.post_id”
    ],
    “rows_examined_per_scan”: 1,
    “rows_produced_per_join”: 8591678,
    “filtered”: “100.00”,
    “cost_info”: {
    “read_cost”: “184269.00”,
    “eval_cost”: “1718335.79”,
    “prefix_cost”: “5341399.27”,
    “data_read_per_join”: “22G”
    },
    “used_columns”: [
    “ID”,
    “post_title”,
    “post_type”
    ],
    “attached_condition”: “(is_not_null_compl(post), ((movie_mysql.post.ID = movie_mysql.rea.post_id) and (movie_mysql.post.post_type = ‘movie’)), true)”
    }
    },
    {
    “table”: {
    “table_name”: “postmeta”,
    “access_type”: “ref”,
    “possible_keys”: [
    “post_id”,
    “meta_key”
    ],
    “key”: “post_id”,
    “used_key_parts”: [
    “post_id”
    ],
    “key_length”: “8”,
    “ref”: [
    “movie_mysql.post.ID”
    ],
    “rows_examined_per_scan”: 6,
    “rows_produced_per_join”: 54579217,
    “filtered”: “100.00”,
    “cost_info”: {
    “read_cost”: “54579217.72”,
    “eval_cost”: “10915843.54”,
    “prefix_cost”: “70836460.54”,
    “data_read_per_join”: “53G”
    },
    “used_columns”: [
    “meta_id”,
    “post_id”,
    “meta_key”,
    “meta_value”
    ],
    “attached_condition”: “(is_not_null_compl(postmeta), ((movie_mysql.post.post_type = ‘movie’) and (movie_mysql.postmeta.meta_key = ‘wpcf-date-of-release’)), true)”
    }
    }
    ]
    }
    }
    }

Leave a Reply