In 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:
1
2
3
|
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
;
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
;
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
and
hire_date
>
'1990-01-01'
;
|
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 :
1
2
3
|
mysql
>
alter
table
employees
add
index
comp
(first_name,
last_name,
hire_date);
Query
OK,
0
rows
affected
(9.32
sec)
Records:
0
Duplicates:
0
Warnings
:
0
|
Now lets check if this index is used to resolve our queries:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
|
mysql
>
explain
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
;
+----+-------------+-----------+------------+------+---------------+------+---------+-------+------+----------+-------------+
|
id
|
select_type
|
table
|
partitions
|
type
|
possible_keys
|
key
|
key_len
|
ref
|
rows
|
filtered
|
Extra
|
+----+-------------+-----------+------------+------+---------------+------+---------+-------+------+----------+-------------+
|
1
|
SIMPLE
|
employees
|
NULL
|
ref
|
comp
|
comp
|
16
|
const
|
245
|
100.00
|
Using
index
|
+----+-------------+-----------+------------+------+---------------+------+---------+-------+------+----------+-------------+
1
row
in
set
,
1
warning
(0.00
sec)
mysql
>
explain
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
;
+----+-------------+-----------+------------+-------+---------------+------+---------+------+------+----------+--------------------------+
|
id
|
select_type
|
table
|
partitions
|
type
|
possible_keys
|
key
|
key_len
|
ref
|
rows
|
filtered
|
Extra
|
+----+-------------+-----------+------------+-------+---------------+------+---------+------+------+----------+--------------------------+
|
1
|
SIMPLE
|
employees
|
NULL
|
range
|
comp
|
comp
|
34
|
NULL
|
8
|
100.00
|
Using
where
;
Using
index
|
+----+-------------+-----------+------------+-------+---------------+------+---------+------+------+----------+--------------------------+
1
row
in
set
,
1
warning
(0.00
sec)
mysql
>
explain
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
and
hire_date
>
'1990-01-01'
;
+----+-------------+-----------+------------+-------+---------------+------+---------+------+------+----------+--------------------------+
|
id
|
select_type
|
table
|
partitions
|
type
|
possible_keys
|
key
|
key_len
|
ref
|
rows
|
filtered
|
Extra
|
+----+-------------+-----------+------------+-------+---------------+------+---------+------+------+----------+--------------------------+
|
1
|
SIMPLE
|
employees
|
NULL
|
range
|
comp
|
comp
|
37
|
NULL
|
8
|
33.33
|
Using
where
;
Using
index
|
+----+-------------+-----------+------------+-------+---------------+------+---------+------+------+----------+--------------------------+
1
row
in
set
,
1
warning
(0.00
sec)
|
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:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
|
mysql
>
explain
format
=
json
SELECT
first
_
name
,
last
_
name
FROM
employees
WHERE
first
_
name
=
'Steve'
G
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
1
.
row
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
*
EXPLAIN
:
{
"query_block"
:
{
"select_id"
:
1
,
"cost_info"
:
{
"query_cost"
:
"51.22"
}
,
"table"
:
{
"table_name"
:
"employees"
,
"access_type"
:
"ref"
,
"possible_keys"
:
[
"comp"
]
,
"key"
:
"comp"
,
"used_key_parts"
:
[
"first_name"
]
,
"key_length"
:
"16"
,
"ref"
:
[
"const"
]
,
"rows_examined_per_scan"
:
245
,
"rows_produced_per_join"
:
245
,
"filtered"
:
"100.00"
,
"using_index"
:
true
,
"cost_info"
:
{
"read_cost"
:
"2.22"
,
"eval_cost"
:
"49.00"
,
"prefix_cost"
:
"51.22"
,
"data_read_per_join"
:
"11K"
}
,
"used_columns"
:
[
"first_name"
,
"last_name"
]
}
}
}
1
row
in
set
,
1
warning
(
0
.
00
sec
)
|
Only the first_name field of the index was used for the query with the WHERE first_name= 'Steve' condition.
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
|
mysql
>
explain
format
=
json
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
G
***************************
1.
row
***************************
EXPLAIN
:
{
"query_block"
:
{
"select_id"
:
1,
"cost_info"
:
{
"query_cost"
:
"4.24"
},
"table"
:
{
"table_name"
:
"employees"
,
"access_type"
:
"range"
,
"possible_keys"
:
[
"comp"
],
"key"
:
"comp"
,
"used_key_parts"
:
[
"first_name"
,
"last_name"
],
"key_length"
:
"34"
,
"rows_examined_per_scan"
:
8,
"rows_produced_per_join"
:
8,
"filtered"
:
"100.00"
,
"using_index"
:
true
,
"cost_info"
:
{
"read_cost"
:
"2.65"
,
"eval_cost"
:
"1.60"
,
"prefix_cost"
:
"4.25"
,
"data_read_per_join"
:
"384"
},
"used_columns"
:
[
"first_name"
,
"last_name"
],
"attached_condition"
:
"((`employees`.`employees`.`first_name` = 'Steve') and (`employees`.`employees`.`last_name` like 'V%'))"
}
}
}
1
row
in
set
,
1
warning
(0.00
sec)
|
And two fields, first_name and last_name , were used for the second query.
1
2
3
4
5
|
"key"
:
"comp"
,
"used_key_parts"
:
[
"first_name"
,
"last_name"
],
|
But surprisingly the same result happens for the last query, although it queries column hire_date too:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
|
mysql
>
explain
format
=
json
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
and
hire_date
>
'1990-01-01'
G
***************************
1.
row
***************************
EXPLAIN
:
{
"query_block"
:
{
"select_id"
:
1,
"cost_info"
:
{
"query_cost"
:
"4.24"
},
"table"
:
{
"table_name"
:
"employees"
,
"access_type"
:
"range"
,
"possible_keys"
:
[
"comp"
],
"key"
:
"comp"
,
"used_key_parts"
:
[
"first_name"
,
"last_name"
],
"key_length"
:
"37"
,
"rows_examined_per_scan"
:
8,
"rows_produced_per_join"
:
2,
"filtered"
:
"33.33"
,
"using_index"
:
true
,
"cost_info"
:
{
"read_cost"
:
"3.71"
,
"eval_cost"
:
"0.53"
,
"prefix_cost"
:
"4.25"
,
"data_read_per_join"
:
"127"
},
"used_columns"
:
[
"first_name"
,
"last_name"
,
"hire_date"
],
"attached_condition"
:
"((`employees`.`employees`.`first_name` = 'Steve') and (`employees`.`employees`.`last_name` like 'V%') and (`employees`.`employees`.`hire_date` > '1990-01-01'))"
}
}
}
1
row
in
set
,
1
warning
(0.00
sec)
|
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:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
|
mysql
>
flush
status
;
Query
OK,
0
rows
affected
(0.06
sec)
mysql
>
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
and
hire_date
>
'1990-01-01'
;
+------------+-----------+
|
first_name
|
last_name
|
+------------+-----------+
|
Steve
|
Vecchi
|
|
Steve
|
Veldwijk
|
|
Steve
|
Vickson
|
+------------+-----------+
3
rows
in
set
(0.00
sec)
mysql
>
show
status
like
'Handler%'
;
+----------------------------+-------+
|
Variable_name
|
Value
|
+----------------------------+-------+
|
Handler_commit
|
1
|
|
Handler_delete
|
0
|
|
Handler_discover
|
0
|
|
Handler_external_lock
|
2
|
|
Handler_mrr_init
|
0
|
|
Handler_prepare
|
0
|
|
Handler_read_first
|
0
|
|
Handler_read_key
|
1
|
|
Handler_read_last
|
0
|
|
Handler_read_next
|
8
|
|
Handler_read_prev
|
0
|
|
Handler_read_rnd
|
0
|
|
Handler_read_rnd_next
|
0
|
|
Handler_rollback
|
0
|
|
Handler_savepoint
|
0
|
|
Handler_savepoint_rollback
|
0
|
|
Handler_update
|
0
|
|
Handler_write
|
0
|
+----------------------------+-------+
18
rows
in
set
(0.00
sec)
mysql
>
alter
table
employees
drop
index
comp;
Query
OK,
0
rows
affected
(0.27
sec)
Records:
0
Duplicates:
0
Warnings
:
0
mysql
>
alter
table
employees
add
index
comp
(first_name,
last_name);
Query
OK,
0
rows
affected
(7.57
sec)
Records:
0
Duplicates:
0
Warnings
:
0
mysql
>
flush
status
;
Query
OK,
0
rows
affected
(0.03
sec)
mysql
>
SELECT
first_name,
last_name
FROM
employees
WHERE
first_name=
'Steve'
and
last_name
like
'V%'
and
hire_date
>
'1990-01-01'
;
+------------+-----------+
|
first_name
|
last_name
|
+------------+-----------+
|
Steve
|
Vecchi
|
|
Steve
|
Veldwijk
|
|
Steve
|
Vickson
|
+------------+-----------+
3
rows
in
set
(0.00
sec)
mysql
>
show
status
like
'Handler%'
;
+----------------------------+-------+
|
Variable_name
|
Value
|
+----------------------------+-------+
|
Handler_commit
|
1
|
|
Handler_delete
|
0
|
|
Handler_discover
|
0
|
|
Handler_external_lock
|
2
|
|
Handler_mrr_init
|
0
|
|
Handler_prepare
|
0
|
|
Handler_read_first
|
0
|
|
Handler_read_key
|
1
|
|
Handler_read_last
|
0
|
|
Handler_read_next
|
8
|
|
Handler_read_prev
|
0
|
|
Handler_read_rnd
|
0
|
|
Handler_read_rnd_next
|
0
|
|
Handler_rollback
|
0
|
|
Handler_savepoint
|
0
|
|
Handler_savepoint_rollback
|
0
|
|
Handler_update
|
0
|
|
Handler_write
|
0
|
+----------------------------+-------+
18
rows
in
set
(0.00
sec)
|
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: