Post

Mysql select & join

QEP: query execution plan

Join

straight join

It is kind of option that forbid reordering tables when joining. According to official doc,

This can be used for those (few) cases for which the join optimizer processes the tables in a suboptimal order.

Semi-join

TLDR: semi-join is a optimization step that transforms a sub-select into a join.

This is a good blog about this topic https://roylyseng.blogspot.com/2012/04/semi-join-in-mysql-56.html

The different semijoin strategy constants are defined here.

Relevant code here.

Choose table order

const table: table with zero or one row. See code.

Why const table is special? Because const table can be put at the most outside order.

system table

System tables are tables with exactly one row. See definition here. It, together const table, is used for join optimization. Btw, max_rows and min_rows are specified as table options when creating a table. Also, these two options are not hard limit, and according to this post, it seems these two options are legacy options. However, they seem play a role in table partition.

Optimizer

Optimizer tracer

Optimizer tracer tracks the optimization evidence and decision, and store the result as a json object. The source code is scattered in these files: opt_trace.h, opt_trace.cc, opt_trace_context.h, and opt_trace2server.cc.

The basic usage is in the class document.

1
2
3
SET SESSION OPTIMIZER_TRACE="enabled=on";
<sql>;
SELECT * FROM information_schema.OPTIMIZER_TRACE;

The code is not hard to understand. It is essentially a json builder and a linked list such that you know the indent level of current trace in the json tree.

