summaryrefslogtreecommitdiff
path: root/mysql-test
diff options
context:
space:
mode:
authorunknown <igor@olga.mysql.com>2007-08-02 12:45:56 -0700
committerunknown <igor@olga.mysql.com>2007-08-02 12:45:56 -0700
commitc90493749aa8736c76b5765cda0ca925864bbe37 (patch)
treecb69ff6598e568046e57c591baf10d4a49f2d5b7 /mysql-test
parentbaf24e69daf32141dda59b6d7fe817cc688b9f88 (diff)
downloadmariadb-git-c90493749aa8736c76b5765cda0ca925864bbe37.tar.gz
Fixed bug#28404.
This patch adds cost estimation for the queries with ORDER BY / GROUP BY and LIMIT. If there was a ref/range access to the table whose rows were required to be ordered in the result set the optimizer always employed this access though a scan by a different index that was compatible with the required order could be cheaper to produce the first L rows of the result set. Now for such queries the optimizer makes a choice between the cheapest ref/range accesses not compatible with the given order and index scans compatible with it. mysql-test/r/distinct.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/endspace.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/group_by.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/group_min_max.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/innodb.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/innodb_mysql.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/merge.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/order_by.result: Added a test case for bug #28404. mysql-test/r/select_found.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/r/subselect.result: Adjusted results for test cases affected fy the fix for bug #28404. mysql-test/t/distinct.test: Changed a test case after adding the fix for bug #28404. mysql-test/t/order_by.test: Added a test case for bug #28404. sql/sql_select.cc: Fixed bug#28404. This patch adds cost estimation for the queries with ORDER BY / GROUP BY and LIMIT. Now for such queries the optimizer makes a choice between the cheapest ref/range accesses not compatible with the given order and index scans compatible with it. Modified the function test_if_skip_sort_order to make the above mentioned choice cost based. sql/sql_select.h: Fixed bug#28404. This patch adds cost estimation for the queries with ORDER BY / GROUP BY and LIMIT. Added a new field fot the JOIN_TAB structure.
Diffstat (limited to 'mysql-test')
-rw-r--r--mysql-test/r/distinct.result8
-rw-r--r--mysql-test/r/endspace.result2
-rw-r--r--mysql-test/r/group_by.result2
-rw-r--r--mysql-test/r/group_min_max.result10
-rw-r--r--mysql-test/r/innodb.result2
-rw-r--r--mysql-test/r/innodb_mysql.result22
-rw-r--r--mysql-test/r/merge.result2
-rw-r--r--mysql-test/r/order_by.result55
-rw-r--r--mysql-test/r/select_found.result2
-rw-r--r--mysql-test/r/subselect.result2
-rw-r--r--mysql-test/t/distinct.test2
-rw-r--r--mysql-test/t/order_by.test37
12 files changed, 119 insertions, 27 deletions
diff --git a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result
index 002dbc6ccb5..795d8956a08 100644
--- a/mysql-test/r/distinct.result
+++ b/mysql-test/r/distinct.result
@@ -209,16 +209,16 @@ id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL PRIMARY 4 NULL 4 Using index
explain SELECT distinct t1.a from t1 order by a desc limit 1;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t1 index NULL PRIMARY 4 NULL 4 Using index
+1 SIMPLE t1 index NULL PRIMARY 4 NULL 1 Using index
explain SELECT distinct a from t3 order by a desc limit 2;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t3 index NULL a 5 NULL 204 Using index
+1 SIMPLE t3 index NULL a 5 NULL 40 Using index
explain SELECT distinct a,b from t3 order by a+1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 204 Using temporary; Using filesort
-explain SELECT distinct a,b from t3 order by a limit 10;
+explain SELECT distinct a,b from t3 order by a limit 2;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t3 index NULL a 5 NULL 204 Using temporary
+1 SIMPLE t3 index NULL a 5 NULL 2 Using temporary
explain SELECT a,b from t3 group by a,b order by a+1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 ALL NULL NULL NULL NULL 204 Using temporary; Using filesort
diff --git a/mysql-test/r/endspace.result b/mysql-test/r/endspace.result
index 6fb33dee826..9c8d12362c4 100644
--- a/mysql-test/r/endspace.result
+++ b/mysql-test/r/endspace.result
@@ -154,7 +154,7 @@ teststring
teststring
explain select * from t1 order by text1;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t1 index NULL key1 34 NULL 3
+1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
alter table t1 modify text1 char(32) binary not null;
select * from t1 order by text1;
text1
diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result
index ebe59331357..e09c66ac362 100644
--- a/mysql-test/r/group_by.result
+++ b/mysql-test/r/group_by.result
@@ -1144,7 +1144,7 @@ CREATE TABLE t2 (a INT, b INT, KEY(a));
INSERT INTO t2 VALUES (1, 1), (2, 2), (3,3), (4,4);
EXPLAIN SELECT a, SUM(b) FROM t2 GROUP BY a LIMIT 2;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t2 index NULL a 5 NULL 4
+1 SIMPLE t2 index NULL a 5 NULL 2
EXPLAIN SELECT a, SUM(b) FROM t2 IGNORE INDEX (a) GROUP BY a LIMIT 2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 ALL NULL NULL NULL NULL 4 Using temporary; Using filesort
diff --git a/mysql-test/r/group_min_max.result b/mysql-test/r/group_min_max.result
index b6bf7260dc2..02b1459afd0 100644
--- a/mysql-test/r/group_min_max.result
+++ b/mysql-test/r/group_min_max.result
@@ -1963,20 +1963,20 @@ id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 128 Using temporary; Using filesort
explain select a1,a2,count(a2) from t1 group by a1,a2,b;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t1 index NULL idx_t1_1 163 NULL 128 Using index
+1 SIMPLE t1 index NULL idx_t1_2 147 NULL 128 Using index
explain extended select a1,a2,count(a2) from t1 where (a1 > 'a') group by a1,a2,b;
id select_type table type possible_keys key key_len ref rows filtered Extra
-1 SIMPLE t1 index idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 163 NULL 128 75.00 Using where; Using index
+1 SIMPLE t1 index idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_2 147 NULL 128 75.00 Using where; Using index
Warnings:
Note 1003 select `test`.`t1`.`a1` AS `a1`,`test`.`t1`.`a2` AS `a2`,count(`test`.`t1`.`a2`) AS `count(a2)` from `test`.`t1` where (`test`.`t1`.`a1` > _latin1'a') group by `test`.`t1`.`a1`,`test`.`t1`.`a2`,`test`.`t1`.`b`
explain extended select sum(ord(a1)) from t1 where (a1 > 'a') group by a1,a2,b;
id select_type table type possible_keys key key_len ref rows filtered Extra
-1 SIMPLE t1 index idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 163 NULL 128 75.00 Using where; Using index
+1 SIMPLE t1 index idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_2 147 NULL 128 75.00 Using where; Using index
Warnings:
Note 1003 select sum(ord(`test`.`t1`.`a1`)) AS `sum(ord(a1))` from `test`.`t1` where (`test`.`t1`.`a1` > _latin1'a') group by `test`.`t1`.`a1`,`test`.`t1`.`a2`,`test`.`t1`.`b`
explain select distinct(a1) from t1 where ord(a2) = 98;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t1 index NULL idx_t1_1 163 NULL 128 Using where; Using index
+1 SIMPLE t1 index NULL idx_t1_2 147 NULL 128 Using where; Using index
select distinct(a1) from t1 where ord(a2) = 98;
a1
a
@@ -2256,7 +2256,7 @@ EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE
a IN (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1_outer index NULL a 10 NULL 15 Using where; Using index
-2 DEPENDENT SUBQUERY t1 index NULL a 10 NULL 15 Using index
+2 DEPENDENT SUBQUERY t1 index NULL a 10 NULL 1 Using index
EXPLAIN SELECT 1 FROM t1 AS t1_outer GROUP BY a HAVING
a > (SELECT max(b) FROM t1 GROUP BY a HAVING a < 2);
id select_type table type possible_keys key key_len ref rows Extra
diff --git a/mysql-test/r/innodb.result b/mysql-test/r/innodb.result
index 804c4b81c17..dce5e1a9a35 100644
--- a/mysql-test/r/innodb.result
+++ b/mysql-test/r/innodb.result
@@ -947,7 +947,7 @@ id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL PRIMARY 4 NULL #
explain select * from t1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t1 index NULL b 4 NULL #
+1 SIMPLE t1 ALL NULL NULL NULL NULL # Using filesort
explain select * from t1 order by c;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL # Using filesort
diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result
index 273374d016b..bf12c31326a 100644
--- a/mysql-test/r/innodb_mysql.result
+++ b/mysql-test/r/innodb_mysql.result
@@ -851,13 +851,13 @@ EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a;
id 1
select_type SIMPLE
table t1
-type range
+type index
possible_keys bkey
-key bkey
-key_len 5
+key PRIMARY
+key_len 4
ref NULL
-rows 16
-Extra Using where; Using index; Using filesort
+rows 32
+Extra Using where; Using index
SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a;
a b
1 2
@@ -946,13 +946,13 @@ EXPLAIN SELECT * FROM t2 WHERE b=1 ORDER BY a;
id 1
select_type SIMPLE
table t2
-type ref
+type index
possible_keys bkey
-key bkey
-key_len 5
-ref const
-rows 8
-Extra Using where; Using index; Using filesort
+key PRIMARY
+key_len 4
+ref NULL
+rows 16
+Extra Using where; Using index
SELECT * FROM t2 WHERE b=1 ORDER BY a;
a b c
1 1 1
diff --git a/mysql-test/r/merge.result b/mysql-test/r/merge.result
index bb4fc654b38..5aa4288500c 100644
--- a/mysql-test/r/merge.result
+++ b/mysql-test/r/merge.result
@@ -86,7 +86,7 @@ a b
19 Testing
explain select a from t3 order by a desc limit 10;
id select_type table type possible_keys key key_len ref rows Extra
-1 SIMPLE t3 index NULL a 4 NULL 1131 Using index
+1 SIMPLE t3 index NULL a 4 NULL 10 Using index
select a from t3 order by a desc limit 10;
a
699
diff --git a/mysql-test/r/order_by.result b/mysql-test/r/order_by.result
index 25fbeadf21b..fd3fb89b5f4 100644
--- a/mysql-test/r/order_by.result
+++ b/mysql-test/r/order_by.result
@@ -1073,3 +1073,58 @@ id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 const PRIMARY,b b 5 const 1
1 SIMPLE t2 ref a a 5 const 2 Using where; Using index
DROP TABLE t1,t2;
+CREATE TABLE t1(
+id int auto_increment PRIMARY KEY, c2 int, c3 int, INDEX k2(c2), INDEX k3(c3));
+INSERT INTO t1 (c2,c3) VALUES
+(31,34),(35,38),(34,31),(32,35),(31,39),
+(11,14),(15,18),(14,11),(12,15),(11,19);
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+SELECT COUNT(*) FROM t1;
+COUNT(*)
+40960
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2=11 ORDER BY c3 LIMIT 20;
+id select_type table type possible_keys key key_len ref rows Extra
+1 SIMPLE t1 index k2 k3 5 NULL 88 Using where
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2=11 ORDER BY c3 LIMIT 100;
+id select_type table type possible_keys key key_len ref rows Extra
+1 SIMPLE t1 ref k2 k2 5 const 9300 Using where; Using filesort
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2 BETWEEN 10 AND 12 ORDER BY c3 LIMIT 100;
+id select_type table type possible_keys key key_len ref rows Extra
+1 SIMPLE t1 index k2 k3 5 NULL 316 Using where
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2 BETWEEN 10 AND 12 ORDER BY c3 LIMIT 2000;
+id select_type table type possible_keys key key_len ref rows Extra
+1 SIMPLE t1 range k2 k2 5 NULL 12937 Using where; Using filesort
+SELECT id,c3 FROM t1 WHERE c2=11 ORDER BY c3 LIMIT 20;
+id c3
+6 14
+16 14
+26 14
+36 14
+46 14
+56 14
+66 14
+76 14
+86 14
+96 14
+106 14
+116 14
+126 14
+136 14
+146 14
+156 14
+166 14
+176 14
+186 14
+196 14
+DROP TABLE t1;
diff --git a/mysql-test/r/select_found.result b/mysql-test/r/select_found.result
index 7abd65beb46..7896f8a9f4e 100644
--- a/mysql-test/r/select_found.result
+++ b/mysql-test/r/select_found.result
@@ -84,7 +84,7 @@ UNIQUE KEY e_n (email,name)
EXPLAIN SELECT SQL_CALC_FOUND_ROWS DISTINCT email FROM t2 LEFT JOIN t1 ON kid = t2.id WHERE t1.id IS NULL LIMIT 10;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 system PRIMARY,kid NULL NULL NULL 0 const row not found
-1 SIMPLE t2 index NULL e_n 104 NULL 200
+1 SIMPLE t2 index NULL e_n 104 NULL 10
SELECT SQL_CALC_FOUND_ROWS DISTINCT email FROM t2 LEFT JOIN t1 ON kid = t2.id WHERE t1.id IS NULL LIMIT 10;
email
email1
diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result
index 40b9e489577..a25183a0e6d 100644
--- a/mysql-test/r/subselect.result
+++ b/mysql-test/r/subselect.result
@@ -3419,7 +3419,7 @@ EXPLAIN
SELECT * FROM t1 WHERE (a,b) = ANY (SELECT a, max(b) FROM t1 GROUP BY a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 9 Using where
-2 DEPENDENT SUBQUERY t1 index NULL a 8 NULL 9 Using filesort
+2 DEPENDENT SUBQUERY t1 index NULL a 8 NULL 1 Using filesort
DROP TABLE t1;
create table t1( f1 int,f2 int);
insert into t1 values (1,1),(2,2);
diff --git a/mysql-test/t/distinct.test b/mysql-test/t/distinct.test
index 7310f98cd16..bfdb5f8b9f8 100644
--- a/mysql-test/t/distinct.test
+++ b/mysql-test/t/distinct.test
@@ -97,7 +97,7 @@ explain SELECT t1.a from t1 group by a order by a desc;
explain SELECT distinct t1.a from t1 order by a desc limit 1;
explain SELECT distinct a from t3 order by a desc limit 2;
explain SELECT distinct a,b from t3 order by a+1;
-explain SELECT distinct a,b from t3 order by a limit 10;
+explain SELECT distinct a,b from t3 order by a limit 2;
explain SELECT a,b from t3 group by a,b order by a+1;
drop table t1,t2,t3,t4;
diff --git a/mysql-test/t/order_by.test b/mysql-test/t/order_by.test
index 1e520da9f00..fb08dbe74e6 100644
--- a/mysql-test/t/order_by.test
+++ b/mysql-test/t/order_by.test
@@ -739,3 +739,40 @@ INSERT INTO t2 VALUES (1,1),(1,2),(2,1),(2,2);
EXPLAIN SELECT 1 FROM t1,t2 WHERE t1.b=2 AND t1.a=t2.a ORDER BY t2.b;
DROP TABLE t1,t2;
+
+# End of 5.0
+
+#
+# Bug #28404: query with ORDER BY and ref access
+#
+
+CREATE TABLE t1(
+ id int auto_increment PRIMARY KEY, c2 int, c3 int, INDEX k2(c2), INDEX k3(c3));
+
+INSERT INTO t1 (c2,c3) VALUES
+ (31,34),(35,38),(34,31),(32,35),(31,39),
+ (11,14),(15,18),(14,11),(12,15),(11,19);
+
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+INSERT INTO t1 (c2,c3) SELECT c2,c3 FROM t1;
+
+SELECT COUNT(*) FROM t1;
+
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2=11 ORDER BY c3 LIMIT 20;
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2=11 ORDER BY c3 LIMIT 100;
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2 BETWEEN 10 AND 12 ORDER BY c3 LIMIT 100;
+EXPLAIN SELECT id,c3 FROM t1 WHERE c2 BETWEEN 10 AND 12 ORDER BY c3 LIMIT 2000;
+
+SELECT id,c3 FROM t1 WHERE c2=11 ORDER BY c3 LIMIT 20;
+
+DROP TABLE t1;