mysql之通过trace分析优化器如何选择执行计划

什么是TRACE

mysql 5.6提供了对SQL的跟踪trace,通过trace文件能够进一步了解为什么优化器选择A执行计划而不选择B执行计划.帮助我们更好的理解优化器的行为.

开启TRACE

打开trace,并设置格式为Json

SET OPTIMIZER_TRACE="enabled=on",END_MARKERS_IN_JSON=on;

设置trace使用的内存大小,避免解析过程内存不足,文件显示不完整.

SET OPTIMIZER_TRACE_MAX_MEM_SIZE=1000000;

表结构

+------------+------------------+------+-----+---------+----------------+
| Field      | Type             | Null | Key | Default | Extra          |
+------------+------------------+------+-----+---------+----------------+
| id         | int(10) unsigned | NO   | PRI | NULL    | auto_increment |
| user_id    | int(10)          | NO   | MUL | 0       |                |
| post_id    | int(10) unsigned | NO   |     | 0       |                |
| car_id     | int(10) unsigned | NO   |     | 0       |                |
| created_at | int(10) unsigned | NO   |     | 0       |                |
| updated_at | int(10) unsigned | NO   |     | 0       |                |
+------------+------------------+------+-----+---------+----------------+

索引情况

+-----------------+------------+--------------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
| Table           | Non_unique | Key_name           | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment |
+-----------------+------------+--------------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
| most_left_index |          0 | PRIMARY            |            1 | id          | A         |     2712843 |     NULL | NULL   |      | BTREE      |         |               |
| most_left_index |          1 | idx_u_id_p_id_c_id |            1 | user_id     | A         |     1472365 |     NULL | NULL   |      | BTREE      |         |               |
| most_left_index |          1 | idx_u_id_p_id_c_id |            2 | post_id     | A         |     2712843 |     NULL | NULL   |      | BTREE      |         |               |
| most_left_index |          1 | idx_u_id_p_id_c_id |            3 | car_id      | A         |     2712843 |     NULL | NULL   |      | BTREE      |         |               |
+-----------------+------------+--------------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+

查询SQL

select  id,user_id,post_id,created_at from most_left_index where user_id > 170050;

user_id的范围

mysql> select * from most_left_index order by user_id asc limit 1;
+---------+---------+---------+--------+------------+------------+
| id      | user_id | post_id | car_id | created_at | updated_at |
+---------+---------+---------+--------+------------+------------+
| 1275623 |       1 |     909 |  54236 | 1521785902 |          0 |
+---------+---------+---------+--------+------------+------------+
1 row in set (0.00 sec)

mysql> select * from most_left_index order by user_id desc limit 1;
+--------+---------+---------+--------+------------+------------+
| id     | user_id | post_id | car_id | created_at | updated_at |
+--------+---------+---------+--------+------------+------------+
| 477803 | 1999998 | 1791109 | 699649 | 1521775032 |          0 |
+--------+---------+---------+--------+------------+------------+
1 row in set (0.00 sec)

大家这里看到了这里user_id的最小值为1 最大值为1999998,当然这个user_id是rand(1,2000000)的...那么我们查询user_id > 170050的数据,来分析下使用索引情况

执行计划

mysql> explain select sql_no_cache id,user_id,post_id,created_at from most_left_index where user_id > 170050;
+----+-------------+-----------------+------------+------+--------------------+------+---------+------+---------+----------+-------------+
| id | select_type | table           | partitions | type | possible_keys      | key  | key_len | ref  | rows    | filtered | Extra       |
+----+-------------+-----------------+------------+------+--------------------+------+---------+------+---------+----------+-------------+
|  1 | SIMPLE      | most_left_index | NULL       | ALL  | idx_u_id_p_id_c_id | NULL | NULL    | NULL | 2712843 |    50.00 | Using where |
+----+-------------+-----------------+------------+------+--------------------+------+---------+------+---------+----------+-------------+
1 row in set, 1 warning (0.00 sec)

这里possible_keys有索引,说明有可能会用到.type=ALL和key=NULL表明了,最后没有用索引

TRACE分析

执行查询

select sql_no_cache id,user_id,post_id,created_at from most_left_index where user_id > 170050;

输出文件

SELECT * FROM INFORMATION_SCHEMA.OPTIMIZER_TRACE\G;

TRACE json文件