example
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
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
mysql> SELECT * FROM information_schema.OPTIMIZER_TRACE \G
*************************** 1. row ***************************
QUERY: select * from employees join dept_emp on dept_emp.emp_no = employees.emp_no limit 1
TRACE: {
  "steps": [
    {
      "join_preparation": {
        "select#": 1,
        "steps": [
          {
            "expanded_query": "/* select#1 */ select `employees`.`emp_no` AS `emp_no`,`employees`.`birth_date` AS `birth_date`,`employees`.`first_name` AS `first_name`,`employees`.`last_name` AS `last_name`,`employees`.`gender` AS `gender`,`employees`.`hire_date` AS `hire_date`,`dept_emp`.`emp_no` AS `emp_no`,`dept_emp`.`dept_no` AS `dept_no`,`dept_emp`.`from_date` AS `from_date`,`dept_emp`.`to_date` AS `to_date` from (`employees` join `dept_emp` on((`dept_emp`.`emp_no` = `employees`.`emp_no`))) limit 1"
          },
          {
            "transformations_to_nested_joins": {
              "transformations": [
                "JOIN_condition_to_WHERE",
                "parenthesis_removal"
              ],
              "expanded_query": "/* select#1 */ select `employees`.`emp_no` AS `emp_no`,`employees`.`birth_date` AS `birth_date`,`employees`.`first_name` AS `first_name`,`employees`.`last_name` AS `last_name`,`employees`.`gender` AS `gender`,`employees`.`hire_date` AS `hire_date`,`dept_emp`.`emp_no` AS `emp_no`,`dept_emp`.`dept_no` AS `dept_no`,`dept_emp`.`from_date` AS `from_date`,`dept_emp`.`to_date` AS `to_date` from `employees` join `dept_emp` where (`dept_emp`.`emp_no` = `employees`.`emp_no`) limit 1"
            }
          }
        ]
      }
    },
    {
      "join_optimization": {
        "select#": 1,
        "steps": [
          {
            "condition_processing": {
              "condition": "WHERE",
              "original_condition": "(`dept_emp`.`emp_no` = `employees`.`emp_no`)",
              "steps": [
                {
                  "transformation": "equality_propagation",
                  "resulting_condition": "multiple equal(`dept_emp`.`emp_no`, `employees`.`emp_no`)"
                },
                {
                  "transformation": "constant_propagation",
                  "resulting_condition": "multiple equal(`dept_emp`.`emp_no`, `employees`.`emp_no`)"
                },
                {
                  "transformation": "trivial_condition_removal",
                  "resulting_condition": "multiple equal(`dept_emp`.`emp_no`, `employees`.`emp_no`)"
                }
              ]
            }
          },
          {
            "substitute_generated_columns": {
            }
          },
          {
            "table_dependencies": [
              {
                "table": "`employees`",
                "row_may_be_null": false,
                "map_bit": 0,
                "depends_on_map_bits": [
                ]
              },
              {
                "table": "`dept_emp`",
                "row_may_be_null": false,
                "map_bit": 1,
                "depends_on_map_bits": [
                ]
              }
            ]
          },
          {
            "ref_optimizer_key_uses": [
              {
                "table": "`employees`",
                "field": "emp_no",
                "equals": "`dept_emp`.`emp_no`",
                "null_rejecting": true
              },
              {
                "table": "`dept_emp`",
                "field": "emp_no",
                "equals": "`employees`.`emp_no`",
                "null_rejecting": true
              }
            ]
          },
          {
            "rows_estimation": [
              {
                "table": "`employees`",
                "table_scan": {
                  "rows": 299423,
                  "cost": 929
                }
              },
              {
                "table": "`dept_emp`",
                "table_scan": {
                  "rows": 331143,
                  "cost": 737
                }
              }
            ]
          },
          {
            "considered_execution_plans": [
              {
                "plan_prefix": [
                ],
                "table": "`employees`",
                "best_access_path": {
                  "considered_access_paths": [
                    {
                      "access_type": "ref",
                      "index": "PRIMARY",
                      "usable": false,
                      "chosen": false
                    },
                    {
                      "rows_to_scan": 299423,
                      "filtering_effect": [
                      ],
                      "final_filtering_effect": 1,
                      "access_type": "scan",
                      "resulting_rows": 299423,
                      "cost": 30871.3,
                      "chosen": true
                    }
                  ]
                },
                "condition_filtering_pct": 100,
                "rows_for_plan": 299423,
                "cost_for_plan": 30871.3,
                "rest_of_plan": [
                  {
                    "plan_prefix": [
                      "`employees`"
                    ],
                    "table": "`dept_emp`",
                    "best_access_path": {
                      "considered_access_paths": [
                        {
                          "access_type": "ref",
                          "index": "PRIMARY",
                          "rows": 1.10555,
                          "cost": 332526,
                          "chosen": true
                        },
                        {
                          "rows_to_scan": 331143,
                          "filtering_effect": [
                          ],
                          "final_filtering_effect": 1,
                          "access_type": "scan",
                          "using_join_cache": true,
                          "buffers_needed": 152,
                          "resulting_rows": 331143,
                          "cost": 9.9153e+09,
                          "chosen": false
                        }
                      ]
                    },
                    "condition_filtering_pct": 100,
                    "rows_for_plan": 331028,
                    "cost_for_plan": 363397,
                    "chosen": true
                  }
                ]
              },
              {
                "plan_prefix": [
                ],
                "table": "`dept_emp`",
                "best_access_path": {
                  "considered_access_paths": [
                    {
                      "access_type": "ref",
                      "index": "PRIMARY",
                      "usable": false,
                      "chosen": false
                    },
                    {
                      "rows_to_scan": 331143,
                      "filtering_effect": [
                      ],
                      "final_filtering_effect": 1,
                      "access_type": "scan",
                      "resulting_rows": 331143,
                      "cost": 33851.3,
                      "chosen": true
                    }
                  ]
                },
                "condition_filtering_pct": 100,
                "rows_for_plan": 331143,
                "cost_for_plan": 33851.3,
                "rest_of_plan": [
                  {
                    "plan_prefix": [
                      "`dept_emp`"
                    ],
                    "table": "`employees`",
                    "best_access_path": {
                      "considered_access_paths": [
                        {
                          "access_type": "eq_ref",
                          "index": "PRIMARY",
                          "rows": 1,
                          "cost": 364257,
                          "chosen": true,
                          "cause": "clustered_pk_chosen_by_heuristics"
                        },
                        {
                          "rows_to_scan": 299423,
                          "filtering_effect": [
                          ],
                          "final_filtering_effect": 1,
                          "access_type": "scan",
                          "using_join_cache": true,
                          "buffers_needed": 33,
                          "resulting_rows": 299423,
                          "cost": 9.91521e+09,
                          "chosen": false
                        }
                      ]
                    },
                    "condition_filtering_pct": 100,
                    "rows_for_plan": 331143,
                    "cost_for_plan": 398109,
                    "pruned_by_cost": true
                  }
                ]
              }
            ]
          },
          {
            "attaching_conditions_to_tables": {
              "original_condition": "(`dept_emp`.`emp_no` = `employees`.`emp_no`)",
              "attached_conditions_computation": [
              ],
              "attached_conditions_summary": [
                {
                  "table": "`employees`",
                  "attached": null
                },
                {
                  "table": "`dept_emp`",
                  "attached": "(`dept_emp`.`emp_no` = `employees`.`emp_no`)"
                }
              ]
            }
          },
          {
            "finalizing_table_conditions": [
              {
                "table": "`dept_emp`",
                "original_table_condition": "(`dept_emp`.`emp_no` = `employees`.`emp_no`)",
                "final_table_condition   ": null
              }
            ]
          },
          {
            "refine_plan": [
              {
                "table": "`employees`"
              },
              {
                "table": "`dept_emp`"
              }
            ]
          }
        ]
      }
    },
    {
      "join_execution": {
        "select#": 1,
        "steps": [
        ]
      }
    }
  ]
}

How we get the row estimation

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
{
  "rows_estimation": [
    {
      "table": "`employees`",
      "table_scan": {
        "rows": 299423,
        "cost": 929
      }
    },
    {
      "table": "`dept_emp`",
      "table_scan": {
        "rows": 331143,
        "cost": 737
      }
    }
  ]
},

