作者:Mutlis

CSDN & 阿里云 & 知乎 等平台优质作者,擅长Oracle & MySQL等主流数据库系统的维护和管理等

本文来源:原创投稿

前言

对于 MySQL 5.6 以及之前的版本来说,查询优化器就像是一个黑盒子一样,你只能通过 EXPLAIN 语句查看到最后优化器决定使用的执行计划,却无法知道它为什么做这个决策。这对于一部分喜欢刨根问底的⼩伙伴来说简直是灾难:“我就觉得使用其他的执行方案⽐ EXPLAIN 输出的这种方案强,凭什么优化器做的决定和我想的不一样呢?”这篇文章主要介绍使用 optimizer trace 查看优化器生成执行计划的整个过程。

optimizer trace 表的神奇功效

在 MySQL 5.6 以及之后的版本中,设计 MySQL 的大叔贴⼼的为这部分小伙伴提出了一个 optimizer trace 的功能,这个功能可以让我们方便的查看优化器生成执行计划的整个过程,这个功能的开启与关闭由系统变量 optimizer_trace 决定,我们看一下:

  1. mysql> show variables like 'optimizer_trace';
  2. +-----------------+--------------------------+
  3. | Variable_name | Value |
  4. +-----------------+--------------------------+
  5. | optimizer_trace | enabled=off,one_line=off |
  6. +-----------------+--------------------------+
  7. 1 row in set (0.01 sec)
mysql> show variables like 'optimizer_trace';
+-----------------+--------------------------+
| Variable_name   | Value                    |
+-----------------+--------------------------+
| optimizer_trace | enabled=off,one_line=off |
+-----------------+--------------------------+
1 row in set (0.01 sec)

可以看到 enabled 值为 off,表明这个功能默认是关闭的。

小提示:

one_line 的值是控制输出格式的,如果为 on 那么所有输出都将在一行中展示,不适合⼈阅读,所以我们就保持其默认值为 off 吧。

如果想打开这个功能,必须⾸先把 enabled 的值改为 on,就像这样:

  1. mysql> SET optimizer_trace="enabled=on";
  2. Query OK, 0 rows affected (0.00 sec)
mysql> SET optimizer_trace="enabled=on";
Query OK, 0 rows affected (0.00 sec)

然后我们就可以输入我们想要查看优化过程的查询语句,当该查询语句执行完成后,就可以到 information_schema 数据库下的 OPTIMIZER_TRACE 表中查看完整的优化过程。这个 OPTIMIZER_TRACE 表有 4 个列,分别是:

  • QUERY:表示我们查询的语句;
  • TRACE:表示优化过程的 JSON 格式⽂本;
  • MISSING_BYTES_BEYOND_MAX_MEM_SIZE:由于优化过程可能会输出很多,如果超过某个限制时,多余的⽂本将不会被显示,这个字段展示了被忽略的⽂本字节数;
  • INSUFFICIENT_PRIVILEGES:表示是否没有权限查看优化过程,默认值是 0,只有某些特殊情况下才会是 1,我们暂时不关心这个字段的值。

完整的使用 optimizer trace 功能的步骤总结如下:

步骤一: 打开 optimizer trace 功能 (默认情况下它是关闭的)。

  1. mysql> SET optimizer_trace="enabled=on";
  2. Query OK, 0 rows affected (0.01 sec)
mysql> SET optimizer_trace="enabled=on";
Query OK, 0 rows affected (0.01 sec)

步骤二: 输入查询语句。

  1. SELECT ...;
SELECT    ...;

步骤三:optimizer_trace 表中查看上一个查询的优化过程。

  1. SELECT * FROM information_schema.OPTIMIZER_TRACE;
SELECT * FROM information_schema.OPTIMIZER_TRACE;

步骤四: 可能你还要观察其他语句执行的优化过程,重复上边的第 2、3步。

