Chinaunix首页 | 论坛 | 博客
  • 博客访问: 4180107
  • 博文数量: 240
  • 博客积分: 11504
  • 博客等级: 上将
  • 技术积分: 4277
  • 用 户 组: 普通用户
  • 注册时间: 2006-12-28 14:24
文章分类

全部博文(240)

分类: Mysql/postgreSQL

2014-06-24 11:44:23

MySQL 的order by 涉及到三个参数:
A. sort_buffer_size 排序缓存。
B. read_rnd_buffer_size 第二次排序缓存。
C. max_length_for_sort_data 带普通列的最大排序约束。


我来简单说下MySQL的排序规则。
假设查询语句select * from tb1 where 1 order by  a ; 字段a没有建立索引;以上三个参数都足够大。
MySQL内部有两种排序规则:
第一种,是普通的排序这种排序的特点是节省内存,但是最终会对磁盘有一次随机扫描。 大概主要过程如下:
1. 由于没有WHERE条件,所以直接对磁盘进行全表扫描,把字段a以及每行的物理ID(假设为TID)拿出来。然后把所有拿到的记录全部放到sort_buffer_size中进行排序。
2. 根据排好序的TID,从磁盘随机扫描所需要的所有记录,排好序后再次把所有必须的记录放到read_rnd_buffer_size中。
第二种,是冗余排序。这种排序的特点是不需要二次对磁盘进行随机扫描,但是缺点很明显,太浪费内存空间。
跟第一种不同的是,在第一步里拿到的不仅仅是字段a以及TID,而是把所有请求的记录全部拿到后,放到sort_buffer_size中进行排序。这样可以直接从缓存中返回记录给客户端,不用再次从磁盘上获取一次。
从MySQL 5.7 后,对第二种排序进行了打包压缩处理,避免太浪费内存。比如对于varchar(255)来说,实际存储为varchar(3)。那么相比之前的方式节约了好多内存,避免缓存区域不够时,建立磁盘临时表。


以下为简单的演示
mysql> use t_girl;
Database changed


三个参数的具体值:

点击(此处)折叠或打开

  1. mysql> select truncate(@@sort_buffer_size/1024/1024,2)||'MB' as 'sort_buffer_size',truncate(@@read_rnd_buffer_size/1024/1024,2)||'MB' as read_rnd_buffer_zie,@@max_length_for_sort_data as max_length_for_sort_data;
  2. +------------------+---------------------+--------------------------+
  3. | sort_buffer_size | read_rnd_buffer_zie | max_length_for_sort_data |
  4. +------------------+---------------------+--------------------------+
  5. | 2.00MB | 2.00MB | 1024 |
  6. +------------------+---------------------+--------------------------+
  7. 1 row in set (0.00 sec)




演示表的相关数据:

点击(此处)折叠或打开

  1. mysql> select table_name,table_rows,concat(truncate(data_length/1024/1024,2),'MB') as 'table_size' from information_schema.tables where table_name = 't1' and table_schema = 't_girl';
  2. +------------+------------+------------+
  3. | table_name | table_rows | table_size |
  4. +------------+------------+------------+
  5. | t1 | 2092640 | 74.60MB |
  6. +------------+------------+------------+
  7. 1 row in set (0.00 sec)






开启优化器跟踪:

点击(此处)折叠或打开

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



从数据字典里面拿到跟踪结果:

点击(此处)折叠或打开

  1. mysql> select * from information_schema.optimizer_trace\G
  2. *************************** 1. row ***************************
  3.                             QUERY: select * from t1 where id < 10 order by id
  4.                             TRACE: {
  5.   "steps": [
  6.     {
  7.       "join_preparation": {
  8.         "select#": 1,
  9.         "steps": [
  10.           {
  11.             "expanded_query": "/* select#1 */ select `t1`.`id` AS `id`,`t1`.`log_time` AS `log_time` from `t1` where (`t1`.`id` < 10) order by `t1`.`id`"
  12.           }
  13.         ] /* steps */
  14.       } /* join_preparation */
  15.     },
  16.     {
  17.       "join_optimization": {
  18.         "select#": 1,
  19.         "steps": [
  20.           {
  21.             "condition_processing": {
  22.               "condition": "WHERE",
  23.               "original_condition": "(`t1`.`id` < 10)",
  24.               "steps": [
  25.                 {
  26.                   "transformation": "equality_propagation",
  27.                   "resulting_condition": "(`t1`.`id` < 10)"
  28.                 },
  29.                 {
  30.                   "transformation": "constant_propagation",
  31.                   "resulting_condition": "(`t1`.`id` < 10)"
  32.                 },
  33.                 {
  34.                   "transformation": "trivial_condition_removal",
  35.                   "resulting_condition": "(`t1`.`id` < 10)"
  36.                 }
  37.               ] /* steps */
  38.             } /* condition_processing */
  39.           },
  40.           {
  41.             "table_dependencies": [
  42.               {
  43.                 "table": "`t1`",
  44.                 "row_may_be_null": false,
  45.                 "map_bit": 0,
  46.                 "depends_on_map_bits": [
  47.                 ] /* depends_on_map_bits */
  48.               }
  49.             ] /* table_dependencies */
  50.           },
  51.           {
  52.             "ref_optimizer_key_uses": [
  53.             ] /* ref_optimizer_key_uses */
  54.           },
  55.           {
  56.             "rows_estimation": [
  57.               {
  58.                 "table": "`t1`",
  59.                 "table_scan": {
  60.                   "rows": 2092640,
  61.                   "cost": 4775
  62.                 } /* table_scan */
  63.               }
  64.             ] /* rows_estimation */
  65.           },
  66.           {
  67.             "considered_execution_plans": [
  68.               {
  69.                 "plan_prefix": [
  70.                 ] /* plan_prefix */,
  71.                 "table": "`t1`",
  72.                 "best_access_path": {
  73.                   "considered_access_paths": [
  74.                     {
  75.                       "access_type": "scan",
  76.                       "rows": 2.09e6,
  77.                       "cost": 423303,
  78.                       "chosen": true,
  79.                       "use_tmp_table": true
  80.                     }
  81.                   ] /* considered_access_paths */
  82.                 } /* best_access_path */,
  83.                 "cost_for_plan": 423303,
  84.                 "rows_for_plan": 2.09e6,
  85.                 "sort_cost": 2.09e6,
  86.                 "new_cost_for_plan": 2.52e6,
  87.                 "chosen": true
  88.               }
  89.             ] /* considered_execution_plans */
  90.           },
  91.           {
  92.             "attaching_conditions_to_tables": {
  93.               "original_condition": "(`t1`.`id` < 10)",
  94.               "attached_conditions_computation": [
  95.               ] /* attached_conditions_computation */,
  96.               "attached_conditions_summary": [
  97.                 {
  98.                   "table": "`t1`",
  99.                   "attached": "(`t1`.`id` < 10)"
  100.                 }
  101.               ] /* attached_conditions_summary */
  102.             } /* attaching_conditions_to_tables */
  103.           },
  104.           {
  105.             "clause_processing": {
  106.               "clause": "ORDER BY",
  107.               "original_clause": "`t1`.`id`",
  108.               "items": [
  109.                 {
  110.                   "item": "`t1`.`id`"
  111.                 }
  112.               ] /* items */,
  113.               "resulting_clause_is_simple": true,
  114.               "resulting_clause": "`t1`.`id`"
  115.             } /* clause_processing */
  116.           },
  117.           {
  118.             "refine_plan": [
  119.               {
  120.                 "table": "`t1`",
  121.                 "access_type": "table_scan"
  122.               }
  123.             ] /* refine_plan */
  124.           }
  125.         ] /* steps */
  126.       } /* join_optimization */
  127.     },
  128.     {
  129.       "join_execution": {
  130.         "select#": 1,
  131.         "steps": [
  132.           {
  133.             "filesort_information": [
  134.               {
  135.                 "direction": "asc",
  136.                 "table": "`t1`",
  137.                 "field": "id"
  138.               }
  139.             ] /* filesort_information */,
  140.             "filesort_priority_queue_optimization": {
  141.               "usable": false,
  142.               "cause": "not applicable (no LIMIT)"
  143.             } /* filesort_priority_queue_optimization */,
  144.             "filesort_execution": [
  145.             ] /* filesort_execution */,
  146.             "filesort_summary": {
  147.               "rows": 62390,
  148.               "examined_rows": 2097152,
  149.               "number_of_tmp_files": 0,
  150.               "sort_buffer_size": 2097152,
  151.               "sort_mode": "<sort_key, additional_fields>"
  152.             } /* filesort_summary */
  153.           }
  154.         ] /* steps */
  155.       } /* join_execution */
  156.     }
  157.   ] /* steps */
  158. }
  159. MISSING_BYTES_BEYOND_MAX_MEM_SIZE: 0
  160.           INSUFFICIENT_PRIVILEGES: 0
  161. 1 row in set (0.00 sec)


  162. mysql>




其中以上红色部分 表示用了第二种排序规则。
其他的两种 以及分别代表第一种和后续版本MySQL的提升, 自己体验去吧。
阅读(5404) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~