mysql> SELECT * FROM INFORMATION_SCHEMA.OPTIMIZER_TRACE\G;
*************************** 1. row ***************************
                            QUERY: select sql_no_cache id,user_id,post_id,created_at from most_left_index where user_id > 170050
                            TRACE: {
  "steps": [
    {
      "join_preparation": {
        "select#": 1,
        "steps": [
          {
            "expanded_query": "/* select#1 */ select sql_no_cache `most_left_index`.`id` AS `id`,`most_left_index`.`user_id` AS `user_id`,`most_left_index`.`post_id` AS `post_id`,`most_left_index`.`created_at` AS `created_at` from `most_left_index` where (`most_left_index`.`user_id` > 170050)"
          }
        ] /* steps */
      } /* join_preparation */
    },
    {
      "join_optimization": {
        "select#": 1,
        "steps": [
          {
            "condition_processing": {
              "condition": "WHERE",
              "original_condition": "(`most_left_index`.`user_id` > 170050)",
              "steps": [
                {
                  "transformation": "equality_propagation",
                  "resulting_condition": "(`most_left_index`.`user_id` > 170050)"
                },
                {
                  "transformation": "constant_propagation",
                  "resulting_condition": "(`most_left_index`.`user_id` > 170050)"
                },
                {
                  "transformation": "trivial_condition_removal",
                  "resulting_condition": "(`most_left_index`.`user_id` > 170050)"
                }
              ] /* steps */
            } /* condition_processing */
          },
          {
            "substitute_generated_columns": {
            } /* substitute_generated_columns */
          },
          {
            "table_dependencies": [
              {
                "table": "`most_left_index`",
                "row_may_be_null": false,
                "map_bit": 0,
                "depends_on_map_bits": [
                ] /* depends_on_map_bits */
              }
            ] /* table_dependencies */
          },
          {
            "ref_optimizer_key_uses": [
            ] /* ref_optimizer_key_uses */
          },
          {
            "rows_estimation": [
              {
                "table": "`most_left_index`",
                "range_analysis": {
                  "table_scan": {
                    "rows": 2712843,
                    "cost": 550227
                  } /* table_scan */,
                  "potential_range_indexes": [
                    {
                      "index": "PRIMARY",
                      "usable": false,
                      "cause": "not_applicable"
                    },
                    {
                      "index": "idx_u_id_p_id_c_id",
                      "usable": true,
                      "key_parts": [
                        "user_id",
                        "post_id",
                        "car_id",
                        "id"
                      ] /* key_parts */
                    }
                  ] /* potential_range_indexes */,
                  "setup_range_conditions": [
                  ] /* setup_range_conditions */,
                  "group_index_range": {
                    "chosen": false,
                    "cause": "not_group_by_or_distinct"
                  } /* group_index_range */,
                  "analyzing_range_alternatives": {
                    "range_scan_alternatives": [
                      {
                        "index": "idx_u_id_p_id_c_id",
                        "ranges": [
                          "170050 < user_id"
                        ] /* ranges */,
                        "index_dives_for_eq_ranges": true,
                        "rowid_ordered": false,
                        "using_mrr": false,
                        "index_only": false,
                        "rows": 1356421,
                        "cost": 1.63e6,
                        "chosen": false,
                        "cause": "cost"
                      }
                    ] /* range_scan_alternatives */,
                    "analyzing_roworder_intersect": {
                      "usable": false,
                      "cause": "too_few_roworder_scans"
                    } /* analyzing_roworder_intersect */
                  } /* analyzing_range_alternatives */
                } /* range_analysis */
              }
            ] /* rows_estimation */
          },
          {
            "considered_execution_plans": [
              {
                "plan_prefix": [
                ] /* plan_prefix */,
                "table": "`most_left_index`",
                "best_access_path": {
                  "considered_access_paths": [
                    {
                      "rows_to_scan": 2712843,
                      "access_type": "scan",
                      "resulting_rows": 2.71e6,
                      "cost": 550225,
                      "chosen": true
                    }
                  ] /* considered_access_paths */
                } /* best_access_path */,
                "condition_filtering_pct": 100,
                "rows_for_plan": 2.71e6,
                "cost_for_plan": 550225,
                "chosen": true
              }
            ] /* considered_execution_plans */
          },
          {
            "attaching_conditions_to_tables": {
              "original_condition": "(`most_left_index`.`user_id` > 170050)",
              "attached_conditions_computation": [
              ] /* attached_conditions_computation */,
              "attached_conditions_summary": [
                {
                  "table": "`most_left_index`",
                  "attached": "(`most_left_index`.`user_id` > 170050)"
                }
              ] /* attached_conditions_summary */
            } /* attaching_conditions_to_tables */
          },
          {
            "refine_plan": [
              {
                "table": "`most_left_index`"
              }
            ] /* refine_plan */
          }
        ] /* steps */
      } /* join_optimization */
    },
    {
      "join_execution": {
        "select#": 1,
        "steps": [
        ] /* steps */
      } /* join_execution */
    }
  ] /* steps */
}
MISSING_BYTES_BEYOND_MAX_MEM_SIZE: 0
          INSUFFICIENT_PRIVILEGES: 0
