diff --git a/mysql-test/main/derived_view.result b/mysql-test/main/derived_view.result index 00940d88805..6da132848d1 100644 --- a/mysql-test/main/derived_view.result +++ b/mysql-test/main/derived_view.result @@ -2698,7 +2698,7 @@ ON p.id = g.p_random ORDER BY gallery_name ASC ; id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY ALL NULL NULL NULL NULL 10 Using filesort +1 PRIMARY ALL NULL NULL NULL NULL 10 Using temporary; Using filesort 1 PRIMARY p eq_ref PRIMARY PRIMARY 4 g.p_random 1 Using where 2 DERIVED gal ALL NULL NULL NULL NULL 10 3 DEPENDENT SUBQUERY pi ref gallery_id gallery_id 4 test.gal.id 4 Using temporary; Using filesort diff --git a/mysql-test/main/having.result b/mysql-test/main/having.result index 51b88c5b8d2..7106b42fc8d 100644 --- a/mysql-test/main/having.result +++ b/mysql-test/main/having.result @@ -837,13 +837,15 @@ ANALYZE TABLE t1; Table Op Msg_type Msg_text test.t1 analyze status Engine-independent statistics collected test.t1 analyze status OK -SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) -GROUP BY t HAVING r = 1 ORDER BY t1.u; +explain SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) GROUP BY t HAVING r = 1 ORDER BY t1.u; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using temporary; Using filesort +SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) GROUP BY t HAVING r = 1 ORDER BY t1.u; t r 10 1 12 1 -15 1 -17 1 +14 1 +16 1 DROP TABLE t1; DROP FUNCTION next_seq_value; DROP TABLE series; diff --git a/mysql-test/main/having.test b/mysql-test/main/having.test index 7e0a0439f8e..5e091afec1e 100644 --- a/mysql-test/main/having.test +++ b/mysql-test/main/having.test @@ -884,8 +884,8 @@ CREATE TABLE t1 (t INT, u INT, KEY(t)); INSERT INTO t1 VALUES(10, 10), (11, 11), (12, 12), (12, 13),(14, 15), (15, 16), (16, 17), (17, 17); ANALYZE TABLE t1; -SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) - GROUP BY t HAVING r = 1 ORDER BY t1.u; +explain SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) GROUP BY t HAVING r = 1 ORDER BY t1.u; +SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) GROUP BY t HAVING r = 1 ORDER BY t1.u; DROP TABLE t1; DROP FUNCTION next_seq_value; diff --git a/mysql-test/main/rownum.result b/mysql-test/main/rownum.result new file mode 100644 index 00000000000..0cd0a3982d6 --- /dev/null +++ b/mysql-test/main/rownum.result @@ -0,0 +1,987 @@ +CREATE OR REPLACE TABLE t1(a int, b int) engine=aria; +CREATE OR REPLACE TABLE t2(a int, b int) engine=aria; +insert into t1 values (1,10),(2,20),(3,30); +insert into t2 values (2,21),(3,31),(4,41); +# +# Simple selects +# +select a,b,rownum() from t1; +a b rownum() +1 10 1 +2 20 2 +3 30 3 +select a,b,rownum() from t1 where rownum() < 2; +a b rownum() +1 10 1 +select a,b from t1 where rownum() <= 2; +a b +1 10 +2 20 +select a,b from t1 where rownum() > 2; +a b +# +# Subqueries +# +select t1.a,rownum(),t3.a,t3.t2_rownum from t1, (select t2.a,rownum() as t2_rownum from t2 where rownum() <=2) t3; +a rownum() a t2_rownum +1 1 2 1 +1 2 3 2 +2 3 2 1 +2 4 3 2 +3 5 2 1 +3 6 3 2 +select t1.a, (select t2.b from t2 where t1.a=t2.a and rownum() <= 1) 'b' from t1; +a b +1 NULL +2 21 +3 31 +select t1.a, t3.a from t1, (select * from t2 where rownum() <= 2) t3; +a a +1 2 +1 3 +2 2 +2 3 +3 2 +3 3 +select * from (select tt.*,rownum() as id from (select * from t1) tt) t3 where id>2; +a b id +3 30 3 +# +# Joins +# +select t1.a,t1.b,t2.a,t2.b,rownum() from t1,t2 where rownum() <= 4; +a b a b rownum() +1 10 2 21 1 +2 20 2 21 2 +3 30 2 21 3 +1 10 3 31 4 +select *,rownum() from t1,t2 where t1.a=t2.a and rownum()<=2; +a b a b rownum() +2 20 2 21 1 +3 30 3 31 2 +select * from t1 left join t2 on (t2.a=t1.a and rownum()=0); +a b a b +1 10 NULL NULL +2 20 NULL NULL +3 30 NULL NULL +select * from t1 left join t2 on (t2.a=t1.a and rownum()>1); +a b a b +1 10 NULL NULL +2 20 NULL NULL +3 30 NULL NULL +select * from t1 left join t2 on (t2.a=t1.a and rownum()<1); +a b a b +1 10 NULL NULL +2 20 NULL NULL +3 30 NULL NULL +select * from t1 left join t2 on (t2.a=t1.a and rownum()=1); +a b a b +2 20 2 21 +1 10 NULL NULL +3 30 NULL NULL +select * from t1 left join t2 on (t2.a=t1.a and rownum()>=1); +a b a b +2 20 2 21 +3 30 3 31 +1 10 NULL NULL +# +# Union +# +select * from t1 where rownum() <=2 union select * from t2 where rownum()<= 1; +a b +1 10 +2 20 +2 21 +# +# Order by +# +select * from t1 where rownum() <= 2 order by a desc; +a b +2 20 +1 10 +explain select * from t1 where rownum() <= 2 order by a desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using filesort +select t1.a,t1.b,rownum() from t1 where rownum() <= 2 order by a desc; +a b rownum() +2 20 2 +1 10 1 +explain select t1.a,t1.b,rownum() from t1 where rownum() <= 2 order by a desc; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where; Using temporary; Using filesort +select *,rownum() from t1,t2; +a b a b rownum() +1 10 2 21 1 +2 20 2 21 2 +3 30 2 21 3 +1 10 3 31 4 +2 20 3 31 5 +3 30 3 31 6 +1 10 4 41 7 +2 20 4 41 8 +3 30 4 41 9 +select *,rownum() from t1,t2 order by t2.a desc, t1.a desc; +a b a b rownum() +3 30 4 41 9 +2 20 4 41 8 +1 10 4 41 7 +3 30 3 31 6 +2 20 3 31 5 +1 10 3 31 4 +3 30 2 21 3 +2 20 2 21 2 +1 10 2 21 1 +select * from (select * from t1 order by a desc) as t where rownum() <= 2; +a b +3 30 +2 20 +select * from t1,t2 where t1.a=t2.a and rownum()<=2 order by t1.a,t2.a; +a b a b +2 20 2 21 +3 30 3 31 +# +# Having +# +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having r <= 2; +a sum(t1.b) r +1 10 1 +2 20 2 +select * from t1 having rownum() <= 2; +a b +1 10 +2 20 +select t1.a, sum(t1.b), rownum() from t1 group by t1.a; +a sum(t1.b) rownum() +1 10 1 +2 20 2 +3 30 3 +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having r <= 2; +a sum(t1.b) r +1 10 1 +2 20 2 +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having rownum() <= 2; +a sum(t1.b) r +1 10 1 +2 20 2 +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having r <= 2 order by a desc; +a sum(t1.b) r +2 20 2 +1 10 1 +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having rownum() <= 2 order by a desc; +a sum(t1.b) r +2 20 2 +1 10 1 +# +# Sum functions +# +select max(rownum()),min(rownum()) from t1; +max(rownum()) min(rownum()) +3 1 +select sum(rownum()),avg(rownum()) from t1; +sum(rownum()) avg(rownum()) +6 2.0000 +# +# Group by +# +select t1.a,sum(t1.b) from t1 where rownum() < 2 group by t1.a; +a sum(t1.b) +1 10 +select t1.a,sum(t2.b) from t1 JOIN t2 ON (t1.a=t2.a) where rownum() <= 2 group by t1.a; +a sum(t2.b) +2 21 +3 31 +select * from (select t1.a,sum(t2.b) from t1 JOIN t2 ON (t1.a=t2.a) group by t1.a) as t where rownum() <= 1; +a sum(t2.b) +2 21 +select t1.a,sum(rownum()),count(*) from t1 where rownum() <= 2 group by t1.a; +a sum(rownum()) count(*) +1 1 1 +2 2 1 +select * from (select t1.a,sum(t1.b) from t1 group by t1.a) as t3 where rownum() < 2; +a sum(t1.b) +1 10 +create table t3 (a int) engine=myisam; +insert into t3 values (3),(5),(5),(3); +select a, max(rownum()) from t3 group by a; +a max(rownum()) +3 4 +5 3 +drop table t3; +CREATE TABLE t3 ( +a int(11) DEFAULT NULL, +b varchar(1024) DEFAULT NULL +); +insert into t3 select mod(seq*3,20)+1, repeat(char(33+mod(seq,90)),mod(seq,10)*100) from seq_1_to_23; +SELECT sq.a,length(sq.f) FROM (SELECT a, GROUP_CONCAT(b,b) AS f FROM t3 GROUP BY a ORDER BY a desc) as sq WHERE ROWNUM() <= 10; +a length(sq.f) +20 600 +19 1200 +18 1800 +17 400 +16 1000 +15 1600 +14 200 +13 800 +12 1400 +11 0 +drop table t3; +# +# Prepared statements +# +PREPARE stmt1 from "select a,b,rownum() from t1 where rownum() <= 2"; +execute stmt1; +a b rownum() +1 10 1 +2 20 2 +execute stmt1; +a b rownum() +1 10 1 +2 20 2 +deallocate prepare stmt1; +# +# Views +# +create view v1 as select t1.a,rownum() from t1; +select * from v1; +a rownum() +1 1 +2 2 +3 3 +select t1.a,v1.* from t1,v1 where t1.a=v1.a; +a a rownum() +1 1 1 +2 2 2 +3 3 3 +drop view v1; +CREATE TABLE t3 (a INT); +INSERT INTO t3 VALUES (1),(2),(3); +CREATE VIEW v1 AS SELECT a FROM t3 WHERE ROWNUM() <= 2; +SELECT * FROM v1; +a +1 +2 +drop view v1; +drop table t3; +# +# Reserved words +# +create table t4 (a int, rownum int); +insert into t4 (a,rownum) values (1,2); +select t4.a,t4.rownum from t4; +a rownum +1 2 +drop table t4; +# +# Test Oracle mode +# +set SQL_MODE=ORACLE; +select t1.a,rownum from t1 where rownum<=2; +a rownum +1 1 +2 2 +select t1.a,rownum() from t1 where rownum()<=2; +a rownum() +1 1 +2 2 +create table t4 (a int, rownum int); +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'rownum int)' at line 1 +DECLARE +CURSOR c_cursor +IS select a,b,rownum from t1 where rownum <= 2; +v_a t1.a%TYPE; +v_b t1.b%TYPE; +v_rn t1.a%TYPE; +BEGIN +OPEN c_cursor; +FETCH c_cursor INTO v_a, v_b, v_rn; +WHILE c_cursor%FOUND LOOP +SELECT concat(v_a,'--',v_b,'--',v_rn); +FETCH c_cursor INTO v_a, v_b, v_rn; +END LOOP; +CLOSE c_cursor; +END;| +concat(v_a,'--',v_b,'--',v_rn) +1--10--1 +concat(v_a,'--',v_b,'--',v_rn) +2--20--2 +select a, rownum from t1 group by a, rownum having rownum < 3; +a rownum +1 1 +2 2 +select a, rownum as r from t1 group by a, rownum having r < 3; +a r +1 1 +2 2 +select a, rownum from t1 group by a, rownum having "rownum" < 3; +a rownum +1 1 +2 2 +select a, rownum from t1 group by a, rownum having rownum < 3 order by a desc; +a rownum +2 2 +1 1 +select a, rownum as r from t1 group by a, rownum having r < 3 order by a desc; +a r +2 2 +1 1 +select a, rownum from t1 group by a, rownum having "rownum" < 3 order by a desc; +a rownum +2 2 +1 1 +set SQL_MODE=DEFAULT; +# Cleanup +drop table t1,t2; +# +# INSERT +# +create table t1 (a int not null primary key, b int); +insert into t1 values (1,rownum()),(2,rownum()),(3,rownum()); +select * from t1; +a b +1 1 +2 2 +3 3 +drop table t1; +# +# INSERT DELAYED +# +create table t1 (a int not null primary key, b int); +insert delayed into t1 values (1,rownum()),(2,rownum()),(3,rownum()); +flush tables; +select * from t1; +a b +1 1 +2 2 +3 3 +drop table t1; +# +# INSERT IGNORED +# +create table t1 (a int not null primary key, b int); +insert ignore into t1 values (1,rownum()),(2,rownum()),(2,rownum()),(3,rownum()); +Warnings: +Warning 1062 Duplicate entry '2' for key 'PRIMARY' +select * from t1; +a b +1 1 +2 2 +3 4 +delete from t1; +insert ignore into t1 select * from (values (1,rownum()),(2,rownum()),(2,rownum()),(3,rownum())) t; +Warnings: +Warning 1062 Duplicate entry '2' for key 'PRIMARY' +select * from t1; +a b +1 1 +2 2 +3 4 +drop table t1; +# +# INSERT ... RETURNING +# +create or replace table t1 (a int); +insert into t1 values (1),(2) returning a, rownum(); +a rownum() +1 1 +2 2 +drop table t1; +# +# UPDATE +# +create table t1 (a int not null primary key, b int); +insert into t1 values (1,1),(2,2),(3,3); +update t1 set b=0; +update t1 set b=rownum()+1; +select * from t1; +a b +1 2 +2 3 +3 4 +update t1 set b=0; +update t1 set b=rownum() where a < 10 and rownum() < 2; +select * from t1; +a b +1 1 +2 0 +3 0 +drop table t1; +create table t1 (a int); +insert into t1 values (10),(20),(30); +update t1 set a = rownum(); +select * from t1; +a +1 +2 +3 +update t1 set a = rownum(); +select * from t1; +a +1 +2 +3 +drop table t1; +# +# DELETE +# +create table t1 (a int not null primary key, b int); +insert into t1 values (1,1),(2,0),(3,0); +delete from t1 where a < 10 and rownum() < 2; +select * from t1; +a b +2 0 +3 0 +drop table t1; +# +# MULTI-TABLE-DELETE +# +create table t1 (a int not null primary key); +insert into t1 values (1),(2),(3); +create table t2 (a int not null primary key); +insert into t2 values (1),(2),(3); +delete t1,t2 from t1,t2 where t1.a=t2.a and rownum() <= 2; +select * from t1; +a +3 +select * from t2; +a +3 +drop table t1,t2; +# +# MULTI-TABLE-UPDATE +CREATE TABLE t1 (ID INT); +CREATE TABLE t2 (ID INT, +s1 TEXT, s2 TEXT, s3 VARCHAR(10), s4 TEXT, s5 VARCHAR(10)); +INSERT INTO t1 VALUES (1),(2); +INSERT INTO t2 VALUES (1,'test', 'test', 'test', 'test', 'test'), +(2,'test', 'test', 'test', 'test', 'test'); +SELECT * FROM t1 LEFT JOIN t2 USING(ID); +ID s1 s2 s3 s4 s5 +1 test test test test test +2 test test test test test +UPDATE t1 LEFT JOIN t2 USING(ID) SET s1 = 'changed'; +select * from t2; +ID s1 s2 s3 s4 s5 +1 changed test test test test +2 changed test test test test +update t2 set s1=""; +UPDATE t1 LEFT JOIN t2 USING(ID) SET s1 = 'changed' where rownum() <=1; +select * from t2; +ID s1 s2 s3 s4 s5 +1 changed test test test test +2 test test test test +drop table t1,t2; +# +# LOAD DATA +# +create table t1 (a int, b int, c int); +load data infile '../../std_data/loaddata7.dat' into table t1 fields terminated by ',' lines terminated by "\r\n" (a,b) set c=rownum(); +select * from t1; +a b c +2 2 1 +3 3 2 +4 4 3 +5 5 4 +6 6 5 +drop table t1; +# +# LIMIT OPTIMIZATION +# +create table t1 (a int); +insert into t1 select seq from seq_1_to_100; +flush status; +select * from t1 where rownum() <= 3; +a +1 +2 +3 +show status like "Rows_read"; +Variable_name Value +Rows_read 3 +flush status; +select * from t1 where rownum() <= 4 and rownum() <= 3; +a +1 +2 +3 +show status like "Rows_read"; +Variable_name Value +Rows_read 3 +flush status; +select * from t1 where rownum() < 4 and a > 10; +a +11 +12 +13 +show status like "Rows_read"; +Variable_name Value +Rows_read 13 +flush status; +select * from t1 where 3 >= rownum(); +a +1 +2 +3 +show status like "Rows_read"; +Variable_name Value +Rows_read 3 +flush status; +select * from t1 where 4 > rownum() and a > 20; +a +21 +22 +23 +show status like "Rows_read"; +Variable_name Value +Rows_read 23 +flush status; +select * from t1 where rownum() = 1 and a > 10; +a +11 +show status like "Rows_read"; +Variable_name Value +Rows_read 11 +flush status; +select * from t1 where a > 30 && 1 = rownum(); +a +31 +show status like "Rows_read"; +Variable_name Value +Rows_read 31 +flush status; +# No limit optimization +select * from t1 where rownum() > 10; +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where 10 < rownum(); +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where rownum() >= 10; +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where 10 < rownum(); +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where 10 <= rownum(); +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where 2 = rownum(); +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where rownum() = 2; +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select * from t1 where rownum() <= 0; +a +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +select *,rownum() from t1 where rownum() < 10 limit 4, 4; +a rownum() +5 5 +6 6 +7 7 +8 8 +show status like "Rows_read"; +Variable_name Value +Rows_read 8 +flush status; +select * from t1 where rownum() < 10 order by a; +a +1 +2 +3 +4 +5 +6 +7 +8 +9 +show status like "Rows_read"; +Variable_name Value +Rows_read 100 +flush status; +# rownum and limit +select * from t1 where rownum() < 4 limit 10; +a +1 +2 +3 +show status like "Rows_read"; +Variable_name Value +Rows_read 3 +flush status; +select * from t1 where rownum() < 10 limit 4; +a +1 +2 +3 +4 +show status like "Rows_read"; +Variable_name Value +Rows_read 4 +drop table t1; +# +# Rownum examples from Woqutech +# +set SQL_MODE=ORACLE; +create table t1 (c1 int ,c2 varchar(20)) engine=myisam; +insert into t1 values (1, 'aaa'),(2, 'bbb'),(3, 'ccc'),(4, 'ddd'),(5, 'eee'); +update t1 set c2 = 'xxx' where rownum = 2; +select * from t1 where c2='xxx'; +c1 c2 +update t1 set c2 = 'xxx' where rownum < 3; +select * from t1 where c2='xxx'; +c1 c2 +1 xxx +2 xxx +delete from t1 where rownum = 2; +select count(*) from t1; +count(*) +5 +delete from t1 where rownum < 3; +select count(*) from t1; +count(*) +3 +delete from t1 where c1=rownum ; +select count(*) from t1; +count(*) +3 +delete from t1 where c1=rownum+2 ; +select count(*) from t1; +count(*) +0 +set SQL_MODE=DEFAULT; +drop table t1; +# +# Rownum() used in not supported places (returns 0 or gives an error) +# +set @a=rownum(); +select @a; +@a +0 +create or replace table t (a int, b int as (rownum()) virtual); +ERROR HY000: Function or expression 'rownum()' cannot be used in the GENERATED ALWAYS AS clause of `b` +create table t1 (a int); +insert into t1 values (3),(1),(5),(8),(4); +handler t1 open; +handler t1 read next where rownum() < 1; +ERROR HY000: Function or expression 'rownum()' cannot be used in the WHERE clause of `HANDLER` +handler t1 close; +drop table t1; +create table t1 (a int not null primary key, b int); +insert into t1 values (1,1),(2,2),(3,3); +create function f() returns int return rownum(); +select a, rownum(), f() from t1; +a rownum() f() +1 1 0 +2 2 0 +3 3 0 +drop function f; +drop table t1; +create or replace table t1 (a int, r int); +create trigger tr before update on t1 for each row set NEW.r = rownum(); +insert into t1 (a) values (1),(2); +select * from t1; +a r +1 NULL +2 NULL +update t1 set a=a+10; +select * from t1; +a r +11 0 +12 0 +drop trigger tr; +drop table t1; +# +# LIMIT optimisation +# +create table t1 (a int); +insert into t1 values (1),(2),(3),(4),(5); +flush status; +select * from (select a from t1 where a < 1000) as tt where rownum() <= 2; +a +1 +2 +show status like "Rows_read"; +Variable_name Value +Rows_read 2 +explain extended select * from (select a from t1 where a < 1000) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 limit 2) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000) as tt where rownum() <= 2"; +flush status; +execute stmt; +a +1 +2 +show status like "Rows_read"; +Variable_name Value +Rows_read 2 +flush status; +execute stmt; +a +1 +2 +show status like "Rows_read"; +Variable_name Value +Rows_read 2 +deallocate prepare stmt; +flush status; +select * from (select a from t1 where a < 1000 group by a) as tt where rownum() <= 2; +a +1 +2 +show status like "Rows_read"; +Variable_name Value +Rows_read 5 +explain extended select * from (select a from t1 where a < 1000 group by a) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where; Using temporary; Using filesort +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 group by `test`.`t1`.`a` limit 2) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000 group by a) as tt where rownum() <= 2"; +execute stmt; +a +1 +2 +execute stmt; +a +1 +2 +deallocate prepare stmt; +flush status; +select * from (select a from t1 where a < 1000 group by a order by 1) as tt where rownum() <= 2; +a +1 +2 +show status like "Rows_read"; +Variable_name Value +Rows_read 5 +explain extended select * from (select a from t1 where a < 1000 group by a order by 1) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where; Using temporary; Using filesort +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 group by `test`.`t1`.`a` order by 1 limit 2) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000 group by a order by 1) as tt where rownum() <= 2"; +execute stmt; +a +1 +2 +execute stmt; +a +1 +2 +deallocate prepare stmt; +flush status; +select * from (select a from t1 where a < 1000 union select 10) as tt where rownum() <= 2; +a +1 +2 +show status like "Rows_read"; +Variable_name Value +Rows_read 5 +explain extended select * from (select a from t1 where a < 1000 union select 10) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +3 UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 union /* select#3 */ select 10 AS `10` limit 2) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000 union select 10) as tt where rownum() <= 2"; +execute stmt; +a +1 +2 +execute stmt; +a +1 +2 +deallocate prepare stmt; +# Other limit +select * from (select a from t1 where a < 1000 group by a order by 1 limit 1) as tt where rownum() <= 2; +a +1 +explain extended select * from (select a from t1 where a < 1000 group by a order by 1 limit 1) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where; Using temporary; Using filesort +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 group by `test`.`t1`.`a` order by 1 limit 1) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000 group by a order by 1 limit 1) as tt where rownum() <= 2"; +execute stmt; +a +1 +execute stmt; +a +1 +deallocate prepare stmt; +# Other limit less +select * from (select a from t1 where a < 1000 group by a order by 1 limit 10) as tt where rownum() <= 2; +a +1 +2 +explain extended select * from (select a from t1 where a < 1000 group by a order by 1 limit 10) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where; Using temporary; Using filesort +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 group by `test`.`t1`.`a` order by 1 limit 2) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000 group by a order by 1 limit 10) as tt where rownum() <= 2"; +execute stmt; +a +1 +2 +execute stmt; +a +1 +2 +deallocate prepare stmt; +select * from (select a from t1 where a < 1000 union select 10 limit 1) as tt where rownum() <= 2; +a +1 +explain extended select * from (select a from t1 where a < 1000 union select 10 limit 1) as tt where rownum() <= 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 5 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +3 UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 union /* select#3 */ select 10 AS `10` limit 1) `tt` where rownum() <= 2 limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000 union select 10 limit 1) as tt where rownum() <= 2"; +execute stmt; +a +1 +execute stmt; +a +1 +deallocate prepare stmt; +# < rownum +select * from (select a from t1 where a < 1000) as tt where rownum() < 2; +a +1 +explain extended select * from (select a from t1 where a < 1000) as tt where rownum() < 2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 limit 1) `tt` where rownum() < 2 limit 1 +prepare stmt from "select * from (select a from t1 where a < 1000) as tt where rownum() < 2"; +execute stmt; +a +1 +execute stmt; +a +1 +deallocate prepare stmt; +# Simple expression +select * from (select a from t1 where a < 1000) as tt where rownum() <= 1+1; +a +1 +2 +explain extended select * from (select a from t1 where a < 1000) as tt where rownum() <= 1+1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 limit 2) `tt` where rownum() <= (1 + 1) limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000) as tt where rownum() <= 1+1"; +execute stmt; +a +1 +2 +execute stmt; +a +1 +2 +deallocate prepare stmt; +# Simple expression reversed +select * from (select a from t1 where a < 1000) as tt where 1+1 >= rownum(); +a +1 +2 +explain extended select * from (select a from t1 where a < 1000) as tt where 1+1 >= rownum(); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 limit 2) `tt` where (1 + 1) >= rownum() limit 2 +prepare stmt from "select * from (select a from t1 where a < 1000) as tt where 1+1 >= rownum()"; +execute stmt; +a +1 +2 +execute stmt; +a +1 +2 +deallocate prepare stmt; +# expensive (no opt) +select * from (select a from t1 where a < 1000) as tt where (select max(a) from t1) >= rownum(); +a +1 +2 +3 +4 +5 +explain extended select * from (select a from t1 where a < 1000) as tt where (select max(a) from t1) >= rownum(); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 5 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 5 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 5 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `tt`.`a` AS `a` from (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 1000 limit 5) `tt` where (/* select#3 */ select max(`test`.`t1`.`a`) from `test`.`t1`) >= rownum() limit 5 +prepare stmt from "select * from (select a from t1 where a < 1000) as tt where (select max(a) from t1) >= rownum()"; +execute stmt; +a +1 +2 +3 +4 +5 +execute stmt; +a +1 +2 +3 +4 +5 +deallocate prepare stmt; +drop table t1; +# +# Table value constructors +# +values ("first row"),("next row is 3"),(rownum()),("next row is 5"),(rownum()); +first row +first row +next row is 3 +3 +next row is 5 +5 diff --git a/mysql-test/main/rownum.test b/mysql-test/main/rownum.test new file mode 100644 index 00000000000..b815d750042 --- /dev/null +++ b/mysql-test/main/rownum.test @@ -0,0 +1,564 @@ +--source include/have_sequence.inc +# +# Test of basic rownum() functionallity +# Test are done with Aria to ensure that row order is stable +# + +CREATE OR REPLACE TABLE t1(a int, b int) engine=aria; +CREATE OR REPLACE TABLE t2(a int, b int) engine=aria; +insert into t1 values (1,10),(2,20),(3,30); +insert into t2 values (2,21),(3,31),(4,41); + +--echo # +--echo # Simple selects +--echo # + +select a,b,rownum() from t1; +select a,b,rownum() from t1 where rownum() < 2; +select a,b from t1 where rownum() <= 2; +select a,b from t1 where rownum() > 2; + +--echo # +--echo # Subqueries +--echo # + +select t1.a,rownum(),t3.a,t3.t2_rownum from t1, (select t2.a,rownum() as t2_rownum from t2 where rownum() <=2) t3; +select t1.a, (select t2.b from t2 where t1.a=t2.a and rownum() <= 1) 'b' from t1; +select t1.a, t3.a from t1, (select * from t2 where rownum() <= 2) t3; +select * from (select tt.*,rownum() as id from (select * from t1) tt) t3 where id>2; + +--echo # +--echo # Joins +--echo # + +select t1.a,t1.b,t2.a,t2.b,rownum() from t1,t2 where rownum() <= 4; +select *,rownum() from t1,t2 where t1.a=t2.a and rownum()<=2; +select * from t1 left join t2 on (t2.a=t1.a and rownum()=0); +select * from t1 left join t2 on (t2.a=t1.a and rownum()>1); +select * from t1 left join t2 on (t2.a=t1.a and rownum()<1); +select * from t1 left join t2 on (t2.a=t1.a and rownum()=1); +select * from t1 left join t2 on (t2.a=t1.a and rownum()>=1); + +--echo # +--echo # Union +--echo # + +select * from t1 where rownum() <=2 union select * from t2 where rownum()<= 1; + +--echo # +--echo # Order by +--echo # + +select * from t1 where rownum() <= 2 order by a desc; +explain select * from t1 where rownum() <= 2 order by a desc; +select t1.a,t1.b,rownum() from t1 where rownum() <= 2 order by a desc; +explain select t1.a,t1.b,rownum() from t1 where rownum() <= 2 order by a desc; +select *,rownum() from t1,t2; +select *,rownum() from t1,t2 order by t2.a desc, t1.a desc; +select * from (select * from t1 order by a desc) as t where rownum() <= 2; +select * from t1,t2 where t1.a=t2.a and rownum()<=2 order by t1.a,t2.a; + +--echo # +--echo # Having +--echo # + +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having r <= 2; +select * from t1 having rownum() <= 2; +select t1.a, sum(t1.b), rownum() from t1 group by t1.a; +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having r <= 2; +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having rownum() <= 2; +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having r <= 2 order by a desc; +select t1.a, sum(t1.b), rownum() as 'r' from t1 group by t1.a having rownum() <= 2 order by a desc; + +--echo # +--echo # Sum functions +--echo # + +select max(rownum()),min(rownum()) from t1; +select sum(rownum()),avg(rownum()) from t1; + +--echo # +--echo # Group by +--echo # + +select t1.a,sum(t1.b) from t1 where rownum() < 2 group by t1.a; +select t1.a,sum(t2.b) from t1 JOIN t2 ON (t1.a=t2.a) where rownum() <= 2 group by t1.a; +select * from (select t1.a,sum(t2.b) from t1 JOIN t2 ON (t1.a=t2.a) group by t1.a) as t where rownum() <= 1; +select t1.a,sum(rownum()),count(*) from t1 where rownum() <= 2 group by t1.a; +select * from (select t1.a,sum(t1.b) from t1 group by t1.a) as t3 where rownum() < 2; + +create table t3 (a int) engine=myisam; +insert into t3 values (3),(5),(5),(3); +select a, max(rownum()) from t3 group by a; +drop table t3; + +CREATE TABLE t3 ( + a int(11) DEFAULT NULL, + b varchar(1024) DEFAULT NULL +); +insert into t3 select mod(seq*3,20)+1, repeat(char(33+mod(seq,90)),mod(seq,10)*100) from seq_1_to_23; +SELECT sq.a,length(sq.f) FROM (SELECT a, GROUP_CONCAT(b,b) AS f FROM t3 GROUP BY a ORDER BY a desc) as sq WHERE ROWNUM() <= 10; +drop table t3; + +--echo # +--echo # Prepared statements +--echo # + +PREPARE stmt1 from "select a,b,rownum() from t1 where rownum() <= 2"; +execute stmt1; +execute stmt1; +deallocate prepare stmt1; + +--echo # +--echo # Views +--echo # + +create view v1 as select t1.a,rownum() from t1; +select * from v1; +select t1.a,v1.* from t1,v1 where t1.a=v1.a; +drop view v1; + +CREATE TABLE t3 (a INT); +INSERT INTO t3 VALUES (1),(2),(3); +CREATE VIEW v1 AS SELECT a FROM t3 WHERE ROWNUM() <= 2; +SELECT * FROM v1; +drop view v1; +drop table t3; + +--echo # +--echo # Reserved words +--echo # + +create table t4 (a int, rownum int); +insert into t4 (a,rownum) values (1,2); +select t4.a,t4.rownum from t4; +drop table t4; + +--echo # +--echo # Test Oracle mode +--echo # + +set SQL_MODE=ORACLE; +select t1.a,rownum from t1 where rownum<=2; +select t1.a,rownum() from t1 where rownum()<=2; +--error ER_PARSE_ERROR +create table t4 (a int, rownum int); + +DELIMITER |; +DECLARE + CURSOR c_cursor + IS select a,b,rownum from t1 where rownum <= 2; + v_a t1.a%TYPE; + v_b t1.b%TYPE; + v_rn t1.a%TYPE; +BEGIN + OPEN c_cursor; + FETCH c_cursor INTO v_a, v_b, v_rn; + WHILE c_cursor%FOUND LOOP + SELECT concat(v_a,'--',v_b,'--',v_rn); + FETCH c_cursor INTO v_a, v_b, v_rn; + END LOOP; + CLOSE c_cursor; +END;| +DELIMITER ;| + +select a, rownum from t1 group by a, rownum having rownum < 3; +select a, rownum as r from t1 group by a, rownum having r < 3; +select a, rownum from t1 group by a, rownum having "rownum" < 3; +select a, rownum from t1 group by a, rownum having rownum < 3 order by a desc; +select a, rownum as r from t1 group by a, rownum having r < 3 order by a desc; +select a, rownum from t1 group by a, rownum having "rownum" < 3 order by a desc; + +set SQL_MODE=DEFAULT; + +--echo # Cleanup + +drop table t1,t2; + +--echo # +--echo # INSERT +--echo # + +create table t1 (a int not null primary key, b int); +insert into t1 values (1,rownum()),(2,rownum()),(3,rownum()); +select * from t1; +drop table t1; + +--echo # +--echo # INSERT DELAYED +--echo # + +create table t1 (a int not null primary key, b int); +insert delayed into t1 values (1,rownum()),(2,rownum()),(3,rownum()); +flush tables; +select * from t1; +drop table t1; + +--echo # +--echo # INSERT IGNORED +--echo # + +create table t1 (a int not null primary key, b int); +# with VALUES +insert ignore into t1 values (1,rownum()),(2,rownum()),(2,rownum()),(3,rownum()); +select * from t1; +delete from t1; +# with SELECT +insert ignore into t1 select * from (values (1,rownum()),(2,rownum()),(2,rownum()),(3,rownum())) t; +select * from t1; +drop table t1; + +--echo # +--echo # INSERT ... RETURNING +--echo # + +create or replace table t1 (a int); +insert into t1 values (1),(2) returning a, rownum(); +drop table t1; + +--echo # +--echo # UPDATE +--echo # + +create table t1 (a int not null primary key, b int); +insert into t1 values (1,1),(2,2),(3,3); +update t1 set b=0; +update t1 set b=rownum()+1; +select * from t1; + +update t1 set b=0; +update t1 set b=rownum() where a < 10 and rownum() < 2; +select * from t1; +drop table t1; + +create table t1 (a int); +insert into t1 values (10),(20),(30); +update t1 set a = rownum(); +select * from t1; +update t1 set a = rownum(); +select * from t1; +drop table t1; + +--echo # +--echo # DELETE +--echo # + +create table t1 (a int not null primary key, b int); +insert into t1 values (1,1),(2,0),(3,0); +delete from t1 where a < 10 and rownum() < 2; +select * from t1; +drop table t1; + +--echo # +--echo # MULTI-TABLE-DELETE +--echo # + +create table t1 (a int not null primary key); +insert into t1 values (1),(2),(3); +create table t2 (a int not null primary key); +insert into t2 values (1),(2),(3); + +delete t1,t2 from t1,t2 where t1.a=t2.a and rownum() <= 2; +select * from t1; +select * from t2; +drop table t1,t2; + +--echo # +--echo # MULTI-TABLE-UPDATE + +CREATE TABLE t1 (ID INT); +CREATE TABLE t2 (ID INT, + s1 TEXT, s2 TEXT, s3 VARCHAR(10), s4 TEXT, s5 VARCHAR(10)); + +INSERT INTO t1 VALUES (1),(2); +INSERT INTO t2 VALUES (1,'test', 'test', 'test', 'test', 'test'), + (2,'test', 'test', 'test', 'test', 'test'); + +SELECT * FROM t1 LEFT JOIN t2 USING(ID); +UPDATE t1 LEFT JOIN t2 USING(ID) SET s1 = 'changed'; +select * from t2; +update t2 set s1=""; +UPDATE t1 LEFT JOIN t2 USING(ID) SET s1 = 'changed' where rownum() <=1; +select * from t2; +drop table t1,t2; + +--echo # +--echo # LOAD DATA +--echo # + +create table t1 (a int, b int, c int); +load data infile '../../std_data/loaddata7.dat' into table t1 fields terminated by ',' lines terminated by "\r\n" (a,b) set c=rownum(); +select * from t1; +drop table t1; + +--echo # +--echo # LIMIT OPTIMIZATION +--echo # + +create table t1 (a int); +insert into t1 select seq from seq_1_to_100; + +flush status; +select * from t1 where rownum() <= 3; +show status like "Rows_read"; +flush status; +select * from t1 where rownum() <= 4 and rownum() <= 3; +show status like "Rows_read"; +flush status; +select * from t1 where rownum() < 4 and a > 10; +show status like "Rows_read"; +flush status; +select * from t1 where 3 >= rownum(); +show status like "Rows_read"; +flush status; +select * from t1 where 4 > rownum() and a > 20; +show status like "Rows_read"; +flush status; +select * from t1 where rownum() = 1 and a > 10; +show status like "Rows_read"; +flush status; +select * from t1 where a > 30 && 1 = rownum(); +show status like "Rows_read"; +flush status; + +--echo # No limit optimization + +select * from t1 where rownum() > 10; +show status like "Rows_read"; +flush status; +select * from t1 where 10 < rownum(); +show status like "Rows_read"; +flush status; +select * from t1 where rownum() >= 10; +show status like "Rows_read"; +flush status; +select * from t1 where 10 < rownum(); +show status like "Rows_read"; +flush status; +select * from t1 where 10 <= rownum(); +show status like "Rows_read"; +flush status; +select * from t1 where 2 = rownum(); +show status like "Rows_read"; +flush status; +select * from t1 where rownum() = 2; +show status like "Rows_read"; +flush status; +select * from t1 where rownum() <= 0; +show status like "Rows_read"; +flush status; +select *,rownum() from t1 where rownum() < 10 limit 4, 4; +show status like "Rows_read"; +flush status; +select * from t1 where rownum() < 10 order by a; +show status like "Rows_read"; +flush status; + + +--echo # rownum and limit + +select * from t1 where rownum() < 4 limit 10; +show status like "Rows_read"; +flush status; +select * from t1 where rownum() < 10 limit 4; +show status like "Rows_read"; + +drop table t1; + +--echo # +--echo # Rownum examples from Woqutech +--echo # + +set SQL_MODE=ORACLE; +create table t1 (c1 int ,c2 varchar(20)) engine=myisam; +insert into t1 values (1, 'aaa'),(2, 'bbb'),(3, 'ccc'),(4, 'ddd'),(5, 'eee'); +update t1 set c2 = 'xxx' where rownum = 2; +select * from t1 where c2='xxx'; +update t1 set c2 = 'xxx' where rownum < 3; +select * from t1 where c2='xxx'; +delete from t1 where rownum = 2; +select count(*) from t1; +delete from t1 where rownum < 3; +select count(*) from t1; +delete from t1 where c1=rownum ; +select count(*) from t1; +delete from t1 where c1=rownum+2 ; +select count(*) from t1; +set SQL_MODE=DEFAULT; +drop table t1; + +--echo # +--echo # Rownum() used in not supported places (returns 0 or gives an error) +--echo # + +set @a=rownum(); +select @a; + +--error ER_GENERATED_COLUMN_FUNCTION_IS_NOT_ALLOWED +create or replace table t (a int, b int as (rownum()) virtual); + +create table t1 (a int); +insert into t1 values (3),(1),(5),(8),(4); +handler t1 open; +--error ER_GENERATED_COLUMN_FUNCTION_IS_NOT_ALLOWED +handler t1 read next where rownum() < 1; +handler t1 close; +drop table t1; + +# rownum() executed in a function will be run in the function context. + +create table t1 (a int not null primary key, b int); +insert into t1 values (1,1),(2,2),(3,3); +create function f() returns int return rownum(); +select a, rownum(), f() from t1; +drop function f; +drop table t1; + +# rownum() executed in a trigger will be run in the function context. + +create or replace table t1 (a int, r int); +create trigger tr before update on t1 for each row set NEW.r = rownum(); +insert into t1 (a) values (1),(2); +select * from t1; +update t1 set a=a+10; +select * from t1; +drop trigger tr; +drop table t1; + +--echo # +--echo # LIMIT optimisation +--echo # + +create table t1 (a int); +insert into t1 values (1),(2),(3),(4),(5); + +let $query= +select * from (select a from t1 where a < 1000) as tt where rownum() <= 2; +flush status; +eval $query; +show status like "Rows_read"; +eval explain extended $query; +eval prepare stmt from "$query"; +flush status; +execute stmt; +show status like "Rows_read"; +flush status; +execute stmt; +show status like "Rows_read"; +deallocate prepare stmt; + + +let $query= +select * from (select a from t1 where a < 1000 group by a) as tt where rownum() <= 2; +flush status; +eval $query; +show status like "Rows_read"; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +let $query= +select * from (select a from t1 where a < 1000 group by a order by 1) as tt where rownum() <= 2; +flush status; +eval $query; +show status like "Rows_read"; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +let $query= +select * from (select a from t1 where a < 1000 union select 10) as tt where rownum() <= 2; +flush status; +eval $query; +show status like "Rows_read"; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +--echo # Other limit + +let $query= +select * from (select a from t1 where a < 1000 group by a order by 1 limit 1) as tt where rownum() <= 2; +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +--echo # Other limit less + +let $query= +select * from (select a from t1 where a < 1000 group by a order by 1 limit 10) as tt where rownum() <= 2; +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +let $query= +select * from (select a from t1 where a < 1000 union select 10 limit 1) as tt where rownum() <= 2; +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +--echo # < rownum + +let $query= +select * from (select a from t1 where a < 1000) as tt where rownum() < 2; +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +--echo # Simple expression + +let $query= +select * from (select a from t1 where a < 1000) as tt where rownum() <= 1+1; +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +--echo # Simple expression reversed + +let $query= +select * from (select a from t1 where a < 1000) as tt where 1+1 >= rownum(); +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +--echo # expensive (no opt) + +let $query= +select * from (select a from t1 where a < 1000) as tt where (select max(a) from t1) >= rownum(); +eval $query; +eval explain extended $query; +eval prepare stmt from "$query"; +execute stmt; +execute stmt; +deallocate prepare stmt; + +drop table t1; + +--echo # +--echo # Table value constructors +--echo # +values ("first row"),("next row is 3"),(rownum()),("next row is 5"),(rownum()); diff --git a/mysql-test/main/show_explain.result b/mysql-test/main/show_explain.result index 6ad93930448..317a12ef311 100644 --- a/mysql-test/main/show_explain.result +++ b/mysql-test/main/show_explain.result @@ -1007,7 +1007,7 @@ SELECT a+SLEEP(0.01) FROM t1 WHERE a IN ( 255, 0 ) OR b BETWEEN 6 AND 129 ORDER BY b; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using filesort +1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using temporary; Using filesort set @show_explain_probe_select_id=1; SET debug_dbug='+d,show_explain_probe_join_exec_start'; SELECT a+SLEEP(0.01) FROM t1 @@ -1016,7 +1016,7 @@ ORDER BY b; connection default; show explain for $thr2; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using filesort +1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using temporary; Using filesort Warnings: Note 1003 SELECT a+SLEEP(0.01) FROM t1 WHERE a IN ( 255, 0 ) OR b BETWEEN 6 AND 129 @@ -1039,7 +1039,7 @@ ORDER BY b; connection default; show explain for $thr2; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using filesort +1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using temporary; Using filesort Warnings: Note 1003 SELECT a+SLEEP(0.01) FROM t1 WHERE a IN ( 255, 0 ) OR b BETWEEN 6 AND 129 diff --git a/mysql-test/main/user_var.result b/mysql-test/main/user_var.result index 7b4c8e0b66e..de339b4b037 100644 --- a/mysql-test/main/user_var.result +++ b/mysql-test/main/user_var.result @@ -368,13 +368,18 @@ select @rownum := @rownum + 1 as row, from t1 order by score desc; drop table t1; create table t1(b bigint); -insert into t1 (b) values (10), (30), (10); +insert into t1 (b) values (10), (30), (10), (10); +set @var := 0; +explain select if(b=@var, 999, b) , @var := b from t1 order by b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using temporary; Using filesort set @var := 0; select if(b=@var, 999, b) , @var := b from t1 order by b; if(b=@var, 999, b) @var := b 10 10 -999 10 +10 10 30 30 +999 10 drop table t1; create temporary table t1 (id int); insert into t1 values (2), (3), (3), (4); diff --git a/mysql-test/main/user_var.test b/mysql-test/main/user_var.test index 54ceb8fd3a5..d7a1cae126c 100644 --- a/mysql-test/main/user_var.test +++ b/mysql-test/main/user_var.test @@ -264,8 +264,11 @@ drop table t1; # create table t1(b bigint); -insert into t1 (b) values (10), (30), (10); +insert into t1 (b) values (10), (30), (10), (10); set @var := 0; +explain select if(b=@var, 999, b) , @var := b from t1 order by b; +set @var := 0; +--sorted_result select if(b=@var, 999, b) , @var := b from t1 order by b; drop table t1; diff --git a/mysql-test/suite/perfschema/r/start_server_low_digest_sql_length.result b/mysql-test/suite/perfschema/r/start_server_low_digest_sql_length.result index eefd4f86708..ba5c0baf79b 100644 --- a/mysql-test/suite/perfschema/r/start_server_low_digest_sql_length.result +++ b/mysql-test/suite/perfschema/r/start_server_low_digest_sql_length.result @@ -8,5 +8,5 @@ SELECT 1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1+1 #################################### SELECT event_name, digest, digest_text, sql_text FROM events_statements_history_long; event_name digest digest_text sql_text -statement/sql/select 5169a25ba78dc5dc99487237f8459aa8 SELECT ? + ? + SELECT ... -statement/sql/truncate 48bb01298bb30bda20be141838160182 TRUNCATE TABLE truncat... +statement/sql/select 62764f94ca18cf720c44d84579e05e60 SELECT ? + ? + SELECT ... +statement/sql/truncate 5947880b8ba439f0ed3ff0bfbb04eebf TRUNCATE TABLE truncat... diff --git a/sql/filesort.cc b/sql/filesort.cc index 3afd30cae30..c9e60aa6434 100644 --- a/sql/filesort.cc +++ b/sql/filesort.cc @@ -93,14 +93,16 @@ static uint32 read_keypart_length(const uchar *from, uint bytes) // @param sortlen [Maximum] length of the sort key void Sort_param::init_for_filesort(uint sortlen, TABLE *table, - ha_rows maxrows, bool sort_positions) + ha_rows maxrows, Filesort *filesort) { DBUG_ASSERT(addon_fields == NULL); sort_length= sortlen; ref_length= table->file->ref_length; + accepted_rows= filesort->accepted_rows; + if (!(table->file->ha_table_flags() & HA_FAST_KEY_READ) && - !table->fulltext_searched && !sort_positions) + !table->fulltext_searched && !filesort->sort_positions) { /* Get the descriptors of all fields whose values are appended @@ -196,16 +198,15 @@ SORT_INFO *filesort(THD *thd, TABLE *table, Filesort *filesort, size_t memory_available= (size_t)thd->variables.sortbuff_size; uint maxbuffer; Merge_chunk *buffpek; - ha_rows num_rows= HA_POS_ERROR; + ha_rows num_rows= HA_POS_ERROR, not_used=0; IO_CACHE tempfile, buffpek_pointers, *outfile; Sort_param param; bool allow_packing_for_sortkeys; Bounded_queue pq; SQL_SELECT *const select= filesort->select; ha_rows max_rows= filesort->limit; - uint s_length= 0; + uint s_length= 0, sort_len; Sort_keys *sort_keys; - DBUG_ENTER("filesort"); if (!(sort_keys= filesort->make_sortorder(thd, join, first_table_bit))) @@ -247,9 +248,10 @@ SORT_INFO *filesort(THD *thd, TABLE *table, Filesort *filesort, sort->found_rows= HA_POS_ERROR; param.sort_keys= sort_keys; - uint sort_len= sortlength(thd, sort_keys, &allow_packing_for_sortkeys); - - param.init_for_filesort(sort_len, table, max_rows, filesort->sort_positions); + sort_len= sortlength(thd, sort_keys, &allow_packing_for_sortkeys); + param.init_for_filesort(sort_len, table, max_rows, filesort); + if (!param.accepted_rows) + param.accepted_rows= ¬_used; param.set_all_read_bits= filesort->set_all_read_bits; param.unpack= filesort->unpack; @@ -971,6 +973,7 @@ static ha_rows find_all_keys(THD *thd, Sort_param *param, SQL_SELECT *select, idx++; } num_records++; + (*param->accepted_rows)++; } /* It does not make sense to read more keys in case of a fatal error */ diff --git a/sql/filesort.h b/sql/filesort.h index 29ae5e20cc6..ebb521e2adc 100644 --- a/sql/filesort.h +++ b/sql/filesort.h @@ -45,23 +45,21 @@ public: ha_rows limit; /** ORDER BY list with some precalculated info for filesort */ SORT_FIELD *sortorder; + /* Used with ROWNUM. Contains the number of rows filesort has found so far */ + ha_rows *accepted_rows; /** select to use for getting records */ SQL_SELECT *select; + /** TRUE <=> free select on destruction */ bool own_select; - /** true means we are using Priority Queue for order by with limit. */ + /** TRUE means we are using Priority Queue for order by with limit. */ bool using_pq; - /* TRUE means sort operation must produce table rowids. FALSE means that it halso has an option of producing {sort_key, addon_fields} pairs. */ bool sort_positions; - - Filesort_tracker *tracker; - Sort_keys *sort_keys; - /* TRUE means all the fields of table of whose bitmap read_set is set need to be read while reading records in the sort buffer. @@ -69,17 +67,24 @@ public: */ bool set_all_read_bits; + Filesort_tracker *tracker; + Sort_keys *sort_keys; + + /* Unpack temp table columns to base table columns*/ + void (*unpack)(TABLE *); + Filesort(ORDER *order_arg, ha_rows limit_arg, bool sort_positions_arg, SQL_SELECT *select_arg): order(order_arg), limit(limit_arg), sortorder(NULL), + accepted_rows(0), select(select_arg), own_select(false), using_pq(false), sort_positions(sort_positions_arg), + set_all_read_bits(false), sort_keys(NULL), - set_all_read_bits(FALSE), unpack(NULL) { DBUG_ASSERT(order); @@ -88,8 +93,6 @@ public: ~Filesort() { cleanup(); } /* Prepare ORDER BY list for sorting. */ Sort_keys* make_sortorder(THD *thd, JOIN *join, table_map first_table_bit); - /* Unpack temp table columns to base table columns*/ - void (*unpack)(TABLE *); private: void cleanup(); diff --git a/sql/item.cc b/sql/item.cc index 1c6074e1916..09578af499f 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -2237,10 +2237,15 @@ void Item::split_sum_func2(THD *thd, Ref_ptr_array ref_pointer_array, return; } } + else if (type() == FUNC_ITEM && + ((Item_func*)this)->functype() == Item_func::ROWNUM_FUNC) + { + } else { /* Not a SUM() function */ - if (unlikely((!with_sum_func() && !(split_flags & SPLIT_SUM_SELECT)))) + if (!with_sum_func() && !with_rownum_func() && + !(split_flags & SPLIT_SUM_SELECT)) { /* This is not a SUM function and there are no SUM functions inside. @@ -9269,7 +9274,7 @@ Item_field::excl_dep_on_grouping_fields(st_select_lex *sel) bool Item_direct_view_ref::excl_dep_on_table(table_map tab_map) { table_map used= used_tables(); - if (used & OUTER_REF_TABLE_BIT) + if (used & (OUTER_REF_TABLE_BIT | RAND_TABLE_BIT)) return false; if (!(used & ~tab_map)) return true; diff --git a/sql/item.h b/sql/item.h index d8991567250..004a56e7371 100644 --- a/sql/item.h +++ b/sql/item.h @@ -761,7 +761,8 @@ enum class item_with_t : item_flags_t WINDOW_FUNC= (1<<1), // If item contains a window func FIELD= (1<<2), // If any item except Item_sum contains a field. SUM_FUNC= (1<<3), // If item contains a sum func - SUBQUERY= (1<<4) // If item containts a sub query + SUBQUERY= (1<<4), // If item containts a sub query + ROWNUM_FUNC= (1<<5) }; @@ -1059,6 +1060,8 @@ public: { return (bool) (with_flags & item_with_t::SUM_FUNC); } inline bool with_subquery() const { return (bool) (with_flags & item_with_t::SUBQUERY); } + inline bool with_rownum_func() const + { return (bool) (with_flags & item_with_t::ROWNUM_FUNC); } inline void copy_flags(const Item *org, item_base_t mask) { base_flags= (item_base_t) (((item_flags_t) base_flags & @@ -1131,7 +1134,7 @@ public: return fix_fields_if_needed_for_scalar(thd, ref); } /* - By default we assume that an Item is fixed by the contstructor. + By default we assume that an Item is fixed by the constructor */ virtual bool fix_fields(THD *, Item **) { @@ -1158,6 +1161,12 @@ public: bool merge) {}; + /* + This is for items that require a fixup after the JOIN::prepare() + is done. + */ + virtual void fix_after_optimize(THD *thd) + {} /* This method should be used in case where we are sure that we do not need complete fix_fields() procedure. @@ -2259,6 +2268,7 @@ public: { return mark_unsupported_function(full_name(), arg, VCOL_IMPOSSIBLE); } + virtual bool check_handler_func_processor(void *arg) { return 0; } virtual bool check_field_expression_processor(void *arg) { return 0; } virtual bool check_func_default_processor(void *arg) { return 0; } /* diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 8b22d437127..d0038c54124 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -5350,7 +5350,7 @@ Item *Item_cond::build_clone(THD *thd) bool Item_cond::excl_dep_on_table(table_map tab_map) { - if (used_tables() & OUTER_REF_TABLE_BIT) + if (used_tables() & (OUTER_REF_TABLE_BIT | RAND_TABLE_BIT)) return false; if (!(used_tables() & ~tab_map)) return true; diff --git a/sql/item_create.cc b/sql/item_create.cc index ff71e36a5d1..d501d327154 100644 --- a/sql/item_create.cc +++ b/sql/item_create.cc @@ -30,6 +30,7 @@ will be resolved later. */ #include "sql_class.h" // set_var.h: THD +#include "sql_parse.h" // sql_command_flags #include "set_var.h" #include "sp_head.h" #include "sp.h" diff --git a/sql/item_func.cc b/sql/item_func.cc index 4b534225224..c31a60304ad 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -7236,3 +7236,77 @@ void Item_func_setval::print(String *str, enum_query_type query_type) str->append_ulonglong(round); str->append(')'); } + + +/* + Return how many row combinations has accepted so far + 1 + + The + 1 is to ensure that, for example, 'WHERE ROWNUM <=1' returns one row +*/ + +longlong Item_func_rownum::val_int() +{ + if (!accepted_rows) + { + /* + Rownum is not properly set up. Probably used in wrong context when + it should not be used. In this case returning 0 is probably the best + solution. + */ + return 0; + } + return (longlong) *accepted_rows+1; +} + + +Item_func_rownum::Item_func_rownum(THD *thd): + Item_longlong_func(thd),accepted_rows(0) +{ + /* + Remember the select context. + Add the function to the list fix_after_optimize in the select context + so that we can easily initializef all rownum functions with the pointers + to the row counters. + */ + select= thd->lex->current_select; + select->fix_after_optimize.push_back(this, thd->mem_root); + + /* + Mark that query is using rownum() and ensure that this select is + not merged with other selects + */ + select->with_rownum= 1; + thd->lex->with_rownum= 1; + thd->lex->uncacheable(UNCACHEABLE_RAND); + with_flags= with_flags | item_with_t::ROWNUM_FUNC; + + /* If this command changes data, mark it as unsafe for statement logging */ + if (sql_command_flags[thd->lex->sql_command] & + (CF_UPDATES_DATA | CF_DELETES_DATA)) + thd->lex->set_stmt_unsafe(LEX::BINLOG_STMT_UNSAFE_SYSTEM_FUNCTION); +} + + +/* + Store a reference to the variable that contains number of accepted rows +*/ + +void Item_func_rownum::fix_after_optimize(THD *thd) +{ + accepted_rows= &select->join->accepted_rows; +} + +/* + Inform all ROWNUM() function where the number of rows are stored +*/ + +void fix_rownum_pointers(THD *thd, SELECT_LEX *select_lex, ha_rows *ptr) +{ + List_iterator li(select_lex->fix_after_optimize); + while (Item *item= li++) + { + if (item->type() == Item::FUNC_ITEM && + ((Item_func*) item)->functype() == Item_func::ROWNUM_FUNC) + ((Item_func_rownum*) item)->store_pointer_to_row_counter(ptr); + } +} diff --git a/sql/item_func.h b/sql/item_func.h index b532a1b1732..560a9fa898e 100644 --- a/sql/item_func.h +++ b/sql/item_func.h @@ -75,9 +75,9 @@ public: SUSERVAR_FUNC, GUSERVAR_FUNC, COLLATE_FUNC, EXTRACT_FUNC, CHAR_TYPECAST_FUNC, FUNC_SP, UDF_FUNC, NEG_FUNC, GSYSVAR_FUNC, IN_OPTIMIZER_FUNC, DYNCOL_FUNC, - JSON_EXTRACT_FUNC, JSON_VALID_FUNC, + JSON_EXTRACT_FUNC, JSON_VALID_FUNC, ROWNUM_FUNC, CASE_SEARCHED_FUNC, // Used by ColumnStore/Spider - CASE_SIMPLE_FUNC // Used by ColumnStore/spider + CASE_SIMPLE_FUNC, // Used by ColumnStore/spider, }; static scalar_comparison_op functype_to_scalar_comparison_op(Functype type) { @@ -326,7 +326,7 @@ public: bool excl_dep_on_table(table_map tab_map) override { - if (used_tables() & OUTER_REF_TABLE_BIT) + if (used_tables() & (OUTER_REF_TABLE_BIT | RAND_TABLE_BIT)) return false; return !(used_tables() & ~tab_map) || Item_args::excl_dep_on_table(tab_map); @@ -2125,6 +2125,61 @@ public: }; +class Item_func_rownum final :public Item_longlong_func +{ + /* + This points to a variable that contains the number of rows + accpted so far in the result set + */ + ha_rows *accepted_rows; + SELECT_LEX *select; +public: + Item_func_rownum(THD *thd); + longlong val_int() override; + LEX_CSTRING func_name_cstring() const override + { + static LEX_CSTRING name= {STRING_WITH_LEN("rownum") }; + return name; + } + enum Functype functype() const override { return ROWNUM_FUNC; } + void update_used_tables() override {} + bool const_item() const override { return 0; } + void fix_after_optimize(THD *thd) override; + bool fix_length_and_dec() override + { + unsigned_flag= 1; + used_tables_cache= RAND_TABLE_BIT; + const_item_cache=0; + set_maybe_null(); + return FALSE; + } + void cleanup() override + { + Item_longlong_func::cleanup(); + /* Ensure we don't point to freed memory */ + accepted_rows= 0; + } + bool check_vcol_func_processor(void *arg) override + { + return mark_unsupported_function(func_name(), "()", arg, + VCOL_IMPOSSIBLE); + } + bool check_handler_func_processor(void *arg) override + { + return mark_unsupported_function(func_name(), "()", arg, + VCOL_IMPOSSIBLE); + } + Item *get_copy(THD *thd) override { return 0; } + /* This function is used in insert, update and delete */ + void store_pointer_to_row_counter(ha_rows *row_counter) + { + accepted_rows= row_counter; + } +}; + +void fix_rownum_pointers(THD *thd, SELECT_LEX *select_lex, ha_rows *ptr); + + class Item_func_sign :public Item_long_func { bool check_arguments() const override diff --git a/sql/lex.h b/sql/lex.h index ba0450f1de9..3357500454a 100644 --- a/sql/lex.h +++ b/sql/lex.h @@ -561,6 +561,7 @@ static SYMBOL symbols[] = { { "ROUTINE", SYM(ROUTINE_SYM)}, { "ROW", SYM(ROW_SYM)}, { "ROWCOUNT", SYM(ROWCOUNT_SYM)}, /* Oracle-N */ + { "ROWNUM", SYM(ROWNUM_SYM)}, /* Oracle-R */ { "ROWS", SYM(ROWS_SYM)}, { "ROWTYPE", SYM(ROWTYPE_MARIADB_SYM)}, { "ROW_COUNT", SYM(ROW_COUNT_SYM)}, diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 1c56f81b12c..5ead22ec746 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7988,3 +7988,5 @@ ER_JSON_TABLE_MULTIPLE_MATCHES eng "Can't store multiple matches of the path in the column '%s' of JSON_TABLE '%s'." ER_WITH_TIES_NEEDS_ORDER eng "FETCH ... WITH TIES requires ORDER BY clause to be present" +ER_FUNCTION_CANNOT_BE_USED_IN_CLAUSE + eng "Function '%s' cannot be used in the %s clause" diff --git a/sql/sql_class.h b/sql/sql_class.h index 8e4aefbbe5b..5a299edbcb8 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -264,10 +264,12 @@ typedef struct st_user_var_events was actually changed or not. */ typedef struct st_copy_info { - ha_rows records; /**< Number of processed records */ - ha_rows deleted; /**< Number of deleted records */ - ha_rows updated; /**< Number of updated records */ - ha_rows copied; /**< Number of copied records */ + ha_rows records; /**< Number of processed records */ + ha_rows deleted; /**< Number of deleted records */ + ha_rows updated; /**< Number of updated records */ + ha_rows copied; /**< Number of copied records */ + ha_rows accepted_rows; /**< Number of accepted original rows + (same as number of rows in RETURNING) */ ha_rows error_count; ha_rows touched; /* Number of touched records */ enum enum_duplicates handle_duplicates; diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index e48ebece0b9..8c83e83f992 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -42,6 +42,7 @@ #include "uniques.h" #include "sql_derived.h" // mysql_handle_derived // end_read_record +#include "sql_insert.h" // fix_rownum_pointers #include "sql_partition.h" // make_used_partitions_str #define MEM_STRIP_BUF_SIZE ((size_t) thd->variables.sortbuff_size) @@ -779,6 +780,8 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, DBUG_ASSERT(table->file->inited != handler::NONE); THD_STAGE_INFO(thd, stage_updating); + fix_rownum_pointers(thd, thd->lex->current_select, &deleted); + while (likely(!(error=info.read_record())) && likely(!thd->killed) && likely(!thd->is_error())) { diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index 1d139f087e1..02633434031 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -673,14 +673,29 @@ static bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) { SELECT_LEX_UNIT *unit= derived->get_unit(); - bool res= FALSE; + SELECT_LEX *first_select; + bool res= FALSE, keep_row_order; DBUG_ENTER("mysql_derived_prepare"); DBUG_PRINT("enter", ("unit: %p table_list: %p alias: '%s'", unit, derived, derived->alias.str)); if (!unit) DBUG_RETURN(FALSE); - SELECT_LEX *first_select= unit->first_select(); + first_select= unit->first_select(); + /* + If rownum() is used we have to preserve the insert row order + to make GROUP BY and ORDER BY with filesort work. + + SELECT * from (SELECT a,b from t1 ORDER BY a)) WHERE rownum <= 0; + + When rownum is not used the optimizer will skip the ORDER BY clause. + With rownum we have to keep the ORDER BY as this is what is expected. + We also have to create any sort result temporary table in such a way + that the inserted row order is maintained. + */ + keep_row_order= (thd->lex->with_rownum && + (first_select->group_list.elements || + first_select->order_list.elements)); if (derived->is_recursive_with_table() && !derived->is_with_table_recursive_reference() && @@ -717,7 +732,8 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) (first_select->options | thd->variables.option_bits | TMP_TABLE_ALL_COLUMNS), - &derived->alias, FALSE, FALSE, FALSE, 0); + &derived->alias, FALSE, FALSE, + keep_row_order, 0); thd->create_tmp_table_for_derived= FALSE; if (likely(!res) && !derived->table) @@ -870,7 +886,7 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) thd->variables.option_bits | TMP_TABLE_ALL_COLUMNS), &derived->alias, - FALSE, FALSE, FALSE, + FALSE, FALSE, keep_row_order, 0)) { thd->create_tmp_table_for_derived= FALSE; diff --git a/sql/sql_handler.cc b/sql/sql_handler.cc index 73bfb8227e1..1a1eead9fdc 100644 --- a/sql/sql_handler.cc +++ b/sql/sql_handler.cc @@ -616,16 +616,28 @@ static SQL_HANDLER *mysql_ha_find_handler(THD *thd, const LEX_CSTRING *name) static bool mysql_ha_fix_cond_and_key(SQL_HANDLER *handler, enum enum_ha_read_modes mode, const char *keyname, - List *key_expr, enum ha_rkey_function ha_rkey_mode, + List *key_expr, + enum ha_rkey_function ha_rkey_mode, Item *cond, bool in_prepare) { THD *thd= handler->thd; TABLE *table= handler->table; if (cond) { + bool ret; + Item::vcol_func_processor_result res; + /* This can only be true for temp tables */ if (table->query_id != thd->query_id) cond->cleanup(); // File was reopened + + ret= cond->walk(&Item::check_handler_func_processor, 0, &res); + if (ret || res.errors) + { + my_error(ER_GENERATED_COLUMN_FUNCTION_IS_NOT_ALLOWED, MYF(0), res.name, + "WHERE", "HANDLER"); + return 1; // ROWNUM() used + } if (cond->fix_fields_if_needed_for_bool(thd, &cond)) return 1; } @@ -1018,7 +1030,8 @@ err0: SQL_HANDLER *mysql_ha_read_prepare(THD *thd, TABLE_LIST *tables, enum enum_ha_read_modes mode, const char *keyname, - List *key_expr, enum ha_rkey_function ha_rkey_mode, + List *key_expr, + enum ha_rkey_function ha_rkey_mode, Item *cond) { SQL_HANDLER *handler; diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index e8722f1a197..52d76950dd0 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -709,7 +709,7 @@ bool mysql_insert(THD *thd, TABLE_LIST *table_list, List_item *values; Name_resolution_context *context; Name_resolution_context_state ctx_state; - SELECT_LEX *returning= thd->lex->has_returning() ? thd->lex->returning() : 0; + SELECT_LEX *returning= thd->lex->has_returning() ? thd->lex->returning() : 0; #ifndef EMBEDDED_LIBRARY char *query= thd->query(); @@ -968,11 +968,16 @@ bool mysql_insert(THD *thd, TABLE_LIST *table_list, */ if (returning && result->send_result_set_metadata(returning->item_list, - Protocol::SEND_NUM_ROWS | Protocol::SEND_EOF)) + Protocol::SEND_NUM_ROWS | + Protocol::SEND_EOF)) goto values_loop_end; THD_STAGE_INFO(thd, stage_update); thd->decide_logging_format_low(table); + fix_rownum_pointers(thd, thd->lex->current_select, &info.accepted_rows); + if (returning) + fix_rownum_pointers(thd, thd->lex->returning(), &info.accepted_rows); + do { DBUG_PRINT("info", ("iteration %llu", iteration)); @@ -1099,6 +1104,7 @@ bool mysql_insert(THD *thd, TABLE_LIST *table_list, error= write_record(thd, table, &info, result); if (unlikely(error)) break; + info.accepted_rows++; thd->get_stmt_da()->inc_current_row_for_warning(); } its.rewind(); @@ -2134,8 +2140,11 @@ ok: autoinc values (generated inside the handler::ha_write()) and values updated in ON DUPLICATE KEY UPDATE. */ - if (sink && sink->send_data(thd->lex->returning()->item_list) < 0) - trg_error= 1; + if (sink) + { + if (sink->send_data(thd->lex->returning()->item_list) < 0) + trg_error= 1; + } after_trg_or_ignored_err: if (key) diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index c347dd06420..2b013b8b88b 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1283,6 +1283,7 @@ void LEX::start(THD *thd_arg) use_only_table_context= 0; escape_used= 0; default_used= 0; + with_rownum= FALSE; is_lex_started= 1; create_info.lex_start(); @@ -2936,6 +2937,7 @@ void st_select_lex::init_query() leaf_tables_prep.empty(); leaf_tables.empty(); item_list.empty(); + fix_after_optimize.empty(); min_max_opt_list.empty(); limit_params.clear(); join= 0; @@ -2948,7 +2950,7 @@ void st_select_lex::init_query() is_item_list_lookup= 0; have_merged_subqueries= 0; is_set_query_expr_tail= 0; - with_sum_func= 0; + with_sum_func= with_rownum= 0; braces= 0; automatic_brackets= 0; having_fix_field= 0; @@ -3960,10 +3962,10 @@ void Query_tables_list::destroy_query_tables_list() */ LEX::LEX() - : explain(NULL), result(0), part_info(NULL), arena_for_set_stmt(0), mem_root_for_set_stmt(0), - json_table(NULL), default_used(0), is_lex_started(0), - option_type(OPT_DEFAULT), context_analysis_only(0), sphead(0), - limit_rows_examined_cnt(ULONGLONG_MAX) + : explain(NULL), result(0), part_info(NULL), arena_for_set_stmt(0), + mem_root_for_set_stmt(0), json_table(NULL), default_used(0), + with_rownum(0), is_lex_started(0), option_type(OPT_DEFAULT), + context_analysis_only(0), sphead(0), limit_rows_examined_cnt(ULONGLONG_MAX) { init_dynamic_array2(PSI_INSTRUMENT_ME, &plugins, sizeof(plugin_ref), @@ -4241,7 +4243,6 @@ void st_select_lex_unit::set_limit(st_select_lex *sl) lim.set_limit(sl->get_limit(), sl->get_offset(), sl->limit_params.with_ties); } - /** Decide if a temporary table is needed for the UNION. diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 4c0bbb0c9e3..27895af80d8 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -1214,7 +1214,8 @@ public: Group_list_ptrs *group_list_ptrs; List item_list; /* list of fields & expressions */ - List pre_fix; /* above list before fix_fields */ + List pre_fix; /* above list before fix_fields */ + List fix_after_optimize; SQL_I_List order_list; /* ORDER clause */ SQL_I_List gorder_list; Lex_select_limit limit_params; /* LIMIT clause parameters */ @@ -1234,6 +1235,7 @@ public: bool have_merged_subqueries:1; bool is_set_query_expr_tail:1; bool with_sum_func:1; /* sum function indicator */ + bool with_rownum:1; /* rownum() function indicator */ bool braces:1; /* SELECT ... UNION (SELECT ... ) <- this braces */ bool automatic_brackets:1; /* dummy select for INTERSECT precedence */ /* TRUE when having fix field called in processing of this SELECT */ @@ -1524,7 +1526,7 @@ public: inline bool is_mergeable() { return (next_select() == 0 && group_list.elements == 0 && - having == 0 && with_sum_func == 0 && + having == 0 && with_sum_func == 0 && with_rownum == 0 && table_list.elements >= 1 && !(options & SELECT_DISTINCT) && limit_params.select_limit == 0); } @@ -1590,7 +1592,7 @@ public: ORDER *find_common_window_func_partition_fields(THD *thd); bool cond_pushdown_is_allowed() const - { return !olap && !limit_params.explicit_limit && !tvc; } + { return !olap && !limit_params.explicit_limit && !tvc && !with_rownum; } bool build_pushable_cond_for_having_pushdown(THD *thd, Item *cond); void pushdown_cond_into_where_clause(THD *thd, Item *extracted_cond, @@ -3376,7 +3378,8 @@ public: bool use_only_table_context:1; bool escape_used:1; bool default_used:1; /* using default() function */ - bool is_lex_started:1; /* If lex_start() did run. For debugging. */ + bool with_rownum:1; /* Using rownum() function */ + bool is_lex_started:1; /* If lex_start() did run. For debugging. */ /* This variable is used in post-parse stage to declare that sum-functions, or functions which have sense only if GROUP BY is present, are allowed. diff --git a/sql/sql_load.cc b/sql/sql_load.cc index 865318e3f05..b144d2afda4 100644 --- a/sql/sql_load.cc +++ b/sql/sql_load.cc @@ -660,6 +660,7 @@ int mysql_load(THD *thd, const sql_exchange *ex, TABLE_LIST *table_list, } table->file->prepare_for_insert(create_lookup_handler); thd_progress_init(thd, 2); + fix_rownum_pointers(thd, thd->lex->current_select, &info.copied); if (table_list->table->validate_default_values_of_unset_fields(thd)) { read_info.error= true; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 62eb66be646..ff4da786bc0 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -311,7 +311,10 @@ bool build_notnull_conds_for_range_scans(JOIN *join, COND *cond, static void build_notnull_conds_for_inner_nest_of_outer_join(JOIN *join, TABLE_LIST *nest_tbl); - +static void fix_items_after_optimize(THD *thd, SELECT_LEX *select_lex); +static void optimize_rownum(THD *thd, SELECT_LEX_UNIT *unit, Item *cond); +static bool process_direct_rownum_comparison(THD *thd, SELECT_LEX_UNIT *unit, + Item *cond); #ifndef DBUG_OFF @@ -363,6 +366,7 @@ bool dbug_user_var_equals_int(THD *thd, const char *name, int value) } #endif /* DBUG_OFF */ + /* Intialize POSITION structure. */ @@ -1196,6 +1200,9 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num, // simple check that we got usable conds dbug_print_item(conds); + /* Fix items that requires the join structure to exist */ + fix_items_after_optimize(thd, select_lex); + if (select_lex->handle_derived(thd->lex, DT_PREPARE)) DBUG_RETURN(-1); @@ -1296,6 +1303,7 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num, &all_fields, &select_lex->pre_fix, 1)) DBUG_RETURN(-1); thd->lex->current_select->context_analysis_place= save_place; + rand_table_in_field_list= select_lex->select_list_tables & RAND_TABLE_BIT; if (setup_without_group(thd, ref_ptrs, tables_list, select_lex->leaf_tables, fields_list, @@ -1462,7 +1470,7 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num, } } - if (having && having->with_sum_func()) + if (having && (having->with_sum_func() || having->with_rownum_func())) having->split_sum_func2(thd, ref_ptrs, all_fields, &having, SPLIT_SUM_SKIP_REGISTERED); if (select_lex->inner_sum_func_list) @@ -1848,7 +1856,6 @@ JOIN::init_range_rowid_filters() DBUG_RETURN(0); } - /** global select optimisation. @@ -1866,12 +1873,18 @@ JOIN::optimize_inner() { DBUG_ENTER("JOIN::optimize_inner"); subq_exit_fl= false; - do_send_rows = (unit->lim.get_select_limit()) ? 1 : 0; DEBUG_SYNC(thd, "before_join_optimize"); - THD_STAGE_INFO(thd, stage_optimizing); + // rownum used somewhere in query, no limits and it is derived + if (unlikely(thd->lex->with_rownum && + select_lex->first_cond_optimization && + select_lex->master_unit()->derived)) + optimize_upper_rownum_func(); + + do_send_rows = (unit->lim.get_select_limit()) ? 1 : 0; + set_allowed_join_cache_types(); need_distinct= TRUE; @@ -1899,7 +1912,12 @@ JOIN::optimize_inner() transform_in_predicates_into_in_subq(thd)) DBUG_RETURN(1); - // Update used tables after all handling derived table procedures + /* + Update used tables after all handling derived table procedures + After this call, select_lex->select_list_tables contains the table + bits of all items in the select list (but not bits from WHERE clause or + other items). + */ select_lex->update_used_tables(); /* @@ -2087,6 +2105,9 @@ JOIN::optimize_inner() DBUG_PRINT("error",("Error from optimize_cond")); DBUG_RETURN(1); } + if (select_lex->with_rownum && ! order && ! group_list && + !select_distinct && conds && select_lex == unit->global_parameters()) + optimize_rownum(thd, unit, conds); having= optimize_cond(this, having, join_list, TRUE, &having_value, &having_equal); @@ -3279,11 +3300,11 @@ bool JOIN::make_aggr_tables_info() JOIN_TAB *curr_tab= join_tab + const_tables; TABLE *exec_tmp_table= NULL; bool distinct= false; - bool keep_row_order= false; + const bool has_group_by= this->group; + bool keep_row_order= thd->lex->with_rownum && (group_list || order); bool is_having_added_as_table_cond= false; DBUG_ENTER("JOIN::make_aggr_tables_info"); - const bool has_group_by= this->group; sort_and_group_aggr_tab= NULL; @@ -3460,7 +3481,7 @@ bool JOIN::make_aggr_tables_info() distinct= select_distinct && !group_list && !select_lex->have_window_funcs(); - keep_row_order= false; + keep_row_order= thd->lex->with_rownum && (group_list || order); bool save_sum_fields= (group_list && simple_group) || implicit_grouping_with_window_funcs; if (create_postjoin_aggr_table(curr_tab, @@ -4208,6 +4229,7 @@ JOIN::reinit() first_record= false; group_sent= false; cleaned= false; + accepted_rows= 0; if (aggr_tables) { @@ -14336,7 +14358,25 @@ static ORDER * remove_const(JOIN *join,ORDER *first_order, COND *cond, bool change_list, bool *simple_order) { - *simple_order= join->rollup.state == ROLLUP::STATE_NONE; + /* + We can't do ORDER BY using filesort if the select list contains a non + deterministic value like RAND() or ROWNUM(). + For example: + SELECT a,ROWNUM() FROM t1 ORDER BY a; + + If we would first sort the table 't1', the ROWNUM() column would be + generated during end_send() and the order would be wrong. + + Previously we had here also a test of ROLLUP: + 'join->rollup.state == ROLLUP::STATE_NONE' + + I deleted this because the ROLLUP was never enforced because of a + bug where the inital value of simple_order was ignored. Having + ROLLUP tested now when the code is fixed, causes many test failure + and some wrong results so better to leave the code as it was + related to ROLLUP. + */ + *simple_order= !join->rand_table_in_field_list; if (join->only_const_tables()) return change_list ? 0 : first_order; // No need to sort @@ -14370,7 +14410,7 @@ remove_const(JOIN *join,ORDER *first_order, COND *cond, tab->cached_eq_ref_table= FALSE; JOIN_TAB *head= join->join_tab + join->const_tables; - *simple_order= head->on_expr_ref[0] == NULL; + *simple_order&= head->on_expr_ref[0] == NULL; if (*simple_order && head->table->file->ha_table_flags() & HA_SLOW_RND_POS) { uint u1, u2, u3, u4; @@ -22086,7 +22126,8 @@ end_send(JOIN *join, JOIN_TAB *join_tab, bool end_of_records) } } - ++join->send_records; + join->send_records++; + join->accepted_rows++; if (join->send_records >= join->unit->lim.get_select_limit()) { if (!join->do_send_rows) @@ -22299,11 +22340,13 @@ end_send_group(JOIN *join, JOIN_TAB *join_tab, bool end_of_records) if (join->procedure) join->procedure->add(); join->group_sent= false; + join->accepted_rows++; DBUG_RETURN(ok_code); } } if (update_sum_func(join->sum_funcs)) DBUG_RETURN(NESTED_LOOP_ERROR); + join->accepted_rows++; if (join->procedure) join->procedure->add(); DBUG_RETURN(NESTED_LOOP_OK); @@ -22328,6 +22371,7 @@ end_write(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)), { int error; join->found_records++; + join->accepted_rows++; if ((error= table->file->ha_write_tmp_row(table->record[0]))) { if (likely(!table->file->is_fatal_error(error, HA_CHECK_DUP))) @@ -22443,6 +22487,7 @@ end_update(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)), } join_tab->send_records++; end: + join->accepted_rows++; // For rownum() if (unlikely(join->thd->check_killed())) { DBUG_RETURN(NESTED_LOOP_KILLED); /* purecov: inspected */ @@ -22471,6 +22516,7 @@ end_unique_update(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)), if (copy_funcs(join_tab->tmp_table_param->items_to_copy, join->thd)) DBUG_RETURN(NESTED_LOOP_ERROR); /* purecov: inspected */ + join->accepted_rows++; if (likely(!(error= table->file->ha_write_tmp_row(table->record[0])))) join_tab->send_records++; // New group else @@ -22514,6 +22560,7 @@ end_unique_update(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)), { DBUG_RETURN(NESTED_LOOP_KILLED); /* purecov: inspected */ } + join->accepted_rows++; // For rownum() DBUG_RETURN(NESTED_LOOP_OK); } @@ -22537,6 +22584,7 @@ end_write_group(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)), int idx= -1; DBUG_ENTER("end_write_group"); + join->accepted_rows++; if (!join->first_record || end_of_records || (idx=test_if_group_changed(join->group_fields)) >= 0) { @@ -24150,6 +24198,7 @@ create_sort_index(THD *thd, JOIN *join, JOIN_TAB *tab, Filesort *fsort) if (table->s->tmp_table) table->file->info(HA_STATUS_VARIABLE); // Get record count + fsort->accepted_rows= &join->accepted_rows; // For ROWNUM file_sort= filesort(thd, table, fsort, fsort->tracker, join, tab->table->map); DBUG_ASSERT(tab->filesort_result == 0); tab->filesort_result= file_sort; @@ -26537,7 +26586,8 @@ int JOIN::rollup_send_data(uint idx) 1 if write_data_failed() */ -int JOIN::rollup_write_data(uint idx, TMP_TABLE_PARAM *tmp_table_param_arg, TABLE *table_arg) +int JOIN::rollup_write_data(uint idx, TMP_TABLE_PARAM *tmp_table_param_arg, + TABLE *table_arg) { uint i; for (i= send_group_parts ; i-- > idx ; ) @@ -29743,6 +29793,224 @@ void unpack_to_base_table_fields(TABLE *table) (*cp->do_copy)(cp); } +/* + Call item->fix_after_optimize for all items registered in + lex->fix_after_optimize + + This is needed for items like ROWNUM(), which needs access to structures + created by the early optimizer pass, like JOIN +*/ + +static void fix_items_after_optimize(THD *thd, SELECT_LEX *select_lex) +{ + List_iterator li(select_lex->fix_after_optimize); + + while (Item *item= li++) + item->fix_after_optimize(thd); +} + + +/* + Set a limit for the SELECT_LEX_UNIT based on ROWNUM usage. + The limit is shown in EXPLAIN +*/ + +static bool set_limit_for_unit(THD *thd, SELECT_LEX_UNIT *unit, ha_rows lim) +{ + SELECT_LEX *gpar= unit->global_parameters(); + if (gpar->limit_params.select_limit != 0 && + // limit can not be an expression but can be parameter + (!gpar->limit_params.select_limit->basic_const_item() || + ((ha_rows)gpar->limit_params.select_limit->val_int()) < lim)) + return false; + + Query_arena *arena, backup; + arena= thd->activate_stmt_arena_if_needed(&backup); + + gpar->limit_params.select_limit= + new (thd->mem_root) Item_int(thd, lim, MAX_BIGINT_WIDTH); + if (gpar->limit_params.select_limit == 0) + return true; // EOM + + unit->set_limit(gpar); + + gpar->limit_params.explicit_limit= true; // to show in EXPLAIN + + if (arena) + thd->restore_active_arena(arena, &backup); + + return false; +} + + +/** + Check possibility of LIMIT setting by rownum() of upper SELECT and do it + + @note Ideal is to convert something like + SELECT ... + FROM (SELECT ...) table + WHERE rownum() < ; + to + SELECT ... + FROM (SELECT ... LIMIT ) table + WHERE rownum() < ; + + @retval true EOM + @retval false no errors +*/ + +bool JOIN::optimize_upper_rownum_func() +{ + DBUG_ASSERT(select_lex->master_unit()->derived); + + if (select_lex->master_unit()->first_select() != select_lex) + return false; // first will set parameter + + if (select_lex->master_unit()->global_parameters()-> + limit_params.offset_limit != NULL) + return false; // offset is set, we cannot set limit + + SELECT_LEX *outer_select= select_lex->master_unit()->outer_select(); + /* + Check that it is safe to use rownum-limit from the outer query + (the one that has 'WHERE rownum()...') + */ + if (outer_select == NULL || + !outer_select->with_rownum || + (outer_select->options & SELECT_DISTINCT) || + outer_select->table_list.elements != 1 || + outer_select->where == NULL || + outer_select->where->type() != Item::FUNC_ITEM) + return false; + + return process_direct_rownum_comparison(thd, unit, outer_select->where); +} + +/** + Test if the predicate compares rownum() with a constant + + @return 1 No or invalid rownum() compare + @return 0 rownum() is compared with a constant. + In this case *args contains the constant and + *inv_order constains 1 if the rownum() was the right + argument, like in 'WHERE 2 >= rownum()'. +*/ + +static bool check_rownum_usage(Item_func *func_item, longlong *limit, + bool *inv_order) +{ + Item *arg1, *arg2; + *inv_order= 0; + DBUG_ASSERT(func_item->argument_count() == 2); + + /* 'rownum op const' or 'const op field' */ + arg1= func_item->arguments()[0]->real_item(); + if (arg1->type() == Item::FUNC_ITEM && + ((Item_func*) arg1)->functype() == Item_func::ROWNUM_FUNC) + { + arg2= func_item->arguments()[1]->real_item(); + if (arg2->can_eval_in_optimize()) + { + *limit= arg2->val_int(); + return *limit <= 0 || (ulonglong) *limit >= HA_POS_ERROR; + } + } + else if (arg1->can_eval_in_optimize()) + { + arg2= func_item->arguments()[1]->real_item(); + if (arg2->type() == Item::FUNC_ITEM && + ((Item_func*) arg2)->functype() == Item_func::ROWNUM_FUNC) + { + *limit= arg1->val_int(); + *inv_order= 1; + return *limit <= 0 || (ulonglong) *limit >= HA_POS_ERROR; + } + } + return 1; +} + + +/* + Limit optimization for ROWNUM() + + Go through the WHERE clause and find out if there are any of the following + constructs on the top level: + rownum() <= integer_constant + rownum() < integer_constant + rownum() = 1 + + If yes, then threat the select as if 'LIMIT integer_constant' would + have been used +*/ + +static void optimize_rownum(THD *thd, SELECT_LEX_UNIT *unit, + Item *cond) +{ + DBUG_ENTER("optimize_rownum"); + + if (cond->type() == Item::COND_ITEM) + { + if (((Item_cond*) cond)->functype() == Item_func::COND_AND_FUNC) + { + List_iterator li(*((Item_cond*) cond)->argument_list()); + Item *item; + while ((item= li++)) + optimize_rownum(thd, unit, item); + } + DBUG_VOID_RETURN; + } + + process_direct_rownum_comparison(thd, unit, cond); + DBUG_VOID_RETURN; +} + + +static bool process_direct_rownum_comparison(THD *thd, SELECT_LEX_UNIT *unit, + Item *cond) +{ + DBUG_ENTER("process_direct_rownum_comparison"); + if (cond->real_type() == Item::FUNC_ITEM) + { + Item_func *pred= (Item_func*) cond; + longlong limit; + bool inv; + + if (pred->argument_count() != 2) + DBUG_RETURN(false); // Not a compare functions + if (check_rownum_usage(pred, &limit, &inv)) + DBUG_RETURN(false); + + Item_func::Functype pred_type= pred->functype(); + + if (inv && pred_type != Item_func::EQ_FUNC) + { + if (pred_type == Item_func::GT_FUNC) // # > rownum() + pred_type= Item_func::LT_FUNC; + else if (pred_type == Item_func::GE_FUNC) // # >= rownum() + pred_type= Item_func::LE_FUNC; + else + DBUG_RETURN(false); + } + switch (pred_type) { + case Item_func::LT_FUNC: // rownum() < # + { + if (limit <= 0) + DBUG_RETURN(false); + DBUG_RETURN(set_limit_for_unit(thd, unit, limit - 1)); + case Item_func::LE_FUNC: + DBUG_RETURN(set_limit_for_unit(thd, unit, limit)); + case Item_func::EQ_FUNC: + if (limit == 1) + DBUG_RETURN(set_limit_for_unit(thd, unit, limit)); + break; + default: + break; + } + } + } + DBUG_RETURN(false); +} + /** diff --git a/sql/sql_select.h b/sql/sql_select.h index 45291541c8d..dbf7209a328 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1238,7 +1238,7 @@ public: table_map outer_join; /* Bitmap of tables used in the select list items */ table_map select_list_used_tables; - ha_rows send_records,found_records,join_examined_rows; + ha_rows send_records,found_records,join_examined_rows, accepted_rows; /* LIMIT for the JOIN operation. When not using aggregation or DISITNCT, this @@ -1398,6 +1398,11 @@ public: GROUP/ORDER BY. */ bool simple_order, simple_group; + /* + Set to 1 if any field in field list has RAND_TABLE set. For example if + if one uses RAND() or ROWNUM() in field list + */ + bool rand_table_in_field_list; /* ordered_index_usage is set if an ordered index access @@ -1557,7 +1562,7 @@ public: first_record= 0; do_send_rows= 1; duplicate_rows= send_records= 0; - found_records= 0; + found_records= accepted_rows= 0; fetch_limit= HA_POS_ERROR; thd= thd_arg; sum_funcs= sum_funcs2= 0; @@ -1573,6 +1578,7 @@ public: no_order= 0; simple_order= 0; simple_group= 0; + rand_table_in_field_list= 0; ordered_index_usage= ordered_index_void; need_distinct= 0; skip_sort_order= 0; @@ -1816,6 +1822,9 @@ public: void make_notnull_conds_for_range_scans(); bool transform_in_predicates_into_in_subq(THD *thd); + + bool optimize_upper_rownum_func(); + private: /** Create a temporary table to be used for processing DISTINCT/ORDER diff --git a/sql/sql_sort.h b/sql/sql_sort.h index 3b23328183c..6c9a81a32c9 100644 --- a/sql/sql_sort.h +++ b/sql/sql_sort.h @@ -558,6 +558,7 @@ public: Bounds_checked_array local_sortorder; Addon_fields *addon_fields; // Descriptors for companion fields. Sort_keys *sort_keys; + ha_rows *accepted_rows; /* For ROWNUM */ bool using_pq; bool set_all_read_bits; @@ -579,7 +580,7 @@ public: tmp_buffer.set_charset(&my_charset_bin); } void init_for_filesort(uint sortlen, TABLE *table, - ha_rows maxrows, bool sort_positions); + ha_rows maxrows, Filesort *filesort); void (*unpack)(TABLE *); /// Enables the packing of addons if possible. diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 52bb1b99be5..49f319b3856 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -434,6 +434,8 @@ bool table_value_constr::exec(SELECT_LEX *sl) DBUG_RETURN(true); } + fix_rownum_pointers(sl->parent_lex->thd, sl, &send_records); + while ((elem= li++)) { if (send_records >= sl->master_unit()->lim.get_select_limit()) diff --git a/sql/sql_union.cc b/sql/sql_union.cc index c76dea02196..f75391c4503 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -1083,8 +1083,9 @@ bool st_select_lex_unit::prepare_join(THD *thd_arg, SELECT_LEX *sl, thd_arg->lex->current_select= sl; - can_skip_order_by= is_union_select && !(sl->braces && - sl->limit_params.explicit_limit); + can_skip_order_by= (is_union_select && !(sl->braces && + sl->limit_params.explicit_limit) && + !thd->lex->with_rownum); saved_error= join->prepare(sl->table_list.first, (derived && derived->merged ? NULL : sl->where), diff --git a/sql/sql_update.cc b/sql/sql_update.cc index 578a05d18ae..80fae87133f 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -383,7 +383,7 @@ int mysql_update(THD *thd, privilege_t want_privilege(NO_ACL); #endif uint table_count= 0; - ha_rows updated, found; + ha_rows updated, updated_or_same, found; key_map old_covering_keys; TABLE *table; SQL_SELECT *select= NULL; @@ -941,7 +941,7 @@ update_begin: if (init_read_record(&info, thd, table, select, file_sort, 0, 1, FALSE)) goto err; - updated= found= 0; + updated= updated_or_same= found= 0; /* Generate an error (in TRADITIONAL mode) or warning when trying to set a NOT NULL field to NULL. @@ -969,7 +969,8 @@ update_begin: } if ((table->file->ha_table_flags() & HA_CAN_FORCE_BULK_UPDATE) && - !table->prepare_triggers_for_update_stmt_or_event()) + !table->prepare_triggers_for_update_stmt_or_event() && + !thd->lex->with_rownum) will_batch= !table->file->start_bulk_update(); /* @@ -993,6 +994,7 @@ update_begin: DBUG_ASSERT(table->file->inited != handler::NONE); THD_STAGE_INFO(thd, stage_updating); + fix_rownum_pointers(thd, thd->lex->current_select, &updated_or_same); while (!(error=info.read_record()) && !thd->killed) { explain->tracker.on_record_read(); @@ -1082,12 +1084,14 @@ update_begin: if (unlikely(record_was_same)) { error= 0; + updated_or_same++; } else if (likely(!error)) { if (has_vers_fields && table->versioned(VERS_TRX_ID)) rows_inserted++; updated++; + updated_or_same++; } if (likely(!error) && !record_was_same && table_list->has_period()) @@ -1106,6 +1110,8 @@ update_begin: goto error; } } + else + updated_or_same++; if (likely(!error) && has_vers_fields && table->versioned(VERS_TIMESTAMP)) { @@ -2930,7 +2936,9 @@ int multi_update::do_updates() } } else + { local_error= 0; + } } if (table->triggers && diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 056f0e02f41..780194c8b85 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -738,6 +738,7 @@ End SQL_MODE_ORACLE_SPECIFIC */ %token PACKAGE_MARIADB_SYM // Oracle-R %token RAISE_MARIADB_SYM // PLSQL-R %token ROWTYPE_MARIADB_SYM // PLSQL-R +%token ROWNUM_SYM /* Oracle-R */ /* Non-reserved keywords @@ -10328,6 +10329,18 @@ function_call_nonkeyword: if (unlikely($$ == NULL)) MYSQL_YYABORT; } + | ROWNUM_SYM +/* Start SQL_MODE_DEFAULT_SPECIFIC */ + '(' ')' +/* End SQL_MODE_DEFAULT_SPECIFIC */ +/* Start SQL_MODE_ORACLE_SPECIFIC + optional_braces +End SQL_MODE_ORACLE_SPECIFIC */ + { + $$= new (thd->mem_root) Item_func_rownum(thd); + if (unlikely($$ == NULL)) + MYSQL_YYABORT; + } | SUBDATE_SYM '(' expr ',' expr ')' { $$= new (thd->mem_root) Item_date_add_interval(thd, $3, $5, @@ -16108,6 +16121,9 @@ keyword_sp_var_and_label: | ROWTYPE_MARIADB_SYM | ROW_COUNT_SYM | ROW_FORMAT_SYM +/* Start SQL_MODE_DEFAULT_SPECIFIC */ + | ROWNUM_SYM +/* End SQL_MODE_DEFAULT_SPECIFIC */ | RTREE_SYM | SCHEDULE_SYM | SCHEMA_NAME_SYM diff --git a/sql/table.cc b/sql/table.cc index 75c156a7c9d..c9420892160 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -9340,6 +9340,10 @@ bool TABLE_LIST::init_derived(THD *thd, bool init_view) { /* A subquery might be forced to be materialized due to a side-effect. */ if (!is_materialized_derived() && first_select->is_mergeable() && + (unit->outer_select() && !unit->outer_select()->with_rownum) && + (!thd->lex->with_rownum || + (!first_select->group_list.elements && + !first_select->order_list.elements)) && optimizer_flag(thd, OPTIMIZER_SWITCH_DERIVED_MERGE) && !thd->lex->can_not_use_merged(1) && !is_recursive_with_table())