This tracer block is set at here. Field rows comes from stats.records. See below.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
mysql> SHOW TABLE STATUS like 'employees' \G
*************************** 1. row ***************************
           Name: employees
         Engine: InnoDB
        Version: 10
     Row_format: Dynamic
           Rows: 299379
 Avg_row_length: 50
    Data_length: 15220736
Max_data_length: 0
   Index_length: 0
      Data_free: 4194304
 Auto_increment: NULL
    Create_time: 2023-12-12 12:16:10
    Update_time: 2023-12-12 12:16:42
     Check_time: NULL
      Collation: utf8mb4_0900_ai_ci
       Checksum: NULL
 Create_options:
        Comment:
1 row in set (0.01 sec)

The cost part is more complicated. It calls function table_scan_cost. Basically, it is the product of scan_time() and page_read_cost(1.0). Function scan_time() returns the number of pages this table occupies. Note this function is a virtual function. InnoDB overwrites the default implementation. See code. It returns m_prebuilt->table->stat_clustered_index_size;, i.e.,

1
2
3
4
5
6
7
mysql> select * from mysql.innodb_table_stats where table_name = 'employees' or table_name = 'dept_emp ';
+---------------+------------+---------------------+--------+----------------------+--------------------------+
| database_name | table_name | last_update         | n_rows | clustered_index_size | sum_of_other_index_sizes |
+---------------+------------+---------------------+--------+----------------------+--------------------------+
| employees     | dept_emp   | 2023-12-12 12:18:05 | 331143 |                  737 |                      353 |
| employees     | employees  | 2023-12-16 22:30:59 | 299423 |                  929 |                        0 |
+---------------+------------+---------------------+--------+----------------------+--------------------------+

Column clustered_index_size shows the number of disk pages this table occupies. A side note: the row count is duplicated in innodb_table_stats table and outcome of show table status.

Function page_raed_cost(1.0) returns the cost of reading one page. It is a mix of cost of reading a page from memory and disk. Wait! Let’s take a step back: cost in what unit? It is unit-less. It is not milliseconds nor other time unit. It is just a unit-less number to indicate the relative cost. See more details from Mysql cost model. Below is what I see in my localhost.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
mysql> select * from mysql.server_cost;
+------------------------------+------------+---------------------+---------+---------------+
| cost_name                    | cost_value | last_update         | comment | default_value |
+------------------------------+------------+---------------------+---------+---------------+
| disk_temptable_create_cost   |       NULL | 2023-12-12 11:13:50 | NULL    |            20 |
| disk_temptable_row_cost      |       NULL | 2023-12-12 11:13:50 | NULL    |           0.5 |
| key_compare_cost             |       NULL | 2023-12-12 11:13:50 | NULL    |          0.05 |
| memory_temptable_create_cost |       NULL | 2023-12-12 11:13:50 | NULL    |             1 |
| memory_temptable_row_cost    |       NULL | 2023-12-12 11:13:50 | NULL    |           0.1 |
| row_evaluate_cost            |       NULL | 2023-12-12 11:13:50 | NULL    |           0.1 |
+------------------------------+------------+---------------------+---------+---------------+
6 rows in set (0.01 sec)

mysql> select * from mysql.engine_cost;
+-------------+-------------+------------------------+------------+---------------------+---------+---------------+
| engine_name | device_type | cost_name              | cost_value | last_update         | comment | default_value |
+-------------+-------------+------------------------+------------+---------------------+---------+---------------+
| default     |           0 | io_block_read_cost     |       NULL | 2023-12-12 11:13:50 | NULL    |             1 |
| default     |           0 | memory_block_read_cost |       NULL | 2023-12-12 11:13:50 | NULL    |          0.25 |
+-------------+-------------+------------------------+------------+---------------------+---------+---------------+
2 rows in set (0.01 sec)

You can see that io_block_read_cost is 4x more expensive than memory_block_read_cost. In our case, Mysql has a fresh reboot, so nothing is cached. page_read_cost(1.0) = io_block_read_cost = 1. This is how Mysql gets the numbers for the cost field in the optimizer tracer output.

Max number of tables in a join is 61. This is because Mysql uses a unit64 to define the table map

1
using table_map = uint64_t;    // Used for table bits in join.

Range optimization

A general introduction to this topic: official guide. One thing to note is below sentense

The optimizer attempts to use additional key parts to determine the interval as long as the comparison operator is =, <=>, or IS NULL. If the operator is >, <, >=, <=, !=, <>, BETWEEN, or LIKE, the optimizer uses it but considers no more key parts.

I did not know this. Previously, I thought Mysql will use as many prefixes as possible.

Skip scan

Iterator/volcano model

When reading LimitOffsetIterator code, I feel limit means limit + offset, which is quite against to my intuition. After a few days, I found this function. Ah! It is.

This post is licensed under CC BY 4.0 by the author.