diff options
author | gkodinov/kgeorge@magare.gmz <> | 2007-07-20 21:05:29 +0300 |
---|---|---|
committer | gkodinov/kgeorge@magare.gmz <> | 2007-07-20 21:05:29 +0300 |
commit | 8fc401e21fc3560a1c50fe24504d713e49e72e2d (patch) | |
tree | 48365c1e22c96fda3210f58953eab90424151b54 | |
parent | 17654758a4198761b0a91bef4e93441724b951aa (diff) | |
download | mariadb-git-8fc401e21fc3560a1c50fe24504d713e49e72e2d.tar.gz |
Bug #28591: MySQL need not sort the records in case of
ORDER BY primary_key on InnoDB table
Queries that use an InnoDB secondary index to retrieve
data don't need to sort in case of ORDER BY primary key
if the secondary index is compared to constant(s).
They can also skip sorting if ORDER BY contains both the
the secondary key parts and the primary key parts (in
that order).
This is because InnoDB returns the rows in order of the
primary key for rows with the same values of the secondary
key columns.
Fixed by preventing temp table sort for the qualifying
queries.
-rw-r--r-- | mysql-test/r/innodb_mysql.result | 245 | ||||
-rw-r--r-- | mysql-test/t/innodb_mysql.test | 33 | ||||
-rw-r--r-- | sql/sql_select.cc | 29 | ||||
-rw-r--r-- | sql/table.cc | 4 |
4 files changed, 309 insertions, 2 deletions
diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index 4535710c905..28f53a628ee 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -735,4 +735,249 @@ COUNT(*) 3072 set @@sort_buffer_size=default; DROP TABLE t1,t2; +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a), KEY bkey (b)) ENGINE=InnoDB; +INSERT INTO t1 VALUES (1,2),(3,2),(2,2),(4,2),(5,2),(6,2),(7,2),(8,2); +INSERT INTO t1 SELECT a + 8, 2 FROM t1; +INSERT INTO t1 SELECT a + 16, 1 FROM t1; +EXPLAIN SELECT * FROM t1 WHERE b=2 ORDER BY a; +id 1 +select_type SIMPLE +table t1 +type ref +possible_keys bkey +key bkey +key_len 5 +ref const +rows 16 +Extra Using where; Using index +SELECT * FROM t1 WHERE b=2 ORDER BY a; +a b +1 2 +2 2 +3 2 +4 2 +5 2 +6 2 +7 2 +8 2 +9 2 +10 2 +11 2 +12 2 +13 2 +14 2 +15 2 +16 2 +EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +id 1 +select_type SIMPLE +table t1 +type range +possible_keys bkey +key bkey +key_len 5 +ref NULL +rows 16 +Extra Using where; Using index; Using filesort +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +a b +1 2 +2 2 +3 2 +4 2 +5 2 +6 2 +7 2 +8 2 +9 2 +10 2 +11 2 +12 2 +13 2 +14 2 +15 2 +16 2 +17 1 +18 1 +19 1 +20 1 +21 1 +22 1 +23 1 +24 1 +25 1 +26 1 +27 1 +28 1 +29 1 +30 1 +31 1 +32 1 +EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; +id 1 +select_type SIMPLE +table t1 +type range +possible_keys bkey +key bkey +key_len 5 +ref NULL +rows 16 +Extra Using where; Using index +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; +a b +17 1 +18 1 +19 1 +20 1 +21 1 +22 1 +23 1 +24 1 +25 1 +26 1 +27 1 +28 1 +29 1 +30 1 +31 1 +32 1 +1 2 +2 2 +3 2 +4 2 +5 2 +6 2 +7 2 +8 2 +9 2 +10 2 +11 2 +12 2 +13 2 +14 2 +15 2 +16 2 +CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a), KEY bkey (b,c)) +ENGINE=InnoDB; +INSERT INTO t2 VALUES (1,1,1),(3,1,1),(2,1,1),(4,1,1); +INSERT INTO t2 SELECT a + 4, 1, 1 FROM t2; +INSERT INTO t2 SELECT a + 8, 1, 1 FROM t2; +EXPLAIN SELECT * FROM t2 WHERE b=1 ORDER BY a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 5 +ref const +rows 8 +Extra Using where; Using index; Using filesort +SELECT * FROM t2 WHERE b=1 ORDER BY a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 10 +ref const,const +rows 8 +Extra Using where; Using index +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 10 +ref const,const +rows 8 +Extra Using where; Using index +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 10 +ref const,const +rows 8 +Extra Using where; Using index +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +DROP TABLE t1,t2; End of 5.0 tests diff --git a/mysql-test/t/innodb_mysql.test b/mysql-test/t/innodb_mysql.test index d4ce997ddb1..9a44c673548 100644 --- a/mysql-test/t/innodb_mysql.test +++ b/mysql-test/t/innodb_mysql.test @@ -741,4 +741,37 @@ set @@sort_buffer_size=default; DROP TABLE t1,t2; +# +# Bug #28591: MySQL need not sort the records in case of ORDER BY +# primary_key on InnoDB table +# + +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a), KEY bkey (b)) ENGINE=InnoDB; +INSERT INTO t1 VALUES (1,2),(3,2),(2,2),(4,2),(5,2),(6,2),(7,2),(8,2); +INSERT INTO t1 SELECT a + 8, 2 FROM t1; +INSERT INTO t1 SELECT a + 16, 1 FROM t1; +query_vertical EXPLAIN SELECT * FROM t1 WHERE b=2 ORDER BY a; +SELECT * FROM t1 WHERE b=2 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; + +CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a), KEY bkey (b,c)) + ENGINE=InnoDB; +INSERT INTO t2 VALUES (1,1,1),(3,1,1),(2,1,1),(4,1,1); +INSERT INTO t2 SELECT a + 4, 1, 1 FROM t2; +INSERT INTO t2 SELECT a + 8, 1, 1 FROM t2; + +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 ORDER BY a; +SELECT * FROM t2 WHERE b=1 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; + +DROP TABLE t1,t2; + --echo End of 5.0 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index c62a19b2752..c77fb341232 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -12009,6 +12009,7 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, key_part_end=key_part+table->key_info[idx].key_parts; key_part_map const_key_parts=table->const_key_parts[idx]; int reverse=0; + my_bool on_primary_key= FALSE; DBUG_ENTER("test_if_order_by_key"); for (; order ; order=order->next, const_key_parts>>=1) @@ -12023,7 +12024,30 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, for (; const_key_parts & 1 ; const_key_parts>>= 1) key_part++; - if (key_part == key_part_end || key_part->field != field) + if (key_part == key_part_end) + { + /* + We are at the end of the key. Check if the engine has the primary + key as a suffix to the secondary keys. If it has continue to check + the primary key as a suffix. + */ + if (!on_primary_key && + (table->file->table_flags() & HA_PRIMARY_KEY_IN_READ_INDEX) && + table->s->primary_key != MAX_KEY) + { + on_primary_key= TRUE; + key_part= table->key_info[table->s->primary_key].key_part; + key_part_end=key_part+table->key_info[table->s->primary_key].key_parts; + const_key_parts=table->const_key_parts[table->s->primary_key]; + + for (; const_key_parts & 1 ; const_key_parts>>= 1) + key_part++; + } + else + DBUG_RETURN(0); + } + + if (key_part->field != field) DBUG_RETURN(0); /* set flag to 1 if we can use read-next on key, else to -1 */ @@ -12034,7 +12058,8 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, reverse=flag; // Remember if reverse key_part++; } - *used_key_parts= (uint) (key_part - table->key_info[idx].key_part); + *used_key_parts= on_primary_key ? table->key_info[idx].key_parts : + (uint) (key_part - table->key_info[idx].key_part); if (reverse == -1 && !(table->file->index_flags(idx, *used_key_parts-1, 1) & HA_READ_PREV)) reverse= 0; // Index can't be used diff --git a/sql/table.cc b/sql/table.cc index 4e0f2b5d287..8cfd206a74f 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -780,7 +780,11 @@ int openfrm(THD *thd, const char *name, const char *alias, uint db_stat, the primary key, then we can use any key to find this column */ if (ha_option & HA_PRIMARY_KEY_IN_READ_INDEX) + { field->part_of_key= share->keys_in_use; + if (field->part_of_sortkey.is_set(key)) + field->part_of_sortkey= share->keys_in_use; + } } if (field->key_length() != key_part->length) { |