步骤五: 当你停⽌查看语句的优化过程时,把 optimizer trace 功能关闭。

  1. mysql> SET optimizer_trace="enabled=off";
  2. Query OK, 0 rows affected (0.01 sec)
mysql> SET optimizer_trace="enabled=off";
Query OK, 0 rows affected (0.01 sec)

现在我们有一个搜索条件比较多的查询语句,它的执行计划如下:

  1. mysql> EXPLAIN SELECT * FROM s1 WHERE key1 > 'z' AND key2 < 1000000 AND key3 IN ('aa', 'bb', 'cb') AND common_field = 'abc';
  2. +----+-------------+-------+------------+-------+----------------------------+----------+---------+------+------+----------+------------------------------------+
  3. | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
  4. +----+-------------+-------+------------+-------+----------------------------+----------+---------+------+------+----------+------------------------------------+
  5. | 1 | SIMPLE | s1 | NULL | range | idx_key2,idx_key1,idx_key3 | idx_key1 | 403 | NULL | 1 | 5.00 | Using index condition; Using where |
  6. +----+-------------+-------+------------+-------+----------------------------+----------+---------+------+------+----------+------------------------------------+
  7. 1 row in set, 1 warning (0.00 sec)
mysql> EXPLAIN SELECT * FROM s1 WHERE key1 > 'z' AND  key2 < 1000000 AND key3 IN ('aa', 'bb', 'cb') AND   common_field = 'abc';
+----+-------------+-------+------------+-------+----------------------------+----------+---------+------+------+----------+------------------------------------+
| id | select_type | table | partitions | type  | possible_keys              | key      | key_len | ref  | rows | filtered | Extra                              |
+----+-------------+-------+------------+-------+----------------------------+----------+---------+------+------+----------+------------------------------------+
|  1 | SIMPLE      | s1    | NULL       | range | idx_key2,idx_key1,idx_key3 | idx_key1 | 403     | NULL |    1 |     5.00 | Using index condition; Using where |
+----+-------------+-------+------------+-------+----------------------------+----------+---------+------+------+----------+------------------------------------+
1 row in set, 1 warning (0.00 sec)

可以看到该查询可能使用到的索引有3个,那么为什么优化器最终选择了idx_key1而不选择其他的索引或者直接全表扫描呢?这时候就可以通过otpimzer trace 功能来查看优化器的具体工作过程:

  1. mysql> SET optimizer_trace="enabled=on";
  2. Query OK, 0 rows affected (0.00 sec)
  3. mysql> SELECT * FROM s1 WHERE key1 > 'z' AND key2 < 1000000 AND key3 IN ('aa', 'bb', 'cb') AND common_field = 'abc';
  4. Empty set (0.00 sec)
  5. mysql> SELECT * FROM information_schema.OPTIMIZER_TRACE\G
mysql> SET optimizer_trace="enabled=on";
Query OK, 0 rows affected (0.00 sec)

mysql> SELECT * FROM s1 WHERE key1 > 'z' AND  key2 < 1000000 AND key3 IN ('aa', 'bb', 'cb') AND   common_field = 'abc';
Empty set (0.00 sec)

mysql> SELECT * FROM information_schema.OPTIMIZER_TRACE\G   

MySQL 可能会在之后的版本中添加更多的优化过程信息。不过杂乱之中其实还是蛮有规律的,优化过程大致分为了三个阶段:

  • prepare 阶段
  • optimize 阶段
  • execute 阶段

我们所说的基于成本的优化主要集中在 optimize 阶段,对于单表查询来说,我们主要关注 optimize 阶段的 "rows_estimation" 这个过程。这个过程深入分析了对单表查询的各种执行方案的成本,对于多表连接查询来说,我们更多需要关注 "considered_execution_plans" 这个过程,这个过程里会写明各种不同的连接方式所对应的成本。反正优化器最终会选择成本最低的那种方案来作为最终的执行计划,也就是我们使用 EXPLAIN 语句所展现出的那种方案。