1 row in set (0.00 sec)

TRACE分析

scan_table扫描代价

 "table_scan": {
    "rows": 2712843,
    "cost": 550227
  } /* table_scan */,
  .....

这里我们看到了全表扫描访问的rows记录为2712843,代价cost计算为550227

索引扫描代价

"range_scan_alternatives": [
      {
        "index": "idx_u_id_p_id_c_id",
        "ranges": [
          "170050 < user_id"
        ] /* ranges */,
        "index_dives_for_eq_ranges": true,
        "rowid_ordered": false,
        "using_mrr": false,
        "index_only": false,
        "rows": 1356421,
        "cost": 1.63e6,
        "chosen": false,
        "cause": "cost"
      }
      .....

这里看到了通过idx_u_id_p_id_c_id索引过滤条件时,优化器预估需要返回1356421记录,访问代价cost为1.63e6,远远大于全表扫描代价550227,所以,优化器倾向于选择全表扫描

缩小user_id的范围为user_id > 1999098

执行计划

mysql> explain select sql_no_cache id,user_id,post_id,created_at from most_left_index where user_id > 1999098;
+----+-------------+-----------------+------------+-------+--------------------+--------------------+---------+------+------+----------+-----------------------+
| id | select_type | table           | partitions | type  | possible_keys      | key                | key_len | ref  | rows | filtered | Extra                 |
+----+-------------+-----------------+------------+-------+--------------------+--------------------+---------+------+------+----------+-----------------------+
|  1 | SIMPLE      | most_left_index | NULL       | range | idx_u_id_p_id_c_id | idx_u_id_p_id_c_id | 4       | NULL | 1209 |   100.00 | Using index condition |
+----+-------------+-----------------+------------+-------+--------------------+--------------------+---------+------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)

这里可以看到我们这里使用到了所以,而且覆盖索引了,但是Using index condition表示,虽然覆盖索引了.但是还是需要回表

TRACE json文件

