Skip to content

Commit

Permalink
MDEV-13695: INTERSECT precedence is not in line with Oracle even in S…
Browse files Browse the repository at this point in the history
…QL_MODE=Oracle

Switch off automatic INTERSECT  priority for ORACLE MODE
  • Loading branch information
sanja-byelkin committed Apr 25, 2018
1 parent 43c5dd0 commit 0544d7c
Show file tree
Hide file tree
Showing 3 changed files with 100 additions and 1 deletion.
60 changes: 60 additions & 0 deletions mysql-test/main/intersect.result
Original file line number Diff line number Diff line change
Expand Up @@ -607,6 +607,22 @@ NULL INTERSECT RESULT <intersect2,4> ALL NULL NULL NULL NULL NULL NULL
NULL UNION RESULT <union1,3,5> ALL NULL NULL NULL NULL NULL NULL
Warnings:
Note 1003 (/* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1`) union /* select#3 */ select `__3`.`c` AS `c`,`__3`.`d` AS `d` from ((/* select#2 */ select `test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d` from `test`.`t2`) intersect (/* select#4 */ select `test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t3`)) `__3` union (/* select#5 */ select 4 AS `4`,4 AS `4`)
set SQL_MODE=ORACLE;
(select a,b from t1) union (select c,d from t2) intersect (select e,f from t3) union (select 4,4);
a b
3 3
4 4
explain extended
(select a,b from t1) union (select c,d from t2) intersect (select e,f from t3) union (select 4,4);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 100.00
2 UNION t2 ALL NULL NULL NULL NULL 2 100.00
3 INTERSECT t3 ALL NULL NULL NULL NULL 2 100.00
4 UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used
NULL UNIT RESULT <unit1,2,3,4> ALL NULL NULL NULL NULL NULL NULL
Warnings:
Note 1003 (/* select#1 */ select "test"."t1"."a" AS "a","test"."t1"."b" AS "b" from "test"."t1") union (/* select#2 */ select "test"."t2"."c" AS "c","test"."t2"."d" AS "d" from "test"."t2") intersect (/* select#3 */ select "test"."t3"."e" AS "e","test"."t3"."f" AS "f" from "test"."t3") union (/* select#4 */ select 4 AS "4",4 AS "4")
set SQL_MODE=default;
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
e f
3 3
Expand All @@ -623,6 +639,24 @@ id select_type table type possible_keys key key_len ref rows filtered Extra
NULL UNIT RESULT <unit1,2,3,4> ALL NULL NULL NULL NULL NULL NULL
Warnings:
Note 1003 (/* select#1 */ select `test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t3`) intersect (/* select#2 */ select `test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d` from `test`.`t2`) union (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1`) union (/* select#4 */ select 4 AS `4`,4 AS `4`)
set SQL_MODE=ORACLE;
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
e f
3 3
4 4
5 5
6 6
explain extended
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t3 ALL NULL NULL NULL NULL 2 100.00
2 INTERSECT t2 ALL NULL NULL NULL NULL 2 100.00
3 UNION t1 ALL NULL NULL NULL NULL 2 100.00
4 UNION NULL NULL NULL NULL NULL NULL NULL NULL No tables used
NULL UNIT RESULT <unit1,2,3,4> ALL NULL NULL NULL NULL NULL NULL
Warnings:
Note 1003 (/* select#1 */ select "test"."t3"."e" AS "e","test"."t3"."f" AS "f" from "test"."t3") intersect (/* select#2 */ select "test"."t2"."c" AS "c","test"."t2"."d" AS "d" from "test"."t2") union (/* select#3 */ select "test"."t1"."a" AS "a","test"."t1"."b" AS "b" from "test"."t1") union (/* select#4 */ select 4 AS "4",4 AS "4")
set SQL_MODE=default;
(/* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1`) union /* select#3 */ select `__3`.`c` AS `c`,`__3`.`d` AS `d` from ((/* select#2 */ select `test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d` from `test`.`t2`) intersect (/* select#4 */ select `test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t3`)) `__3` union (/* select#5 */ select 4 AS `4`,4 AS `4`);
a b
3 3
Expand Down Expand Up @@ -772,4 +806,30 @@ SELECT * FROM t1 LEFT OUTER JOIN t2 LEFT OUTER JOIN t3 ON b < c ON a > b
count(*)
14848
drop table t1,t2,t3;
#
# MDEV-13695: INTERSECT precedence is not in line with Oracle even
# in SQL_MODE=Oracle
#
create table t12(c1 int);
insert into t12 values(1);
insert into t12 values(2);
create table t13(c1 int);
insert into t13 values(1);
insert into t13 values(3);
create table t234(c1 int);
insert into t234 values(2);
insert into t234 values(3);
insert into t234 values(4);
set SQL_MODE=oracle;
select * from t13 union select * from t234 intersect select * from t12;
c1
1
2
set SQL_MODE=default;
select * from t13 union select * from t234 intersect select * from t12;
c1
1
2
3
drop table t12,t13,t234;
# End of 10.3 tests
38 changes: 38 additions & 0 deletions mysql-test/main/intersect.test
Original file line number Diff line number Diff line change
Expand Up @@ -147,12 +147,25 @@ insert into t3 values (1,1),(3,3);
(select a,b from t1) union (select c,d from t2) intersect (select e,f from t3) union (select 4,4);
explain extended
(select a,b from t1) union (select c,d from t2) intersect (select e,f from t3) union (select 4,4);
set SQL_MODE=ORACLE;
--sorted_result
(select a,b from t1) union (select c,d from t2) intersect (select e,f from t3) union (select 4,4);
explain extended
(select a,b from t1) union (select c,d from t2) intersect (select e,f from t3) union (select 4,4);
set SQL_MODE=default;


# test result of linear mix operation
--sorted_result
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
explain extended
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
set SQL_MODE=ORACLE;
--sorted_result
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
explain extended
(select e,f from t3) intersect (select c,d from t2) union (select a,b from t1) union (select 4,4);
set SQL_MODE=default;

--sorted_result
(/* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1`) union /* select#3 */ select `__3`.`c` AS `c`,`__3`.`d` AS `d` from ((/* select#2 */ select `test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d` from `test`.`t2`) intersect (/* select#4 */ select `test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t3`)) `__3` union (/* select#5 */ select 4 AS `4`,4 AS `4`);
Expand Down Expand Up @@ -282,4 +295,29 @@ select count(*) from (

drop table t1,t2,t3;

--echo #
--echo # MDEV-13695: INTERSECT precedence is not in line with Oracle even
--echo # in SQL_MODE=Oracle
--echo #

create table t12(c1 int);
insert into t12 values(1);
insert into t12 values(2);
create table t13(c1 int);
insert into t13 values(1);
insert into t13 values(3);
create table t234(c1 int);
insert into t234 values(2);
insert into t234 values(3);
insert into t234 values(4);

set SQL_MODE=oracle;
--sorted_result
select * from t13 union select * from t234 intersect select * from t12;
set SQL_MODE=default;
--sorted_result
select * from t13 union select * from t234 intersect select * from t12;

drop table t12,t13,t234;

--echo # End of 10.3 tests
3 changes: 2 additions & 1 deletion sql/sql_yacc.yy
Original file line number Diff line number Diff line change
Expand Up @@ -546,7 +546,8 @@ bool LEX::add_select_to_union_list(bool is_union_distinct,
as possible */
if (type == INTERSECT_TYPE &&
(current_select->linkage != INTERSECT_TYPE &&
current_select != current_select->master_unit()->first_select()))
current_select != current_select->master_unit()->first_select())
&& !(thd->variables.sql_mode & MODE_ORACLE))
{
/*
This and previous SELECTs should go one level down because of
Expand Down

0 comments on commit 0544d7c

Please sign in to comment.