最后,我们为感兴趣的小伙伴展示一下通过查询 OPTIMIZER_TRACE 表得到的输出(我使用#后跟随注释的形式为大家解释了优化过程中的一些比较重要的点,建议用电脑屏幕观看):

  1. *************************** 1. row ***************************
  2. # 分析的查询语句是什么
  3. QUERY: SELECT * FROM s1 WHERE key1 > 'z' AND key2 < 1000000 AND key3 IN ('aa', 'bb', 'cb') AND common_field = 'abc'
  4. # 优化的具体过程
  5. TRACE: {
  6. "steps": [
  7. {
  8. "join_preparation": { # prepare阶段
  9. "select#": 1,
  10. "steps": [
  11. {
  12. "IN_uses_bisection": true
  13. },
  14. {
  15. "expanded_query": "/* select#1 */ select `s1`.`id` AS `id`,`s1`.`key1` AS `key1`,`s1`.`key2` AS `key2`,`s1`.`key3` AS `key3`,`s1`.`key_part1` AS `key_part1`,`s1`.`key_part2` AS `key_part2`,`s1`.`key_part3` AS `key_part3`,`s1`.`common_field` AS `common_field` from `s1` where ((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and (`s1`.`common_field` = 'abc'))"
  16. }
  17. ]
  18. }
  19. },
  20. {
  21. "join_optimization": { # optimize阶段
  22. "select#": 1,
  23. "steps": [
  24. {
  25. "condition_processing": { # 处理搜索条件
  26. "condition": "WHERE",
  27. # 原始搜索条件
  28. "original_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and (`s1`.`common_field` = 'abc'))",
  29. "steps": [
  30. {
  31. # 等值传递转换
  32. "transformation": "equality_propagation",
  33. "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and multiple equal('abc', `s1`.`common_field`))"
  34. },
  35. {
  36. # 常量传递转换
  37. "transformation": "constant_propagation",
  38. "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and multiple equal('abc', `s1`.`common_field`))"
  39. },
  40. {
  41. # 去除没用的条件
  42. "transformation": "trivial_condition_removal",
  43. "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and multiple equal('abc', `s1`.`common_field`))"
  44. }
  45. ]
  46. }
  47. },
  48. {
  49. # 替换虚拟生成列
  50. "substitute_generated_columns": {
  51. }
  52. },
  53. {
  54. # 表的依赖信息
  55. "table_dependencies": [
  56. {
  57. "table": "`s1`",
  58. "row_may_be_null": false,
  59. "map_bit": 0,
  60. "depends_on_map_bits": [
  61. ]
  62. }
  63. ]
  64. },
  65. {
  66. "ref_optimizer_key_uses": [
  67. ]
  68. },
  69. {
  70. # 预估不同单表访问方法的访问成本
  71. "rows_estimation": [
  72. {
  73. "table": "`s1`",
  74. "range_analysis": {
  75. "table_scan": {
  76. "rows": 20250,
  77. "cost": 2051.35
  78. },
  79. # 分析可能使用的索引
  80. "potential_range_indexes": [
  81. {
  82. "index": "PRIMARY", # 主键不可用
  83. "usable": false,
  84. "cause": "not_applicable"
  85. },
  86. {
  87. "index": "idx_key2",# idx_key2可能被使用
  88. "usable": true,
  89. "key_parts": [
  90. "key2"
  91. ]
  92. },
  93. {
  94. "index": "idx_key1", # idx_key1可能被使用
  95. "usable": true,
  96. "key_parts": [
  97. "key1",
  98. "id"
  99. ]
  100. },
  101. {
  102. "index": "idx_key3", # idx_key3可能被使用
  103. "usable": true,
  104. "key_parts": [
  105. "key3",
  106. "id"
  107. ]
  108. },
  109. {
  110. "index": "idx_key_part", # idx_key_part不可用
  111. "usable": false,
  112. "cause": "not_applicable"
  113. }
  114. ],
  115. "setup_range_conditions": [
  116. ],
  117. "group_index_range": {
  118. "chosen": false,
  119. "cause": "not_group_by_or_distinct"
  120. },
  121. "skip_scan_range": {
  122. "potential_skip_scan_indexes": [
  123. {
  124. "index": "idx_key2",
  125. "usable": false,
  126. "cause": "query_references_nonkey_column"
  127. },
  128. {
  129. "index": "idx_key1",
  130. "usable": false,
  131. "cause": "query_references_nonkey_column"
  132. },
  133. {
  134. "index": "idx_key3",
  135. "usable": false,
  136. "cause": "query_references_nonkey_column"
  137. }
  138. ]
  139. },
  140. # 分析各种可能使用的索引的成本
  141. "analyzing_range_alternatives": {
  142. "range_scan_alternatives": [
  143. {
  144. # 使用idx_key2的成本分析
  145. "index": "idx_key2",
  146. # 使用idx_key2的范围区间
  147. "ranges": [
  148. "NULL < key2 < 1000000"
  149. ],
  150. "index_dives_for_eq_ranges": true,# 是否使用index dive
  151. "rowid_ordered": false,# 使用该索引获取的记录是否按照主键排序
  152. "using_mrr": false, # 是否使用mrr
  153. "index_only": false, # 是否是索引覆盖访问
  154. "in_memory": 1,
  155. "rows": 10125,# 使用该索引获取的记录条数
  156. "cost": 3544.01,# 使用该索引的成本
  157. "chosen": false, # 使用该索引的成本
  158. "cause": "cost" # 因为成本太大所以不选择该索引
  159. },
  160. {
  161. # 使用idx_key1的成本分析
  162. "index": "idx_key1",
  163. # 使用idx_key1的范围区间
  164. "ranges": [
  165. "'z' < key1"
  166. ],
  167. "index_dives_for_eq_ranges": true,# 同上
  168. "rowid_ordered": false,# 同上
  169. "using_mrr": false,# 同上
  170. "index_only": false,# 同上
  171. "in_memory": 1,
  172. "rows": 1,# 同上
  173. "cost": 0.61,# 同上
  174. "chosen": true# 是否选择该索引
  175. },
  176. {
  177. # 使用idx_key3的成本分析
  178. "index": "idx_key3",
  179. # 使用idx_key3的范围区间
  180. "ranges": [
  181. "key3 = 'aa'",
  182. "key3 = 'bb'",
  183. "key3 = 'cb'"
  184. ],
  185. "index_dives_for_eq_ranges": true,# 同上
  186. "rowid_ordered": false,# 同上
  187. "using_mrr": false,# 同上
  188. "index_only": false,# 同上
  189. "in_memory": 1,
  190. "rows": 3,# 同上
  191. "cost": 1.81,# 同上
  192. "chosen": false,# 同上
  193. "cause": "cost"# 同上
  194. }
  195. ],
  196. # 分析使用索引合并的成本
  197. "analyzing_roworder_intersect": {
  198. "usable": false,
  199. "cause": "too_few_roworder_scans"
  200. }
  201. },
  202. # 对于上述单表查询s1最优的访问方法
  203. "chosen_range_access_summary": {
  204. "range_access_plan": {
  205. "type": "range_scan",
  206. "index": "idx_key1",
  207. "rows": 1,
  208. "ranges": [
  209. "'z' < key1"
  210. ]
  211. },
  212. "rows_for_plan": 1,
  213. "cost_for_plan": 0.61,
  214. "chosen": true
  215. }
  216. }
  217. }
  218. ]
  219. },
  220. {
  221. # 分析各种可能的执行计划
  222. #(对多表查询这可能有很多种不同的方案,单表查询的方案上边已经分析过了,直接选取idx_key1就好)
  223. "considered_execution_plans": [
  224. {
  225. "plan_prefix": [
  226. ],
  227. "table": "`s1`",
  228. "best_access_path": {
  229. "considered_access_paths": [
  230. {
  231. "rows_to_scan": 1,
  232. "access_type": "range",
  233. "range_details": {
  234. "used_index": "idx_key1"
  235. },
  236. "resulting_rows": 1,
  237. "cost": 0.71,
  238. "chosen": true
  239. }
  240. ]
  241. },
  242. "condition_filtering_pct": 100,
  243. "rows_for_plan": 1,
  244. "cost_for_plan": 0.71,
  245. "chosen": true
  246. }
  247. ]
  248. },
  249. {
  250. "attaching_conditions_to_tables": {
  251. "original_condition": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))",
  252. "attached_conditions_computation": [
  253. ],
  254. "attached_conditions_summary": [
  255. {
  256. "table": "`s1`",
  257. "attached": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))"
  258. }
  259. ]
  260. }
  261. },
  262. {
  263. # 尝试给查询添加一些其他的查询条件
  264. "finalizing_table_conditions": [
  265. {
  266. "table": "`s1`",
  267. "original_table_condition": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))",
  268. "final_table_condition ": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))"
  269. }
  270. ]
  271. },
  272. {
  273. # 再稍稍的改进一下执行计划
  274. "refine_plan": [
  275. {
  276. "table": "`s1`",
  277. "pushed_index_condition": "(`s1`.`key1` > 'z')",
  278. "table_condition_attached": "((`s1`.`common_field` = 'abc') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))"
  279. }
  280. ]
  281. }
  282. ]
  283. }
  284. },
  285. {
  286. "join_execution": { # execute阶段
  287. "select#": 1,
  288. "steps": [
  289. ]
  290. }
  291. }
  292. ]
  293. }
  294. # 因优化过程文本太多而丢弃的文本字节大小,值为0时表示并没有丢弃
  295. MISSING_BYTES_BEYOND_MAX_MEM_SIZE: 0
  296. # 权限字段
  297. INSUFFICIENT_PRIVILEGES: 0
  298. 1 row in set (0.01 sec)
  299. ERROR:
  300. No query specified
