From 24b256987eb93ed7b14d92ce0100f2fc859bd4f9 Mon Sep 17 00:00:00 2001 From: unknown Date: Sat, 4 Jan 2003 14:59:52 +0400 Subject: [PATCH] Optimization of key usage (ORDER BY) (SCRUM) --- mysql-test/r/order_by.result | 34 +++++++++++++++ mysql-test/t/order_by.test | 21 +++++++++ sql/sql_select.cc | 84 ++++++++++++++++++++++++++++++++++++ 3 files changed, 139 insertions(+) diff --git a/mysql-test/r/order_by.result b/mysql-test/r/order_by.result index 5645961a178..a2b463ab361 100644 --- a/mysql-test/r/order_by.result +++ b/mysql-test/r/order_by.result @@ -506,3 +506,37 @@ SELECT titre,t1.numeropost,auteur,icone,nbrep,'0',date,vue,ouvert,lastauteur,des titre numeropost auteur icone nbrep 0 date vue ouvert lastauteur dest test 1 joce 0 0 0 0000-00-00 00:00:00 0 1 bug drop table t1,t2; +CREATE TABLE t1 ( +FieldKey varchar(36) NOT NULL default '', +LongVal bigint(20) default NULL, +StringVal mediumtext, +KEY FieldKey (FieldKey), +KEY LongField (FieldKey,LongVal), +KEY StringField (FieldKey,StringVal(32)) +); +INSERT INTO t1 VALUES ('0',3,'0'),('1',2,'1'),('1',1,'3'), ('1',0,'2'); +EXPLAIN SELECT * FROM t1 WHERE FieldKey = '1' ORDER BY LongVal; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ref FieldKey,LongField,StringField LongField 36 const 2 Using where +SELECT * FROM t1 WHERE FieldKey = '1' ORDER BY LongVal; +FieldKey LongVal StringVal +1 0 2 +1 1 3 +1 2 1 +EXPLAIN SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY LongVal; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range FieldKey,LongField,StringField FieldKey 36 NULL 3 Using where; Using filesort +SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY LongVal; +FieldKey LongVal StringVal +1 0 2 +1 1 3 +1 2 1 +EXPLAIN SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY FieldKey, LongVal; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range FieldKey,LongField,StringField LongField 36 NULL 3 Using where +SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY FieldKey, LongVal; +FieldKey LongVal StringVal +1 0 2 +1 1 3 +1 2 1 +DROP TABLE t1; diff --git a/mysql-test/t/order_by.test b/mysql-test/t/order_by.test index 0ee6f901aae..f4842a4998c 100644 --- a/mysql-test/t/order_by.test +++ b/mysql-test/t/order_by.test @@ -330,3 +330,24 @@ INSERT INTO t2 (numeropost,pseudo) VALUES (1,'joce'),(1,'bug'); SELECT titre,t1.numeropost,auteur,icone,nbrep,0,date,vue,ouvert,lastauteur,dest FROM t2 LEFT JOIN t1 USING(numeropost) WHERE t2.pseudo='joce' ORDER BY date DESC LIMIT 0,30; SELECT titre,t1.numeropost,auteur,icone,nbrep,'0',date,vue,ouvert,lastauteur,dest FROM t2 LEFT JOIN t1 USING(numeropost) WHERE t2.pseudo='joce' ORDER BY date DESC LIMIT 0,30; drop table t1,t2; + +# +# Test of test_if_subkey() function +# + +CREATE TABLE t1 ( + FieldKey varchar(36) NOT NULL default '', + LongVal bigint(20) default NULL, + StringVal mediumtext, + KEY FieldKey (FieldKey), + KEY LongField (FieldKey,LongVal), + KEY StringField (FieldKey,StringVal(32)) +); +INSERT INTO t1 VALUES ('0',3,'0'),('1',2,'1'),('1',1,'3'), ('1',0,'2'); +EXPLAIN SELECT * FROM t1 WHERE FieldKey = '1' ORDER BY LongVal; +SELECT * FROM t1 WHERE FieldKey = '1' ORDER BY LongVal; +EXPLAIN SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY LongVal; +SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY LongVal; +EXPLAIN SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY FieldKey, LongVal; +SELECT * FROM t1 WHERE FieldKey > '0' ORDER BY FieldKey, LongVal; +DROP TABLE t1; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ae45f96fbe8..dc2e315e69d 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -5933,6 +5933,69 @@ static uint find_shortest_key(TABLE *table, key_map usable_keys) return best; } +/* + SYNOPSIS + is_subkey() + key_part - first key parts + ref_key_part - second key parts + ref_key_part_end - last+1 part of the second key + DESCRIPTION + Test if a second key is the subkey of the first one. + NOTE + Second key MUST be shorter than the first one. + RETURN + 1 - is the subkey + 0 - otherwise +*/ + +inline bool +is_subkey(KEY_PART_INFO *key_part, KEY_PART_INFO *ref_key_part, + KEY_PART_INFO *ref_key_part_end) +{ + for (; ref_key_part < ref_key_part_end; key_part++, ref_key_part++) + if (!key_part->field->eq(ref_key_part->field)) + return 0; + return 1; +} + +/* + SYNOPSIS + test_if_subkey() + ref - number of key, used for WHERE clause + usable_keys - keys for testing + DESCRIPTION + Test if we can use one of the 'usable_keys' instead of 'ref' key. + RETURN + MAX_KEY - if we can't use other key + the number of found key - otherwise +*/ + +static uint +test_if_subkey(ORDER *order, TABLE *table, uint ref, key_map usable_keys) +{ + uint nr; + uint min_length= (uint) ~0; + uint best= MAX_KEY; + uint not_used; + KEY_PART_INFO *ref_key_part= table->key_info[ref].key_part; + uint ref_key_parts= table->key_info[ref].key_parts; + KEY_PART_INFO *ref_key_part_end= ref_key_part + ref_key_parts; + + for (nr= 0; usable_keys; usable_keys>>= 1, nr++) + { + if ((usable_keys & 1) && + table->key_info[nr].key_length < min_length && + table->key_info[nr].key_parts >= ref_key_parts && + is_subkey(table->key_info[nr].key_part, ref_key_part, + ref_key_part_end) && + test_if_order_by_key(order, table, nr, ¬_used)) + { + min_length= table->key_info[nr].key_length; + best= nr; + } + } + return best; +} /* Test if we can skip the ORDER BY by using an index. @@ -5980,6 +6043,27 @@ test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,ha_rows select_limit, */ int order_direction; uint used_key_parts; + if (!(usable_keys & ((key_map) 1 << ref_key))) + { + /* + We come here when ref_key is not among usable_keys + */ + uint a; + if ((a= test_if_subkey(order, table, ref_key, usable_keys)) < MAX_KEY) + { + if (tab->ref.key >= 0) + { + tab->ref.key= a; + table->file->index_init(a); + } + else + { + select->quick->index= a; + select->quick->init(); + } + ref_key= a; + } + } /* Check if we get the rows in requested sorted order by using the key */ if ((usable_keys & ((key_map) 1 << ref_key)) && (order_direction = test_if_order_by_key(order,table,ref_key,