mysql> SELECT * FROM INFORMATION_SCHEMA.OPTIMIZER_TRACE\G;
*************************** 1. row ***************************
                            QUERY: select sql_no_cache id,user_id,post_id,created_at from most_left_index where user_id > 1999098
                            TRACE: {
  "steps": [
    {
      "join_preparation": {
        "select#": 1,
        "steps": [
          {
            "expanded_query": "/* select#1 */ select sql_no_cache `most_left_index`.`id` AS `id`,`most_left_index`.`user_id` AS `user_id`,`most_left_index`.`post_id` AS `post_id`,`most_left_index`.`created_at` AS `created_at` from `most_left_index` where (`most_left_index`.`user_id` > 1999098)"
          }
        ] /* steps */
      } /* join_preparation */
    },
    {
      "join_optimization": {
        "select#": 1,
        "steps": [
          {
            "condition_processing": {
              "condition": "WHERE",
              "original_condition": "(`most_left_index`.`user_id` > 1999098)",
              "steps": [
                {
                  "transformation": "equality_propagation",
                  "resulting_condition": "(`most_left_index`.`user_id` > 1999098)"
                },
                {
                  "transformation": "constant_propagation",
                  "resulting_condition": "(`most_left_index`.`user_id` > 1999098)"
                },
                {
                  "transformation": "trivial_condition_removal",
                  "resulting_condition": "(`most_left_index`.`user_id` > 1999098)"
                }
              ] /* steps */
            } /* condition_processing */
          },
          {
            "substitute_generated_columns": {
            } /* substitute_generated_columns */
          },
          {
            "table_dependencies": [
              {
                "table": "`most_left_index`",
                "row_may_be_null": false,
                "map_bit": 0,
                "depends_on_map_bits": [
                ] /* depends_on_map_bits */
              }
            ] /* table_dependencies */
          },
          {
            "ref_optimizer_key_uses": [
            ] /* ref_optimizer_key_uses */
          },
          {
            "rows_estimation": [
              {
                "table": "`most_left_index`",
                "range_analysis": {
                  "table_scan": {
                    "rows": 2712843,
                    "cost": 550227
                  } /* table_scan */,
                  "potential_range_indexes": [
                    {
                      "index": "PRIMARY",
                      "usable": false,
                      "cause": "not_applicable"
                    },
                    {
                      "index": "idx_u_id_p_id_c_id",
                      "usable": true,
                      "key_parts": [
                        "user_id",
                        "post_id",
                        "car_id",
                        "id"
                      ] /* key_parts */
                    }
                  ] /* potential_range_indexes */,
                  "setup_range_conditions": [
                  ] /* setup_range_conditions */,
                  "group_index_range": {
                    "chosen": false,
                    "cause": "not_group_by_or_distinct"
                  } /* group_index_range */,
                  "analyzing_range_alternatives": {
                    "range_scan_alternatives": [
                      {
                        "index": "idx_u_id_p_id_c_id",
                        "ranges": [
                          "1999098 < user_id"
                        ] /* ranges */,
                        "index_dives_for_eq_ranges": true,
                        "rowid_ordered": false,
                        "using_mrr": false,
                        "index_only": false,
                        "rows": 1209,
                        "cost": 1451.8,
                        "chosen": true
                      }
                    ] /* range_scan_alternatives */,
                    "analyzing_roworder_intersect": {
                      "usable": false,
                      "cause": "too_few_roworder_scans"
                    } /* analyzing_roworder_intersect */
                  } /* analyzing_range_alternatives */,
                  "chosen_range_access_summary": {
                    "range_access_plan": {
                      "type": "range_scan",
                      "index": "idx_u_id_p_id_c_id",
                      "rows": 1209,
                      "ranges": [
                        "1999098 < user_id"
                      ] /* ranges */
                    } /* range_access_plan */,
                    "rows_for_plan": 1209,
                    "cost_for_plan": 1451.8,
                    "chosen": true
                  } /* chosen_range_access_summary */
                } /* range_analysis */
              }
            ] /* rows_estimation */
          },
          {
            "considered_execution_plans": [
              {
                "plan_prefix": [
                ] /* plan_prefix */,
                "table": "`most_left_index`",
                "best_access_path": {
                  "considered_access_paths": [
                    {
                      "rows_to_scan": 1209,
                      "access_type": "range",
                      "range_details": {
                        "used_index": "idx_u_id_p_id_c_id"
                      } /* range_details */,
                      "resulting_rows": 1209,
                      "cost": 1693.6,
                      "chosen": true
                    }
                  ] /* considered_access_paths */
                } /* best_access_path */,
                "condition_filtering_pct": 100,
                "rows_for_plan": 1209,
                "cost_for_plan": 1693.6,
                "chosen": true
              }
            ] /* considered_execution_plans */
          },
          {
            "attaching_conditions_to_tables": {
              "original_condition": "(`most_left_index`.`user_id` > 1999098)",
              "attached_conditions_computation": [
              ] /* attached_conditions_computation */,
              "attached_conditions_summary": [
                {
                  "table": "`most_left_index`",
                  "attached": "(`most_left_index`.`user_id` > 1999098)"
                }
              ] /* attached_conditions_summary */
            } /* attaching_conditions_to_tables */
          },
          {
            "refine_plan": [
              {
                "table": "`most_left_index`",
                "pushed_index_condition": "(`most_left_index`.`user_id` > 1999098)",
                "table_condition_attached": null
              }
            ] /* refine_plan */
          }
        ] /* steps */
      } /* join_optimization */
    },
    {
      "join_execution": {
        "select#": 1,
        "steps": [
        ] /* steps */
      } /* join_execution */
    }
  ] /* steps */
}
MISSING_BYTES_BEYOND_MAX_MEM_SIZE: 0
          INSUFFICIENT_PRIVILEGES: 0
1 row in set (0.00 sec)

全表扫描代价

"table_scan": {
    "rows": 2712843,
    "cost": 550227
  } /* table_scan */,
  ....

索引扫描代价

"range_scan_alternatives": [
      {
        "index": "idx_u_id_p_id_c_id",
        "ranges": [
          "1999098 < user_id"
        ] /* ranges */,
        "index_dives_for_eq_ranges": true,
        "rowid_ordered": false,
        "using_mrr": false,
        "index_only": false,
        "rows": 1209,
        "cost": 1451.8,
        "chosen": true
      }
      .....

对照一下查询代价吧..就知道这次为什么要用索引了吧

好了...😜😜😜😜...贼累...