summaryrefslogtreecommitdiff
path: root/mysql-test/t/order_by.test
diff options
context:
space:
mode:
authorIgor Babaev <igor@askmonty.org>2012-09-01 14:21:59 -0700
committerIgor Babaev <igor@askmonty.org>2012-09-01 14:21:59 -0700
commita6b88f1431238152643e41979ce10b9bbdac2a82 (patch)
tree42482ef66f3c59b255d299fc58ace8c1b0c518ea /mysql-test/t/order_by.test
parent5a86a61219826aadf8d08cbc447fe438f2bf50c3 (diff)
downloadmariadb-git-a6b88f1431238152643e41979ce10b9bbdac2a82.tar.gz
MDEV-415: Back-port of the WL task #1393 from the mysql-5.6 code line.
The task adds a more efficient handling of the queries with ORDER BY order LIMIT n, such that n is small enough and no indexes are used for order.
Diffstat (limited to 'mysql-test/t/order_by.test')
-rw-r--r--mysql-test/t/order_by.test201
1 files changed, 200 insertions, 1 deletions
diff --git a/mysql-test/t/order_by.test b/mysql-test/t/order_by.test
index a6f50107cbe..07675dc243a 100644
--- a/mysql-test/t/order_by.test
+++ b/mysql-test/t/order_by.test
@@ -865,6 +865,7 @@ CALL mtr.add_suppression("Out of sort memory");
--error ER_OUT_OF_SORTMEMORY
select * from t1 order by b;
drop table t1;
+set session sort_buffer_size= 30000;
--echo #
--echo # Bug #39844: Query Crash Mysql Server 5.0.67
@@ -1391,7 +1392,205 @@ ORDER BY t2.c LIMIT 5;
DROP TABLE t1,t2,t3;
-#
+--echo #
+--echo # WL#1393 - Optimizing filesort with small limit
+--echo #
+
+CREATE TABLE t1(f0 int auto_increment primary key, f1 int, f2 varchar(200));
+INSERT INTO t1(f1, f2) VALUES
+(0,"0"),(1,"1"),(2,"2"),(3,"3"),(4,"4"),(5,"5"),
+(6,"6"),(7,"7"),(8,"8"),(9,"9"),(10,"10"),
+(11,"11"),(12,"12"),(13,"13"),(14,"14"),(15,"15"),
+(16,"16"),(17,"17"),(18,"18"),(19,"19"),(20,"20"),
+(21,"21"),(22,"22"),(23,"23"),(24,"24"),(25,"25"),
+(26,"26"),(27,"27"),(28,"28"),(29,"29"),(30,"30"),
+(31,"31"),(32,"32"),(33,"33"),(34,"34"),(35,"35"),
+(36,"36"),(37,"37"),(38,"38"),(39,"39"),(40,"40"),
+(41,"41"),(42,"42"),(43,"43"),(44,"44"),(45,"45"),
+(46,"46"),(47,"47"),(48,"48"),(49,"49"),(50,"50"),
+(51,"51"),(52,"52"),(53,"53"),(54,"54"),(55,"55"),
+(56,"56"),(57,"57"),(58,"58"),(59,"59"),(60,"60"),
+(61,"61"),(62,"62"),(63,"63"),(64,"64"),(65,"65"),
+(66,"66"),(67,"67"),(68,"68"),(69,"69"),(70,"70"),
+(71,"71"),(72,"72"),(73,"73"),(74,"74"),(75,"75"),
+(76,"76"),(77,"77"),(78,"78"),(79,"79"),(80,"80"),
+(81,"81"),(82,"82"),(83,"83"),(84,"84"),(85,"85"),
+(86,"86"),(87,"87"),(88,"88"),(89,"89"),(90,"90"),
+(91,"91"),(92,"92"),(93,"93"),(94,"94"),(95,"95"),
+(96,"96"),(97,"97"),(98,"98"),(99,"99");
+
+################
+## Test sort when source data fits in memory
+
+SELECT * FROM t1 ORDER BY f1 ASC, f0 LIMIT 100;
+SELECT * FROM t1 ORDER BY f1 ASC, f0 LIMIT 30;
+SELECT * FROM t1 ORDER BY f1 ASC, f0 LIMIT 0;
+SELECT * FROM t1 ORDER BY f2 DESC, f0 LIMIT 30;
+SELECT * FROM t1 ORDER BY f2 DESC, f0 LIMIT 0;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 20;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 0;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 10 OFFSET 10;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 0 OFFSET 10;
+
+################
+## Test sort when source data does not fit in memory
+set sort_buffer_size= 32768;
+CREATE TEMPORARY TABLE tmp (f1 int, f2 varchar(20));
+INSERT INTO tmp SELECT f1, f2 FROM t1;
+INSERT INTO t1(f1, f2) SELECT * FROM tmp;
+INSERT INTO tmp SELECT f1, f2 FROM t1;
+INSERT INTO t1(f1, f2) SELECT * FROM tmp;
+
+SELECT * FROM t1 ORDER BY f1 ASC, f0 LIMIT 30;
+SELECT * FROM t1 ORDER BY f1 ASC, f0 LIMIT 0;
+SELECT * FROM t1 ORDER BY f2 DESC, f0 LIMIT 30;
+SELECT * FROM t1 ORDER BY f2 DESC, f0 LIMIT 0;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 20;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 0;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 10 OFFSET 10;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 0 OFFSET 10;
+
+################
+## Test with SQL_CALC_FOUND_ROWS
+set sort_buffer_size= 32768;
+SELECT SQL_CALC_FOUND_ROWS * FROM t1
+ORDER BY f1, f0 LIMIT 30;
+SELECT FOUND_ROWS();
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1
+ORDER BY f1, f0 LIMIT 0;
+SELECT FOUND_ROWS();
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 WHERE f1>10
+ORDER BY f2, f0 LIMIT 20;
+SELECT FOUND_ROWS();
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 WHERE f1>10
+ORDER BY f2, f0 LIMIT 0;
+SELECT FOUND_ROWS();
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 WHERE f1>10
+ORDER BY f2, f0 LIMIT 10 OFFSET 10;
+SELECT FOUND_ROWS();
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 WHERE f1>10
+ORDER BY f2, f0 LIMIT 0 OFFSET 10;
+SELECT FOUND_ROWS();
+
+################
+## Test sorting with join
+## These are re-written to use PQ during execution.
+set sort_buffer_size= 327680;
+
+SELECT * FROM t1 JOIN tmp on t1.f2=tmp.f2
+ORDER BY tmp.f1, f0 LIMIT 30;
+
+SELECT * FROM t1 JOIN tmp on t1.f2=tmp.f2
+ORDER BY tmp.f1, f0 LIMIT 30 OFFSET 30;
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 JOIN tmp on t1.f2=tmp.f2
+ORDER BY tmp.f1, f0 LIMIT 30 OFFSET 30;
+SELECT FOUND_ROWS();
+
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 JOIN tmp on t1.f2=tmp.f2
+WHERE t1.f2>20
+ORDER BY tmp.f1, f0 LIMIT 30 OFFSET 30;
+SELECT FOUND_ROWS();
+
+################
+## Test views
+CREATE VIEW v1 as SELECT * FROM t1 ORDER BY f1, f0 LIMIT 30;
+SELECT * FROM v1;
+drop view v1;
+
+CREATE VIEW v1 as SELECT * FROM t1 ORDER BY f1, f0 LIMIT 100;
+SELECT * FROM v1 ORDER BY f2, f0 LIMIT 30;
+
+CREATE VIEW v2 as SELECT * FROM t1 ORDER BY f2, f0 LIMIT 100;
+SELECT * FROM v1 JOIN v2 on v1.f1=v2.f1 ORDER BY v1.f2,v1.f0,v2.f0
+LIMIT 30;
+
+################
+## Test group & having
+SELECT floor(f1/10) f3, count(f2) FROM t1
+GROUP BY 1 ORDER BY 2,1 LIMIT 5;
+
+SELECT floor(f1/10) f3, count(f2) FROM t1
+GROUP BY 1 ORDER BY 2,1 LIMIT 0;
+
+################
+## Test SP
+delimiter |;
+CREATE PROCEDURE wl1393_sp_test()
+BEGIN
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 30;
+SELECT * FROM t1 WHERE f1>10 ORDER BY f2, f0 LIMIT 15 OFFSET 15;
+SELECT SQL_CALC_FOUND_ROWS * FROM t1 WHERE f1>10
+ORDER BY f2, f0 LIMIT 15 OFFSET 15;
+SELECT FOUND_ROWS();
+SELECT * FROM v1 ORDER BY f2, f0 LIMIT 30;
+END|
+CALL wl1393_sp_test()|
+DROP PROCEDURE wl1393_sp_test|
+delimiter ;|
+
+################
+## Test with subqueries
+SELECT d1.f1, d1.f2 FROM t1
+LEFT JOIN (SELECT * FROM t1 ORDER BY f1 LIMIT 30) d1 on t1.f1=d1.f1
+ORDER BY d1.f2 DESC LIMIT 30;
+
+SELECT * FROM t1 WHERE f1 = (SELECT f1 FROM t1 ORDER BY 1 LIMIT 1);
+
+--error ER_SUBQUERY_NO_1_ROW
+SELECT * FROM t1 WHERE f1 = (SELECT f1 FROM t1 ORDER BY 1 LIMIT 2);
+
+DROP TABLE t1, tmp;
+DROP VIEW v1, v2;
+
+--echo # end of WL#1393 - Optimizing filesort with small limit
+
+--echo #
+--echo # Bug #58761
+--echo # Crash in Field::is_null in field.h on subquery in WHERE clause
+--echo #
+
+CREATE TABLE t1 (
+ pk INT NOT NULL AUTO_INCREMENT,
+ col_int_key INT DEFAULT NULL,
+ col_varchar_key VARCHAR(1) DEFAULT NULL,
+ PRIMARY KEY (pk),
+ KEY col_varchar_key (col_varchar_key,col_int_key)
+);
+
+INSERT INTO t1 VALUES (27,7,'x');
+INSERT INTO t1 VALUES (28,6,'m');
+INSERT INTO t1 VALUES (29,4,'c');
+
+CREATE TABLE where_subselect
+ SELECT DISTINCT `pk` AS field1 , `pk` AS field2
+ FROM t1 AS alias1
+ WHERE alias1 . `col_int_key` > 229
+ OR alias1 . `col_varchar_key` IS NOT NULL
+ GROUP BY field1, field2
+;
+
+SELECT *
+FROM where_subselect
+WHERE (field1, field2) IN (
+ SELECT DISTINCT `pk` AS field1 , `pk` AS field2
+ FROM t1 AS alias1
+ WHERE alias1 . `col_int_key` > 229
+ OR alias1 . `col_varchar_key` IS NOT NULL
+ GROUP BY field1, field2
+);
+
+DROP TABLE t1;
+DROP TABLE where_subselect;
+
+--echo # End of Bug #58761
+
+##
# Bug#35844: Covering index for ref access not compatible with ORDER BY list
#