*************************** 1. row ***************************
# 分析的查询语句是什么
QUERY: SELECT * FROM s1 WHERE key1 > 'z' AND  key2 < 1000000 AND key3 IN ('aa', 'bb', 'cb') AND   common_field = 'abc'
# 优化的具体过程
TRACE: {
  "steps": [
    {
      "join_preparation": {    # prepare阶段
        "select#": 1,
        "steps": [
          {
            "IN_uses_bisection": true
          },
          {
            "expanded_query": "/* select#1 */ select `s1`.`id` AS `id`,`s1`.`key1` AS `key1`,`s1`.`key2` AS `key2`,`s1`.`key3` AS `key3`,`s1`.`key_part1` AS `key_part1`,`s1`.`key_part2` AS `key_part2`,`s1`.`key_part3` AS `key_part3`,`s1`.`common_field` AS `common_field` from `s1` where ((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and (`s1`.`common_field` = 'abc'))"
          }
        ]
      }
    },
    {
      "join_optimization": {  # optimize阶段
        "select#": 1,
        "steps": [
          {
            "condition_processing": { # 处理搜索条件
              "condition": "WHERE",
              # 原始搜索条件
              "original_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and (`s1`.`common_field` = 'abc'))",
              "steps": [
                {
                # 等值传递转换
                  "transformation": "equality_propagation",
                  "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and multiple equal('abc', `s1`.`common_field`))"
                },
                {
                # 常量传递转换
                  "transformation": "constant_propagation",
                  "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and multiple equal('abc', `s1`.`common_field`))"
                },
                {
                # 去除没用的条件
                  "transformation": "trivial_condition_removal",
                  "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')) and multiple equal('abc', `s1`.`common_field`))"
                }
              ]
            }
          },
          {
          # 替换虚拟生成列
            "substitute_generated_columns": {
            }
          },
          {
          # 表的依赖信息
            "table_dependencies": [
              {
                "table": "`s1`",
                "row_may_be_null": false,
                "map_bit": 0,
                "depends_on_map_bits": [
                ]
              }
            ]
          },
          {
            "ref_optimizer_key_uses": [
            ]
          },
          {
          # 预估不同单表访问方法的访问成本
            "rows_estimation": [
              {
                "table": "`s1`",
                "range_analysis": {
                  "table_scan": {
                    "rows": 20250,
                    "cost": 2051.35
                  },
                   # 分析可能使用的索引
                  "potential_range_indexes": [
                    {
                      "index": "PRIMARY", # 主键不可用
                      "usable": false,
                      "cause": "not_applicable"
                    },
                    {
                      "index": "idx_key2",# idx_key2可能被使用
                      "usable": true,
                      "key_parts": [
                        "key2"
                      ]
                    },
                    {
                      "index": "idx_key1", # idx_key1可能被使用
                      "usable": true,
                      "key_parts": [
                        "key1",
                        "id"
                      ]
                    },
                    {
                      "index": "idx_key3", # idx_key3可能被使用
                      "usable": true,
                      "key_parts": [
                        "key3",
                        "id"
                      ]
                    },
                    {
                      "index": "idx_key_part", # idx_key_part不可用
                      "usable": false,
                      "cause": "not_applicable"
                    }
                  ],
                  "setup_range_conditions": [
                  ],
                  "group_index_range": {
                    "chosen": false,
                    "cause": "not_group_by_or_distinct"
                  },
                  "skip_scan_range": {
                    "potential_skip_scan_indexes": [
                      {
                        "index": "idx_key2",
                        "usable": false,
                        "cause": "query_references_nonkey_column"
                      },
                      {
                        "index": "idx_key1",
                        "usable": false,
                        "cause": "query_references_nonkey_column"
                      },
                      {
                        "index": "idx_key3",
                        "usable": false,
                        "cause": "query_references_nonkey_column"
                      }
                    ]
                  },
                  # 分析各种可能使用的索引的成本
                  "analyzing_range_alternatives": {
                    "range_scan_alternatives": [
                      {
                      # 使用idx_key2的成本分析
                        "index": "idx_key2",
                        # 使用idx_key2的范围区间
                        "ranges": [
                          "NULL < key2 < 1000000"
                        ],
                        "index_dives_for_eq_ranges": true,# 是否使用index dive
                        "rowid_ordered": false,# 使用该索引获取的记录是否按照主键排序
                        "using_mrr": false, # 是否使用mrr
                        "index_only": false, # 是否是索引覆盖访问
                        "in_memory": 1,
                        "rows": 10125,# 使用该索引获取的记录条数
                        "cost": 3544.01,# 使用该索引的成本
                        "chosen": false,  # 使用该索引的成本
                        "cause": "cost" # 因为成本太大所以不选择该索引
                      },
                      {
                      # 使用idx_key1的成本分析
                        "index": "idx_key1",
                         # 使用idx_key1的范围区间
                        "ranges": [
                          "'z' < key1"
                        ],
                        "index_dives_for_eq_ranges": true,# 同上
                        "rowid_ordered": false,# 同上
                        "using_mrr": false,# 同上
                        "index_only": false,# 同上
                        "in_memory": 1,
                        "rows": 1,# 同上
                        "cost": 0.61,# 同上
                        "chosen": true# 是否选择该索引
                      },
                      {
                       # 使用idx_key3的成本分析
                        "index": "idx_key3",
                          # 使用idx_key3的范围区间
                        "ranges": [
                          "key3 = 'aa'",
                          "key3 = 'bb'",
                          "key3 = 'cb'"
                        ],
                        "index_dives_for_eq_ranges": true,# 同上
                        "rowid_ordered": false,# 同上
                        "using_mrr": false,# 同上
                        "index_only": false,# 同上
                        "in_memory": 1,
                        "rows": 3,# 同上
                        "cost": 1.81,# 同上
                        "chosen": false,# 同上
                        "cause": "cost"# 同上
                      }
                    ],
                    # 分析使用索引合并的成本
                    "analyzing_roworder_intersect": {
                      "usable": false,
                      "cause": "too_few_roworder_scans"
                    }
                  },
                  # 对于上述单表查询s1最优的访问方法
                  "chosen_range_access_summary": {
                    "range_access_plan": {
                      "type": "range_scan",
                      "index": "idx_key1",
                      "rows": 1,
                      "ranges": [
                        "'z' < key1"
                      ]
                    },
                    "rows_for_plan": 1,
                    "cost_for_plan": 0.61,
                    "chosen": true
                  }
                }
              }
            ]
          },
          {

            # 分析各种可能的执行计划
            #(对多表查询这可能有很多种不同的方案,单表查询的方案上边已经分析过了,直接选取idx_key1就好)
            "considered_execution_plans": [
              {
                "plan_prefix": [
                ],
                "table": "`s1`",
                "best_access_path": {
                  "considered_access_paths": [
                    {
                      "rows_to_scan": 1,
                      "access_type": "range",
                      "range_details": {
                        "used_index": "idx_key1"
                      },
                      "resulting_rows": 1,
                      "cost": 0.71,
                      "chosen": true
                    }
                  ]
                },
                "condition_filtering_pct": 100,
                "rows_for_plan": 1,
                "cost_for_plan": 0.71,
                "chosen": true
              }
            ]
          },
          {
            "attaching_conditions_to_tables": {
              "original_condition": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))",
              "attached_conditions_computation": [
              ],
              "attached_conditions_summary": [
                {
                  "table": "`s1`",
                  "attached": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))"
                }
              ]
            }
          },
          {
          # 尝试给查询添加一些其他的查询条件
            "finalizing_table_conditions": [
              {
                "table": "`s1`",
                "original_table_condition": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))",
                "final_table_condition   ": "((`s1`.`common_field` = 'abc') and (`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))"
              }
            ]
          },
          {
           # 再稍稍的改进一下执行计划
            "refine_plan": [
              {
                "table": "`s1`",
                "pushed_index_condition": "(`s1`.`key1` > 'z')",
                "table_condition_attached": "((`s1`.`common_field` = 'abc') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('aa','bb','cb')))"
              }
            ]
          }
        ]
      }
    },
    {
      "join_execution": { # execute阶段
        "select#": 1,
        "steps": [
        ]
      }
    }
  ]
}
# 因优化过程文本太多而丢弃的文本字节大小,值为0时表示并没有丢弃
MISSING_BYTES_BEYOND_MAX_MEM_SIZE: 0
# 权限字段
INSUFFICIENT_PRIVILEGES: 0
1 row in set (0.01 sec)

ERROR: 
No query specified

大家看到这个输出的第一感觉就是这文本也太多了点吧,其实这只是优化器执行过程中的一小部分。

如果有小伙伴对使用 EXPLAIN 语句展示出的对某个查询的执行计划很不理解,大家可以尝试使用 optimizer trace 功能来详细了解每一种执行方案对应的成本,相信这个功能能让大家更深入的了解 MySQL 查询优化器。

关于 SQLE

爱可生开源社区的 SQLE 是一款面向数据库使用者和管理者,支持多场景审核,支持标准化上线流程,原生支持 MySQL 审核且数据库类型可扩展的 SQL 审核工具。

SQLE 获取

类型地址
版本库https://github.com/actiontech/sqle
文档https://actiontech.github.io/sqle-docs-cn/
发布信息https://github.com/actiontech/sqle/releases
数据审核插件开发文档https://actiontech.github.io/sqle-docs-cn/3.modules/3.7_auditplugin/auditplugin_development.html

提交有效 pr,高质量 issue,将获赠面值 200-500 元(具体面额依据质量而定)京东卡以及爱可生开源社区精美周边!更多关于 SQLE 的信息和交流,请加入官方QQ交流群:637150065