diff --git a/libmysqld/CMakeLists.txt b/libmysqld/CMakeLists.txt index 4a20801761d..58e5dbcb0d3 100644 --- a/libmysqld/CMakeLists.txt +++ b/libmysqld/CMakeLists.txt @@ -92,6 +92,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc ../sql/sql_lex.cc ../sql/keycaches.cc ../sql/sql_list.cc ../sql/sql_load.cc ../sql/sql_locale.cc ../sql/sql_binlog.cc ../sql/sql_manager.cc + ../sql/sql_oracle_outer_join.cc ../sql/sql_parse.cc ../sql/sql_bootstrap.cc ../sql/sql_partition.cc ../sql/sql_plugin.cc ../sql/debug_sync.cc ../sql/debug.cc diff --git a/mysql-test/suite/compat/oracle/r/ora_outer_join.result b/mysql-test/suite/compat/oracle/r/ora_outer_join.result new file mode 100644 index 00000000000..b2cc2233b05 --- /dev/null +++ b/mysql-test/suite/compat/oracle/r/ora_outer_join.result @@ -0,0 +1,951 @@ +set SQL_MODE= oracle; +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create table t3 (c int, e int); +insert into t3 values (3,2),(10,3),(2,20); +create table t4 (d int); +insert into t4 values (3),(1),(20); +select t1.a, t4.d, t2.b, t3.c +from t1, t2, t3, t4 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +a d b c +3 3 NULL 3 +1 1 1 NULL +1 3 NULL NULL +2 3 NULL NULL +2 1 NULL NULL +3 1 NULL NULL +1 20 NULL NULL +2 20 NULL NULL +3 20 NULL NULL +explain extended +select t1.a, t4.d, t2.b, t3.c +from t1, t2, t3, t4 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t4 ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t4"."d" AS "d","test"."t2"."b" AS "b","test"."t3"."c" AS "c" from "test"."t1" join "test"."t4" left join "test"."t2" on("test"."t4"."d" = "test"."t1"."a" and "test"."t2"."b" = "test"."t1"."a") left join "test"."t3" on("test"."t4"."d" = "test"."t1"."a" and "test"."t3"."c" = "test"."t1"."a") where 1 +select t1.a, t4.d, t2.b, t3.c +from t4, t3, t2, t1 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +a d b c +1 1 1 NULL +3 3 NULL 3 +1 3 NULL NULL +1 20 NULL NULL +2 3 NULL NULL +2 1 NULL NULL +2 20 NULL NULL +3 1 NULL NULL +3 20 NULL NULL +explain extended +select t1.a, t4.d, t2.b, t3.c +from t4, t3, t2, t1 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t4"."d" AS "d","test"."t2"."b" AS "b","test"."t3"."c" AS "c" from "test"."t4" join "test"."t1" left join "test"."t3" on("test"."t1"."a" = "test"."t4"."d" and "test"."t3"."c" = "test"."t4"."d") left join "test"."t2" on("test"."t1"."a" = "test"."t4"."d" and "test"."t2"."b" = "test"."t4"."d") where 1 +select t1.a, t4.d, t2.b, t3.c +from t2, t1, t4, t3 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +a d b c +3 3 NULL 3 +1 1 1 NULL +1 3 NULL NULL +2 3 NULL NULL +2 1 NULL NULL +3 1 NULL NULL +1 20 NULL NULL +2 20 NULL NULL +3 20 NULL NULL +explain extended +select t1.a, t4.d, t2.b, t3.c +from t2, t1, t4, t3 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t4 ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t4"."d" AS "d","test"."t2"."b" AS "b","test"."t3"."c" AS "c" from "test"."t1" join "test"."t4" left join "test"."t2" on("test"."t4"."d" = "test"."t1"."a" and "test"."t2"."b" = "test"."t1"."a") left join "test"."t3" on("test"."t4"."d" = "test"."t1"."a" and "test"."t3"."c" = "test"."t1"."a") where 1 +select t1.a, t4.d, t2.b, t3.c +from t3, t4, t1, t2 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +a d b c +1 1 1 NULL +3 3 NULL 3 +1 3 NULL NULL +1 20 NULL NULL +2 3 NULL NULL +2 1 NULL NULL +2 20 NULL NULL +3 1 NULL NULL +3 20 NULL NULL +explain extended +select t1.a, t4.d, t2.b, t3.c +from t3, t4, t1, t2 +where +t1.a = t2.b(+) and +t1.a = t3.c(+) and +t4.d = t2.b(+) and +t4.d = t3.c(+); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t4 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (incremental, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t4"."d" AS "d","test"."t2"."b" AS "b","test"."t3"."c" AS "c" from "test"."t4" join "test"."t1" left join "test"."t3" on("test"."t1"."a" = "test"."t4"."d" and "test"."t3"."c" = "test"."t4"."d") left join "test"."t2" on("test"."t1"."a" = "test"."t4"."d" and "test"."t2"."b" = "test"."t4"."d") where 1 +drop table t1, t2, t3, t4; +# +# tests of Iqbal Hassan +# (with 2 fixes) +# +CREATE TABLE tj1(a int, b int); +CREATE TABLE tj2(c int, d int); +CREATE TABLE tj3(e int, f int); +CREATE TABLE tj4(b int, c int); +INSERT INTO tj1 VALUES (1, 1); +INSERT INTO tj1 VALUES (2, 2); +INSERT INTO tj2 VALUES (2, 3); +INSERT INTO tj3 VALUES (1, 4); +# +# Basic test +# +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+); +a b c d +2 2 2 3 +1 1 NULL NULL +# +# Compare marked with literal +# +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND tj2.d(+) > 4; +a b c d +1 1 NULL NULL +2 2 NULL NULL +explain extended +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND tj2.d(+) > 4; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE tj1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE tj2 ALL NULL NULL NULL NULL 1 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."tj1"."a" AS "a","test"."tj1"."b" AS "b","test"."tj2"."c" AS "c","test"."tj2"."d" AS "d" from "test"."tj1" left join "test"."tj2" on("test"."tj2"."c" = "test"."tj1"."a" and "test"."tj2"."d" > 4) where 1 +# +# Use both marked and unmarked field in the same condition +# +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND tj2.d = 3; +a b c d +2 2 2 3 +# +# Use both marked and unmarked field in OR condition +# +SELECT * FROM tj2,tj1 WHERE tj1.a = tj2.c(+) OR tj2.d=4; +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj3.e(+) AND (tj1.a = tj2.c(+) OR tj2.d=4); +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +# +# Use unmarked fields in OR condition +# +SELECT * FROM tj2,tj1 WHERE tj1.a = tj2.c(+) AND (tj2.d=3 OR tj2.d * 2=3); +c d a b +2 3 2 2 +# +# Use marked fields in OR condition when all fields are marked +# +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND (tj2.d(+)=3 OR tj2.c(+)=1); +a b c d +2 2 2 3 +1 1 NULL NULL +# +# Use more than one marked table per condition +# +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) + tj3.e(+); +ERROR HY000: Invalid usage of (+) operator: both tables tj2 and tj3 are of INNER type in the relation +# +# Use different tables per `AND` operand +# +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj1.a = tj3.e(+); +a b c d e f +1 1 NULL NULL 1 4 +2 2 2 3 NULL NULL +# +# Ensure table dependencies are properly resolved +# +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj3.e AND tj1.a + 1 = tj2.c(+); +a b c d e f +1 1 2 3 1 4 +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj2.c = tj3.e(+) + 1; +a b c d e f +2 2 2 3 1 4 +1 1 NULL NULL NULL NULL +SELECT * FROM tj1, tj2, tj3 WHERE tj1.a + tj3.e = tj2.c(+); +a b c d e f +1 1 2 3 1 4 +2 2 NULL NULL 1 4 +# +# Cyclic dependency of tables +# ORA-01416 two tables cannot be outer-joined to each other +# +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj2.c = tj3.e(+) + 1 AND tj3.e = tj1.a(+); +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +# +# Table not referenced in where condition (must be cross-joined) +# +SELECT * FROM tj1, tj2, tj3 WHERE tj1.a + 1 = tj2.c(+); +a b c d e f +1 1 2 3 1 4 +2 2 NULL NULL 1 4 +# +# Alias +# +SELECT * FROM tj1, tj2 b WHERE tj1.a + 1 = b.c(+); +a b c d +1 1 2 3 +2 2 NULL NULL +# +# Subselect +# +SELECT * FROM tj1, (SELECT * from tj2) b WHERE tj1.a + 1 = b.c(+); +a b c d +1 1 2 3 +2 2 NULL NULL +SELECT * FROM tj1, (SELECT * FROM tj1, tj2 d WHERE tj1.a = d.c(+)) b WHERE tj1.a + 1 = b.c(+); +a b a b c d +1 1 2 2 2 3 +2 2 NULL NULL NULL NULL +# +# Single table +# +SELECT * FROM tj1 WHERE tj1.a(+) = 1; +a b +1 1 +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '"test"."tj1"."a" = 1' +# +# Self outer join +# +SELECT * FROM tj1 a, tj1 b WHERE a.a + 1 = b.a(+); +a b a b +1 1 2 2 +2 2 NULL NULL +# +# Self outer join without alias +# +SELECT * FROM tj1, tj2 WHERE tj1.a + 1 = tj1.a(+); +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +# +# Outer join condition is independent of other tables +# In this case we need to restrict the marked table(s) to appear +# after the unmarked table(s) during topological sort. This test +# ensures that the topological sort is working correctly. +# +# correct result in is empty result set (tj2.c = 1 filters all out) +SELECT * FROM tj1, tj2 WHERE tj2.c(+) = 1; +a b c d +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '"test"."tj2"."c" = 1' +# one row (there is tj1.a = 1) +SELECT * FROM tj1, tj2 WHERE tj1.a(+) = 1; +a b c d +1 1 2 3 +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '"test"."tj1"."a" = 1' +# +# Outer join in 'IN' condition +# ORA-01719 +# +SELECT * FROM tj1, tj2 WHERE tj1.a IN (tj2.c(+), tj2.d(+)); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +SELECT * FROM tj1, tj2 WHERE tj1.a NOT IN (tj2.c(+), tj2.d(+)); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +# +# Outer join in 'IN' condition with a single expression +# This is also allowed in oracle since the expression is +# can be simplified to 'equal' or 'not equal' condition +# +SELECT * FROM tj1, tj2 WHERE tj1.a IN (tj2.c(+)); +a b c d +2 2 2 3 +1 1 NULL NULL +SELECT * FROM tj1, tj2 WHERE tj1.a NOT IN (tj2.c(+)); +a b c d +1 1 2 3 +2 2 NULL NULL +# +# Oracle outer join not in WHERE clause +# +SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c GROUP BY tj2.c(+); +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 ')' at line 1 +SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c GROUP BY tj2.c HAVING tj2.c(+) > 1; +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 ') > 1' at line 1 +SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c ORDER BY tj2.c(+); +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 ')' at line 1 +SELECT tj2.c(+) FROM tj2; +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 ') FROM tj2' at line 1 +# +# Mix ANSI and Oracle outer join +# ORA-25156 +SELECT * FROM tj1 LEFT JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +SELECT * FROM tj1 INNER JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +SELECT * FROM tj1 NATURAL JOIN tj2 WHERE tj1.a = tj2.c(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +# +# View with oracle outer join +# +CREATE VIEW v1 AS SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c(+); +SELECT * FROM v1; +a b c d +2 2 2 3 +1 1 NULL NULL +# +# Cursor with oracle outer join +# +DECLARE +CURSOR c1 IS SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c(+); +BEGIN +FOR r1 IN c1 LOOP +SELECT r1.a || ' ' || r1.c; +END LOOP; +END +$$ +r1.a || ' ' || r1.c +2 2 +r1.a || ' ' || r1.c +1 +# +# Marking ROW type +# +DECLARE +v1 ROW (a INT, b INT); +BEGIN +SELECT * FROM tj1 WHERE tj1.a = v1.a(+); +END +$$ +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 '); +END' at line 4 +# +# Unspecified table used in WHERE clause that contains (+) +# +SELECT * FROM tj1, tj2 WHERE tj1.a = tj3.c(+); +ERROR 42S22: Unknown column 'tj3.c' in 'WHERE' +# +# '.' prefixed table name +# +SELECT * FROM tj1, tj2 WHERE tj1.a = .tj2.c(+); +a b c d +2 2 2 3 +1 1 NULL NULL +CREATE DATABASE db1; +USE db1; +CREATE TABLE tj1(a int, b int); +INSERT INTO tj1 VALUES (3, 3); +INSERT INTO tj1 VALUES (4, 4); +# +# DB qualifed ident with oracle outer join (aliased) +# +SELECT * FROM test.tj2 a, tj1 WHERE a.c(+) = tj1.a - 1; +c d a b +2 3 3 3 +NULL NULL 4 4 +# +# DB qualifed ident with oracle outer join (non-aliased) +# +SELECT * FROM test.tj2, tj1 WHERE test.tj2.c(+) = tj1.a - 1; +c d a b +2 3 3 3 +NULL NULL 4 4 +# +# DB qualifed ident with oracle outer join (aliased but use table name) +# +SELECT * FROM test.tj2 a, tj1 WHERE test.tj2.c(+) = tj1.a - 1; +ERROR 42S22: Unknown column 'test.tj2.c' in 'WHERE' +USE test; +# +# UPDATE with oracle outer join +# +UPDATE tj1, tj2 SET tj1.a = tj2.c WHERE tj1.a = tj2.c(+); +SELECT * FROM tj1; +a b +NULL 1 +2 2 +# +# DELETE with oracle outer join +# +DELETE tj1 FROM tj1, tj2 WHERE tj1.b(+) = tj2.c; +SELECT * FROM tj1; +a b +NULL 1 +DROP DATABASE db1; +DROP VIEW v1; +DROP TABLE tj4; +DROP TABLE tj3; +DROP TABLE tj2; +DROP TABLE tj1; +# +# End of iqbal-rsec tests +# +# +# Test from the MDEV comments +# +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create table t3 (c int, e int); +insert into t3 values (3,2),(10,3),(2,20); +create table t4 (d int); +insert into t4 values (3),(1),(20); +select t1.a, t4.d, t2.b, t3.c from t1, t2, t3, t4 where t1.a = t2.b(+) and t1.a = t3.c(+) and t4.d = t2.b(+) and t4.d = t3.c(+); +a d b c +3 3 NULL 3 +1 1 1 NULL +1 3 NULL NULL +2 3 NULL NULL +2 1 NULL NULL +3 1 NULL NULL +1 20 NULL NULL +2 20 NULL NULL +3 20 NULL NULL +select t1.a, t4.d, t2.b, t3.c from t1, t2, t3, t4 where t1.a + t3.c = t2.b(+) and t1.a = t3.c(+) and t4.d = t2.b(+) and t4.d = t3.c(+); +a d b c +3 3 NULL 3 +1 3 NULL NULL +2 3 NULL NULL +1 1 NULL NULL +2 1 NULL NULL +3 1 NULL NULL +1 20 NULL NULL +2 20 NULL NULL +3 20 NULL NULL +select t1.a, t4.d, t2.b, t3.c from t1, t2, t3, t4 where (t2.b(+) in (t1.a, t1.a+1)) and t1.a = t3.c(+) and t4.d = t2.b(+) and t4.d = t3.c(+); +a d b c +3 3 NULL 3 +1 1 1 NULL +1 3 NULL NULL +2 3 NULL NULL +2 1 NULL NULL +3 1 NULL NULL +1 20 NULL NULL +2 20 NULL NULL +3 20 NULL NULL +drop tables t1, t2, t3, t4; +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create table t3 (c int, f int); +insert into t3 values (3,2),(10,3),(2,20); +create table t4 (d int); +insert into t4 values (3),(1),(20); +create table t5 (e int); +insert into t5 values (3),(2),(20); +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, t2, t3, t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and t3.c=t5.e(+); +a b c d e +2 2 2 NULL NULL +3 NULL NULL 3 NULL +1 1 NULL 1 NULL +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, t2, t3, t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and 1=t5.e(+); +a b c d e +3 NULL NULL 3 NULL +1 1 NULL 1 NULL +2 2 2 NULL NULL +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, t2, t3, t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and 3=t5.e(+); +a b c d e +3 NULL NULL 3 3 +1 1 NULL 1 NULL +2 2 2 NULL NULL +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, (t2, t3), t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and 3=t5.e(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +drop tables t1, t2, t3, t4, t5; +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +select t1.a, t2.b from t1, t2 where 1 = t2.b(+); +a b +1 1 +2 1 +3 1 +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '1 = "test"."t2"."b"' +select t1.a, t2.b from t2, t1 where 1 = t2.b(+); +a b +1 1 +2 1 +3 1 +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '1 = "test"."t2"."b"' +select t1.a,t2.b from t2,t1 where t2.b(+) in (1,2); +a b +1 2 +1 1 +2 2 +2 1 +3 2 +3 1 +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '"test"."t2"."b" in (1,2)' +select t2.b from t2 where 1 = t2.b(+); +b +1 +Warnings: +Warning 4237 Oracle outer join operator (+) ignored in '1 = "test"."t2"."b"' +drop tables t1, t2; +create table t1 (a int); +insert into t1 values (1),(2),(4),(5),(20),(21),(23); +create table t2 (b int); +insert into t2 values (1),(4),(6),(7),(8),(23); +create table t3 (c int); +insert into t3 values (4),(7),(9),(4),(6),(10),(11),(1); +create table t4 (d int); +insert into t4 values (1),(4),(10),(12),(20),(21),(23); +SELECT * FROM t1,t2,t3,t4 WHERE t1.a = t2.b(+) AND t1.a = t3.c(+) AND t2.b=t4.d(+) AND t3.c=t4.d(+); +a b c d +1 1 1 1 +4 4 4 4 +4 4 4 4 +23 23 NULL NULL +2 NULL NULL NULL +5 NULL NULL NULL +20 NULL NULL NULL +21 NULL NULL NULL +select * from t1, t2, t3 where (t1.a + t2.b = t3.c(+)); +a b c +1 6 7 +1 8 9 +2 7 9 +5 4 9 +2 4 6 +5 1 6 +2 8 10 +4 6 10 +4 7 11 +5 6 11 +1 1 NULL +1 4 NULL +1 7 NULL +1 23 NULL +2 1 NULL +2 6 NULL +2 23 NULL +4 1 NULL +4 4 NULL +4 8 NULL +4 23 NULL +5 7 NULL +5 8 NULL +5 23 NULL +20 1 NULL +20 4 NULL +20 6 NULL +20 7 NULL +20 8 NULL +20 23 NULL +21 1 NULL +21 4 NULL +21 6 NULL +21 7 NULL +21 8 NULL +21 23 NULL +23 1 NULL +23 4 NULL +23 6 NULL +23 7 NULL +23 8 NULL +23 23 NULL +# no tables mentioned +select * from t2, t3 where b = c(+); +b c +4 4 +7 7 +4 4 +6 6 +1 1 +8 NULL +23 NULL +# should be the same as above +select * from t2, t3 where t2.b = t3.c(+); +b c +4 4 +7 7 +4 4 +6 6 +1 1 +8 NULL +23 NULL +drop tables t1, t2, t3, t4; +# +# View creation and usage +# +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create view v1 as +select t1.a, t2.b from t1, t2 where t1.a = t2.b(+); +show create view v1; +View Create View character_set_client collation_connection +v1 CREATE VIEW "v1" AS select "t1"."a" AS "a","t2"."b" AS "b" from ("t1" left join "t2" on("t1"."a" = "t2"."b")) latin1 latin1_swedish_ci +select * from v1; +a b +2 2 +1 1 +3 NULL +select t1.a, t2.b from t1, t2 where t1.a = t2.b(+); +a b +2 2 +1 1 +3 NULL +usage without oracle sql mode +set SQL_MODE= ''; +select * from v1; +a b +2 2 +1 1 +3 NULL +select t1.a, t2.b from t1, t2 where t1.a = t2.b(+); +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 ')' at line 1 +set SQL_MODE= oracle; +drop view v1; +drop table t1,t2; +# +# MDEV-36830: Oracle outer join syntax (+): outer join not converted to inner +# +create table t1 ( +a int not null, +b int not null +); +insert into t1 select seq,seq from seq_1_to_10; +create table t2 ( +a int not null, +b int not null +); +insert into t2 select seq,seq from seq_1_to_3; +# Must be converted to inner join: +explain extended +select * from t1, t2 +where +t1.a=1 and +t1.b=t2.b(+) and +t2.b=1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where +1 SIMPLE t1 ALL NULL NULL NULL NULL 10 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."b" AS "b","test"."t2"."a" AS "a","test"."t2"."b" AS "b" from "test"."t1" join "test"."t2" where "test"."t1"."a" = 1 and "test"."t2"."b" = 1 and "test"."t1"."b" = 1 +drop table t1,t2; +# +# MDEV-36838: Oracle outer join syntax (+): server crash on derived tables +# +select a.a +from (select 1 as a) a, +(select 2 as b) b +where a.a=b.b(+); +a +1 +# +# MDEV-36866: Oracle outer join syntax (+): query with checking for +# null of non-null column uses wrong query plan and returns wrong +# result +# +create table t1 (a int default NULL); +create table t2 (a int not null); +insert into t1 values (1), (2), (3), (4), (5), (6), (NULL); +insert into t2 values (1), (4), (5), (6), (7); +select t1.*,t2.* from t1,t2 where t1.a=t2.a and isnull(t2.a)=1; +a a +explain select t1.*,t2.* from t1,t2 where t1.a=t2.a and isnull(t2.a)=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select t1.*,t2.* from t1 left join t2 on t1.a=t2.a where isnull(t2.a)=1; +a a +2 NULL +3 NULL +NULL NULL +explain select t1.*,t2.* from t1 left join t2 on t1.a=t2.a where isnull(t2.a)=1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 7 +1 SIMPLE t2 ALL NULL NULL NULL NULL 5 Using where; Using join buffer (flat, BNL join) +select t1.*,t2.* from t1,t2 where t1.a=t2.a(+) and isnull(t2.a)=1; +a a +2 NULL +3 NULL +NULL NULL +explain extended select t1.*,t2.* from t1,t2 where t1.a=t2.a(+) and isnull(t2.a)=1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 7 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 5 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t2"."a" AS "a" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where "test"."t2"."a" is null = 1 +drop table t1,t2; +# +# Correct nullability test +# +create table t1 (a int not null, s varchar(10) not null); +create table t2 (a int not null, s varchar(10) not null); +insert into t1 values (1, 'one'); +insert into t1 values (2, 'two'); +insert into t2 values (2, 'two'); +insert into t2 values (3, 'three'); +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(t2.a); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Not exists; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where "test"."t2"."a" is null +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(t1.a+t2.a); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where "test"."t1"."a" + "test"."t2"."a" is null +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(coalesce(t2.s, 'null')); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on(multiple equal("test"."t1"."a", "test"."t2"."a")) where 0 +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(ifnull(t2.s, 'null')); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on(multiple equal("test"."t1"."a", "test"."t2"."a")) where 0 +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(coalesce(t2.s, null)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where coalesce("test"."t2"."s",NULL) is null +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(ifnull(t2.s, null)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where ifnull("test"."t2"."s",NULL) is null +# Our optimizer does not optimize out never-null-subselects under +# isnull() so we do not test it. The following test is to make +# sure that nullable one stay in the WHERE. +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(t2.a in (select a from t1)); +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 +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +2 MATERIALIZED t1 ALL NULL NULL NULL NULL 2 100.00 +Warnings: +Note 1003 /* select#1 */ select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where <"test"."t2"."a">(("test"."t2"."a","test"."t2"."a" in ( (/* select#2 */ select "test"."t1"."a" from "test"."t1" ), ("test"."t2"."a" in on distinct_key where "test"."t2"."a" = ""."a")))) is null +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(t2.a in (1, 2, 3)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on("test"."t2"."a" = "test"."t1"."a") where "test"."t2"."a" in (1,2,3) is null +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(t1.a in (1, 2, 3)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on(multiple equal("test"."t1"."a", "test"."t2"."a")) where 0 +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(isnull(t2.a)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on(multiple equal("test"."t1"."a", "test"."t2"."a")) where 0 +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(field(t2.a, 2, 23)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on(multiple equal("test"."t1"."a", "test"."t2"."a")) where 0 +explain extended +select * from t1,t2 where t1.a = t2.a (+) and +isnull(benchmark(10, t2.a)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t1"."s" AS "s","test"."t2"."a" AS "a","test"."t2"."s" AS "s" from "test"."t1" left join "test"."t2" on(multiple equal("test"."t1"."a", "test"."t2"."a")) where 0 +drop table t1, t2; +# +# MDEV-36895: Oracle outer join syntax (+): some NULLs missing from +# result of the query with derived tables and limit +# +create table t2 (b int); +insert into t2 values (3),(7),(1); +create table t3 (c int); +insert into t3 values (3),(1); +create table t1 (a int); +insert into t1 values (1),(2),(7),(1); +select * from +( +select * from +(select 'Z' as z, t1.a from t1) dt1 +left join +(select 'Y' as y, t2.b from t2) dt2 +left join +(select 'X' as x, t3.c from t3) dt3 +on dt2.b=dt3.c +on dt1.a=dt2.b +order by z, a, y, b, x, c +limit 9 +) dt; +z a y b x c +Z 1 Y 1 X 1 +Z 1 Y 1 X 1 +Z 2 NULL NULL NULL NULL +Z 7 Y 7 NULL NULL +select * from +( +select * from +(select 'Z' as z, t1.a from t1) dt1 +,(select * from +(select 'Y' as y, t2.b from t2) dt2 +, +(select 'X' as x, t3.c from t3) dt3 +where dt2.b=dt3.c(+) +) tdt2 +where dt1.a=tdt2.b(+) +order by z, a, y, b, x, c +limit 9 +) dt; +z a y b x c +Z 1 Y 1 X 1 +Z 1 Y 1 X 1 +Z 2 NULL NULL NULL NULL +Z 7 Y 7 NULL NULL +drop table t1, t2, t3; +# +# MDEV-37337: Oracle outer join syntax (+): IN equal to = allow (+) on right side +# +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +set SQL_MODE= oracle; +select t1.a, t2.b +from t1, t2 +where +t1.a = t2.b(+); +a b +2 2 +1 1 +3 NULL +select t1.a, t2.b +from t1, t2 +where +t1.a IN (t2.b(+)); +a b +2 2 +1 1 +3 NULL +explain extended +select t1.a, t2.b +from t1, t2 +where +t1.a IN (t2.b(+)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t2"."b" AS "b" from "test"."t1" left join "test"."t2" on("test"."t2"."b" = "test"."t1"."a") where 1 +select t1.a, t2.b +from t1, t2 +where +t1.a IN (t2.b(+), 29); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +DROP TABLE t1, t2; +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +set SQL_MODE= oracle; +select t1.a, t2.b +from t1, t2 +where +t1.a = t2.b(+); +a b +2 2 +1 1 +3 NULL +select t1.a, t2.b +from t1, t2 +where +t1.a IN (t2.b(+)); +a b +2 2 +1 1 +3 NULL +explain extended +select t1.a, t2.b +from t1, t2 +where +t1.a IN (t2.b(+)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select "test"."t1"."a" AS "a","test"."t2"."b" AS "b" from "test"."t1" left join "test"."t2" on("test"."t2"."b" = "test"."t1"."a") where 1 +select t1.a, t2.b +from t1, t2 +where +t1.a IN (t2.b(+), 29); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +DROP TABLE t1, t2; +# End of 12.1 tests diff --git a/mysql-test/suite/compat/oracle/r/ora_outer_join_err.result b/mysql-test/suite/compat/oracle/r/ora_outer_join_err.result new file mode 100644 index 00000000000..f54ee14bbf4 --- /dev/null +++ b/mysql-test/suite/compat/oracle/r/ora_outer_join_err.result @@ -0,0 +1,107 @@ +SET sql_mode=ORACLE; +# +# Cycles +# +create table t1 (a int); +create table t2 (b int); +create table t3 (c int); +# b - cyrcle +select * from t1, t2, t3 +where t1.a = t2.b(+) AND t2.b = t3.c(+) AND +t3.c = t2.b(+); +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +# O - cyrcle +select * from t1, t2, t3 +where t1.a = t2.b(+) AND t2.b = t3.c(+) AND +t3.c = t1.a(+); +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +# self-reference cyrcle +select * from t1, t2, t3 +where t1.a = t2.b(+) AND t2.b = t3.c(+) AND +t3.c = t3.c(+); +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +DROP TABLE t1,t2,t3; +create table t1 (a int); +create table t2 (b int); +create table t3 (c int); +create table t4 (d int); +create table t5 (e int); +# complex case +select * from t1, t2, t3, t4, t5 +where +t3.c = t4.d(+) AND t4.d = t3.c(+) AND +t1.a = t5.e(+) AND t2.b = t5.e(+) AND +t2.b = t3.c(+) +; +ERROR HY000: Invalid usage of (+) operator: cycle dependencies +DROP TABLE t1,t2,t3,t4,t5; +# +# mix with other join operatirs +# +create table t1 (a int); +create table t2 (a int); +create table t3 (a int); +# mixing with left join +select * from t1, t2 left join t3 on (t2.a = t3.a) +where t1.a = t2.a(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +# mixing with right join +select * from t1, t2 right join t3 on (t2.a = t3.a) +where t1.a = t2.a(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +# mixing with natural join +select * from t1, t2 natural join t3 +where t1.a = t2.a(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +# mixing with nested join +select * from t1, t2 join t3 +where t1.a = t2.a(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +# mixing with nested join +select * from t1, (t2, t3) +where t1.a = t2.a(+); +ERROR HY000: Invalid usage of (+) operator: mixed with other type of join +DROP TABLE t1,t2,t3; +# +# misplaced usage of (+) +# +create table t1 (a int); +create table t2 (a int); +select t1.a(+), t2.a from t1,t2; +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 '), t2.a from t1,t2' at line 1 +select t1.a, t2.a from t1,t2 HAVING t1.a(+) = t2.a; +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 ') = t2.a' at line 1 +select t1.a, t2.a from t1 join t2 on (t1.a(+) = t2.a); +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 ') = t2.a)' at line 1 +DROP TABLE t1,t2; +# +# outer reference +# +create table t1 (a int); +create table t2 (a int); +select u2.a, (select t1.a, t2.a from t1,t2 where u1.a(+) = t2.a) +from t1 as u1, t2 as u2 where u1.a(+) = u2.a; +ERROR HY000: Invalid usage of (+) operator with outer reference a +DROP TABLE t1,t2; +# +# MDEV-36883: Oracle outer join syntax (+): operator (+) is not +# processed in condition like "(t2.b(+) , t1.b) in (select ...)" +# +create table t1 ( c int, b char(1)); +insert into t1 values (1,'b'); +create table t2 ( a int , b char(1)); +insert into t2 values (1,'a'); +create table t3 (c1 char(1), c2 char(2)); +insert into t3 values ('c','d'); +insert into t3 values ('c','d'); +SELECT t2.b +FROM t1, t2 WHERE t1.c = t2.a(+) AND (t2.b(+), t1.b) IN (SELECT * from t3); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +SELECT t2.b +FROM t1, t2 WHERE t1.c = t2.a(+) AND (t2.b(+), t1.b) IN (('a','a'),('b','b')); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +SELECT t2.b +FROM t1, t2 WHERE t1.c = t2.a(+) AND (t2.b(+), t1.b) = (SELECT * from t3 +ORDER BY a LIMIT 1); +ERROR HY000: Invalid usage of (+) operator: used in OR, IN or ROW operation +drop tables t1,t2,t3; diff --git a/mysql-test/suite/compat/oracle/t/ora_outer_join.test b/mysql-test/suite/compat/oracle/t/ora_outer_join.test new file mode 100644 index 00000000000..4ffdfd0a772 --- /dev/null +++ b/mysql-test/suite/compat/oracle/t/ora_outer_join.test @@ -0,0 +1,667 @@ + +set SQL_MODE= oracle; + +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create table t3 (c int, e int); +insert into t3 values (3,2),(10,3),(2,20); +create table t4 (d int); +insert into t4 values (3),(1),(20); + +select t1.a, t4.d, t2.b, t3.c + from t1, t2, t3, t4 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +explain extended +select t1.a, t4.d, t2.b, t3.c + from t1, t2, t3, t4 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +select t1.a, t4.d, t2.b, t3.c + from t4, t3, t2, t1 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +explain extended +select t1.a, t4.d, t2.b, t3.c + from t4, t3, t2, t1 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +select t1.a, t4.d, t2.b, t3.c + from t2, t1, t4, t3 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +explain extended +select t1.a, t4.d, t2.b, t3.c + from t2, t1, t4, t3 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +select t1.a, t4.d, t2.b, t3.c + from t3, t4, t1, t2 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +explain extended +select t1.a, t4.d, t2.b, t3.c + from t3, t4, t1, t2 + where + t1.a = t2.b(+) and + t1.a = t3.c(+) and + t4.d = t2.b(+) and + t4.d = t3.c(+); + +drop table t1, t2, t3, t4; + +--echo # +--echo # tests of Iqbal Hassan +--echo # (with 2 fixes) +--echo # + +CREATE TABLE tj1(a int, b int); +CREATE TABLE tj2(c int, d int); +CREATE TABLE tj3(e int, f int); +CREATE TABLE tj4(b int, c int); +INSERT INTO tj1 VALUES (1, 1); +INSERT INTO tj1 VALUES (2, 2); +INSERT INTO tj2 VALUES (2, 3); +INSERT INTO tj3 VALUES (1, 4); + +--echo # +--echo # Basic test +--echo # +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+); + +--echo # +--echo # Compare marked with literal +--echo # +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND tj2.d(+) > 4; +explain extended +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND tj2.d(+) > 4; + +--echo # +--echo # Use both marked and unmarked field in the same condition +--echo # +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND tj2.d = 3; + +--echo # +--echo # Use both marked and unmarked field in OR condition +--echo # +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +SELECT * FROM tj2,tj1 WHERE tj1.a = tj2.c(+) OR tj2.d=4; +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj3.e(+) AND (tj1.a = tj2.c(+) OR tj2.d=4); + +--echo # +--echo # Use unmarked fields in OR condition +--echo # +SELECT * FROM tj2,tj1 WHERE tj1.a = tj2.c(+) AND (tj2.d=3 OR tj2.d * 2=3); + +--echo # +--echo # Use marked fields in OR condition when all fields are marked +--echo # +SELECT * FROM tj1,tj2 WHERE tj1.a = tj2.c(+) AND (tj2.d(+)=3 OR tj2.c(+)=1); + +--echo # +--echo # Use more than one marked table per condition +--echo # +--error ER_INVALID_USE_OF_ORA_JOIN_ONE_TABLE +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) + tj3.e(+); + +--echo # +--echo # Use different tables per `AND` operand +--echo # +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj1.a = tj3.e(+); + +--echo # +--echo # Ensure table dependencies are properly resolved +--echo # +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj3.e AND tj1.a + 1 = tj2.c(+); +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj2.c = tj3.e(+) + 1; +SELECT * FROM tj1, tj2, tj3 WHERE tj1.a + tj3.e = tj2.c(+); + +--echo # +--echo # Cyclic dependency of tables +--echo # ORA-01416 two tables cannot be outer-joined to each other +--echo # +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj2.c = tj3.e(+) + 1 AND tj3.e = tj1.a(+); + +--echo # +--echo # Table not referenced in where condition (must be cross-joined) +--echo # +SELECT * FROM tj1, tj2, tj3 WHERE tj1.a + 1 = tj2.c(+); + +--echo # +--echo # Alias +--echo # +SELECT * FROM tj1, tj2 b WHERE tj1.a + 1 = b.c(+); + +--echo # +--echo # Subselect +--echo # +SELECT * FROM tj1, (SELECT * from tj2) b WHERE tj1.a + 1 = b.c(+); +SELECT * FROM tj1, (SELECT * FROM tj1, tj2 d WHERE tj1.a = d.c(+)) b WHERE tj1.a + 1 = b.c(+); + +--echo # +--echo # Single table +--echo # +# --error ER_INVALID_USE_OF_ORA_JOIN +# it is legal, Oracle just ignore the operator if it is applied to all tabes + +# The WARN_ORA_JOIN_IGNORED is emitted only on PREPARE: +--disable_ps_protocol +SELECT * FROM tj1 WHERE tj1.a(+) = 1; +--enable_ps_protocol + +--echo # +--echo # Self outer join +--echo # +SELECT * FROM tj1 a, tj1 b WHERE a.a + 1 = b.a(+); + +--echo # +--echo # Self outer join without alias +--echo # +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +SELECT * FROM tj1, tj2 WHERE tj1.a + 1 = tj1.a(+); + +--echo # +--echo # Outer join condition is independent of other tables +--echo # In this case we need to restrict the marked table(s) to appear +--echo # after the unmarked table(s) during topological sort. This test +--echo # ensures that the topological sort is working correctly. +--echo # +--echo # correct result in is empty result set (tj2.c = 1 filters all out) + +# The WARN_ORA_JOIN_IGNORED is emitted only on PREPARE: +--disable_ps_protocol +SELECT * FROM tj1, tj2 WHERE tj2.c(+) = 1; +--echo # one row (there is tj1.a = 1) +SELECT * FROM tj1, tj2 WHERE tj1.a(+) = 1; +--enable_ps_protocol + +--echo # +--echo # Outer join in 'IN' condition +--echo # ORA-01719 +--echo # +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +SELECT * FROM tj1, tj2 WHERE tj1.a IN (tj2.c(+), tj2.d(+)); +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +SELECT * FROM tj1, tj2 WHERE tj1.a NOT IN (tj2.c(+), tj2.d(+)); + +--echo # +--echo # Outer join in 'IN' condition with a single expression +--echo # This is also allowed in oracle since the expression is +--echo # can be simplified to 'equal' or 'not equal' condition +--echo # +SELECT * FROM tj1, tj2 WHERE tj1.a IN (tj2.c(+)); +SELECT * FROM tj1, tj2 WHERE tj1.a NOT IN (tj2.c(+)); + +--echo # +--echo # Oracle outer join not in WHERE clause +--echo # +--error ER_PARSE_ERROR +SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c GROUP BY tj2.c(+); +--error ER_PARSE_ERROR +SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c GROUP BY tj2.c HAVING tj2.c(+) > 1; +--error ER_PARSE_ERROR +SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c ORDER BY tj2.c(+); +--error ER_PARSE_ERROR +SELECT tj2.c(+) FROM tj2; + +--echo # +--echo # Mix ANSI and Oracle outer join +--echo # ORA-25156 +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +SELECT * FROM tj1 LEFT JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +SELECT * FROM tj1 INNER JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +SELECT * FROM tj1 NATURAL JOIN tj2 WHERE tj1.a = tj2.c(+); + +--echo # +--echo # View with oracle outer join +--echo # +CREATE VIEW v1 AS SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c(+); +SELECT * FROM v1; + +--echo # +--echo # Cursor with oracle outer join +--echo # +DELIMITER $$; +DECLARE + CURSOR c1 IS SELECT * FROM tj1, tj2 WHERE tj1.a = tj2.c(+); +BEGIN + FOR r1 IN c1 LOOP + SELECT r1.a || ' ' || r1.c; + END LOOP; +END +$$ +DELIMITER ;$$ + +--echo # +--echo # Marking ROW type +--echo # +DELIMITER $$; +--error ER_PARSE_ERROR +DECLARE + v1 ROW (a INT, b INT); +BEGIN + SELECT * FROM tj1 WHERE tj1.a = v1.a(+); +END +$$ +DELIMITER ;$$ + +--echo # +--echo # Unspecified table used in WHERE clause that contains (+) +--echo # +--error ER_BAD_FIELD_ERROR +SELECT * FROM tj1, tj2 WHERE tj1.a = tj3.c(+); + +--echo # +--echo # '.' prefixed table name +--echo # +SELECT * FROM tj1, tj2 WHERE tj1.a = .tj2.c(+); + +CREATE DATABASE db1; +USE db1; +CREATE TABLE tj1(a int, b int); +INSERT INTO tj1 VALUES (3, 3); +INSERT INTO tj1 VALUES (4, 4); + +--echo # +--echo # DB qualifed ident with oracle outer join (aliased) +--echo # +SELECT * FROM test.tj2 a, tj1 WHERE a.c(+) = tj1.a - 1; + +--echo # +--echo # DB qualifed ident with oracle outer join (non-aliased) +--echo # +SELECT * FROM test.tj2, tj1 WHERE test.tj2.c(+) = tj1.a - 1; + +--echo # +--echo # DB qualifed ident with oracle outer join (aliased but use table name) +--echo # +--error ER_BAD_FIELD_ERROR +SELECT * FROM test.tj2 a, tj1 WHERE test.tj2.c(+) = tj1.a - 1; + +USE test; + +--echo # +--echo # UPDATE with oracle outer join +--echo # +UPDATE tj1, tj2 SET tj1.a = tj2.c WHERE tj1.a = tj2.c(+); +SELECT * FROM tj1; + +--echo # +--echo # DELETE with oracle outer join +--echo # +DELETE tj1 FROM tj1, tj2 WHERE tj1.b(+) = tj2.c; +SELECT * FROM tj1; + +DROP DATABASE db1; +DROP VIEW v1; +DROP TABLE tj4; +DROP TABLE tj3; +DROP TABLE tj2; +DROP TABLE tj1; + +--echo # +--echo # End of iqbal-rsec tests +--echo # + +--echo # +--echo # Test from the MDEV comments +--echo # + +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create table t3 (c int, e int); +insert into t3 values (3,2),(10,3),(2,20); +create table t4 (d int); +insert into t4 values (3),(1),(20); +select t1.a, t4.d, t2.b, t3.c from t1, t2, t3, t4 where t1.a = t2.b(+) and t1.a = t3.c(+) and t4.d = t2.b(+) and t4.d = t3.c(+); +select t1.a, t4.d, t2.b, t3.c from t1, t2, t3, t4 where t1.a + t3.c = t2.b(+) and t1.a = t3.c(+) and t4.d = t2.b(+) and t4.d = t3.c(+); +select t1.a, t4.d, t2.b, t3.c from t1, t2, t3, t4 where (t2.b(+) in (t1.a, t1.a+1)) and t1.a = t3.c(+) and t4.d = t2.b(+) and t4.d = t3.c(+); + +drop tables t1, t2, t3, t4; + +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); +create table t3 (c int, f int); +insert into t3 values (3,2),(10,3),(2,20); +create table t4 (d int); +insert into t4 values (3),(1),(20); +create table t5 (e int); +insert into t5 values (3),(2),(20); + +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, t2, t3, t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and t3.c=t5.e(+); +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, t2, t3, t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and 1=t5.e(+); +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, t2, t3, t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and 3=t5.e(+); +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +select t1.a, t2.b, t3.c, t4.d, t5.e from t1, (t2, t3), t4, t5 where t1.a = t2.b(+) and t2.b = t3.c(+) and t1.a = t4.d(+) and t4.d=t5.e(+) and 3=t5.e(+); + +drop tables t1, t2, t3, t4, t5; + +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); + +# The WARN_ORA_JOIN_IGNORED is emitted only on PREPARE: +--disable_ps_protocol +select t1.a, t2.b from t1, t2 where 1 = t2.b(+); +select t1.a, t2.b from t2, t1 where 1 = t2.b(+); +select t1.a,t2.b from t2,t1 where t2.b(+) in (1,2); +select t2.b from t2 where 1 = t2.b(+); +--enable_ps_protocol + +drop tables t1, t2; + +create table t1 (a int); +insert into t1 values (1),(2),(4),(5),(20),(21),(23); +create table t2 (b int); +insert into t2 values (1),(4),(6),(7),(8),(23); +create table t3 (c int); +insert into t3 values (4),(7),(9),(4),(6),(10),(11),(1); +create table t4 (d int); +insert into t4 values (1),(4),(10),(12),(20),(21),(23); + +SELECT * FROM t1,t2,t3,t4 WHERE t1.a = t2.b(+) AND t1.a = t3.c(+) AND t2.b=t4.d(+) AND t3.c=t4.d(+); +select * from t1, t2, t3 where (t1.a + t2.b = t3.c(+)); + +--echo # no tables mentioned +select * from t2, t3 where b = c(+); +--echo # should be the same as above +select * from t2, t3 where t2.b = t3.c(+); + +drop tables t1, t2, t3, t4; + +--echo # +--echo # View creation and usage +--echo # +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); + +create view v1 as +select t1.a, t2.b from t1, t2 where t1.a = t2.b(+); +show create view v1; +select * from v1; +select t1.a, t2.b from t1, t2 where t1.a = t2.b(+); + +--echo usage without oracle sql mode +set SQL_MODE= ''; +select * from v1; +--error ER_PARSE_ERROR +select t1.a, t2.b from t1, t2 where t1.a = t2.b(+); +set SQL_MODE= oracle; + +drop view v1; +drop table t1,t2; + +--echo # +--echo # MDEV-36830: Oracle outer join syntax (+): outer join not converted to inner +--echo # +--source include/have_sequence.inc + +create table t1 ( + a int not null, + b int not null +); +insert into t1 select seq,seq from seq_1_to_10; + +create table t2 ( + a int not null, + b int not null +); +insert into t2 select seq,seq from seq_1_to_3; + +--echo # Must be converted to inner join: +explain extended +select * from t1, t2 +where + t1.a=1 and + t1.b=t2.b(+) and + t2.b=1; + +drop table t1,t2; + + +--echo # +--echo # MDEV-36838: Oracle outer join syntax (+): server crash on derived tables +--echo # + +select a.a +from (select 1 as a) a, + (select 2 as b) b + where a.a=b.b(+); + +--echo # +--echo # MDEV-36866: Oracle outer join syntax (+): query with checking for +--echo # null of non-null column uses wrong query plan and returns wrong +--echo # result +--echo # + +create table t1 (a int default NULL); +create table t2 (a int not null); +insert into t1 values (1), (2), (3), (4), (5), (6), (NULL); +insert into t2 values (1), (4), (5), (6), (7); + +select t1.*,t2.* from t1,t2 where t1.a=t2.a and isnull(t2.a)=1; +explain select t1.*,t2.* from t1,t2 where t1.a=t2.a and isnull(t2.a)=1; + +select t1.*,t2.* from t1 left join t2 on t1.a=t2.a where isnull(t2.a)=1; +explain select t1.*,t2.* from t1 left join t2 on t1.a=t2.a where isnull(t2.a)=1; + +select t1.*,t2.* from t1,t2 where t1.a=t2.a(+) and isnull(t2.a)=1; +explain extended select t1.*,t2.* from t1,t2 where t1.a=t2.a(+) and isnull(t2.a)=1; + +drop table t1,t2; + +--echo # +--echo # Correct nullability test +--echo # + +create table t1 (a int not null, s varchar(10) not null); +create table t2 (a int not null, s varchar(10) not null); +insert into t1 values (1, 'one'); +insert into t1 values (2, 'two'); +insert into t2 values (2, 'two'); +insert into t2 values (3, 'three'); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(t2.a); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(t1.a+t2.a); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(coalesce(t2.s, 'null')); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(ifnull(t2.s, 'null')); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(coalesce(t2.s, null)); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(ifnull(t2.s, null)); + +--echo # Our optimizer does not optimize out never-null-subselects under +--echo # isnull() so we do not test it. The following test is to make +--echo # sure that nullable one stay in the WHERE. +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(t2.a in (select a from t1)); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(t2.a in (1, 2, 3)); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(t1.a in (1, 2, 3)); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(isnull(t2.a)); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(field(t2.a, 2, 23)); + +explain extended +select * from t1,t2 where t1.a = t2.a (+) and + isnull(benchmark(10, t2.a)); + + +drop table t1, t2; + +--echo # +--echo # MDEV-36895: Oracle outer join syntax (+): some NULLs missing from +--echo # result of the query with derived tables and limit +--echo # + +create table t2 (b int); +insert into t2 values (3),(7),(1); +create table t3 (c int); +insert into t3 values (3),(1); +create table t1 (a int); +insert into t1 values (1),(2),(7),(1); + +select * from +( + select * from + (select 'Z' as z, t1.a from t1) dt1 + left join + (select 'Y' as y, t2.b from t2) dt2 + left join + (select 'X' as x, t3.c from t3) dt3 + on dt2.b=dt3.c + on dt1.a=dt2.b + order by z, a, y, b, x, c + limit 9 +) dt; + + +select * from +( + select * from + (select 'Z' as z, t1.a from t1) dt1 + ,(select * from + (select 'Y' as y, t2.b from t2) dt2 + , + (select 'X' as x, t3.c from t3) dt3 + where dt2.b=dt3.c(+) + ) tdt2 + where dt1.a=tdt2.b(+) + order by z, a, y, b, x, c + limit 9 +) dt; + +drop table t1, t2, t3; + +--echo # +--echo # MDEV-37337: Oracle outer join syntax (+): IN equal to = allow (+) on right side +--echo # + +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); + +set SQL_MODE= oracle; + +select t1.a, t2.b + from t1, t2 + where + t1.a = t2.b(+); + +select t1.a, t2.b + from t1, t2 + where + t1.a IN (t2.b(+)); +explain extended +select t1.a, t2.b + from t1, t2 + where + t1.a IN (t2.b(+)); + +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +select t1.a, t2.b + from t1, t2 + where + t1.a IN (t2.b(+), 29); + +DROP TABLE t1, t2; +create table t1 (a int); +insert into t1 values (1),(2),(3); +create table t2 (b int); +insert into t2 values (2),(1),(20); + +set SQL_MODE= oracle; + +select t1.a, t2.b + from t1, t2 + where + t1.a = t2.b(+); + +select t1.a, t2.b + from t1, t2 + where + t1.a IN (t2.b(+)); + +explain extended +select t1.a, t2.b + from t1, t2 + where + t1.a IN (t2.b(+)); + +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +select t1.a, t2.b + from t1, t2 + where + t1.a IN (t2.b(+), 29); + +DROP TABLE t1, t2; + +--echo # End of 12.1 tests diff --git a/mysql-test/suite/compat/oracle/t/ora_outer_join_err.test b/mysql-test/suite/compat/oracle/t/ora_outer_join_err.test new file mode 100644 index 00000000000..94faa293323 --- /dev/null +++ b/mysql-test/suite/compat/oracle/t/ora_outer_join_err.test @@ -0,0 +1,138 @@ + +SET sql_mode=ORACLE; + +--echo # +--echo # Cycles +--echo # + +create table t1 (a int); +create table t2 (b int); +create table t3 (c int); + +--echo # b - cyrcle +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +select * from t1, t2, t3 + where t1.a = t2.b(+) AND t2.b = t3.c(+) AND + t3.c = t2.b(+); +--echo # O - cyrcle +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +select * from t1, t2, t3 + where t1.a = t2.b(+) AND t2.b = t3.c(+) AND + t3.c = t1.a(+); +--echo # self-reference cyrcle +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +select * from t1, t2, t3 + where t1.a = t2.b(+) AND t2.b = t3.c(+) AND + t3.c = t3.c(+); + +DROP TABLE t1,t2,t3; + +create table t1 (a int); +create table t2 (b int); +create table t3 (c int); +create table t4 (d int); +create table t5 (e int); + +--echo # complex case +--error ER_INVALID_USE_OF_ORA_JOIN_CYCLE +select * from t1, t2, t3, t4, t5 + where + t3.c = t4.d(+) AND t4.d = t3.c(+) AND + t1.a = t5.e(+) AND t2.b = t5.e(+) AND + t2.b = t3.c(+) + ; + +DROP TABLE t1,t2,t3,t4,t5; + +--echo # +--echo # mix with other join operatirs +--echo # + +create table t1 (a int); +create table t2 (a int); +create table t3 (a int); + +--echo # mixing with left join +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +select * from t1, t2 left join t3 on (t2.a = t3.a) + where t1.a = t2.a(+); + +--echo # mixing with right join +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +select * from t1, t2 right join t3 on (t2.a = t3.a) + where t1.a = t2.a(+); + +--echo # mixing with natural join +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +select * from t1, t2 natural join t3 + where t1.a = t2.a(+); + +--echo # mixing with nested join +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +select * from t1, t2 join t3 + where t1.a = t2.a(+); + +--echo # mixing with nested join +--error ER_INVALID_USE_OF_ORA_JOIN_MIX +select * from t1, (t2, t3) + where t1.a = t2.a(+); + +DROP TABLE t1,t2,t3; + + +--echo # +--echo # misplaced usage of (+) +--echo # + +create table t1 (a int); +create table t2 (a int); + +--error ER_PARSE_ERROR +select t1.a(+), t2.a from t1,t2; +--error ER_PARSE_ERROR +select t1.a, t2.a from t1,t2 HAVING t1.a(+) = t2.a; +--error ER_PARSE_ERROR +select t1.a, t2.a from t1 join t2 on (t1.a(+) = t2.a); + +DROP TABLE t1,t2; + +--echo # +--echo # outer reference +--echo # +create table t1 (a int); +create table t2 (a int); + +--error ER_INVALID_USE_OF_ORA_JOIN_OUTER_REF +select u2.a, (select t1.a, t2.a from t1,t2 where u1.a(+) = t2.a) + from t1 as u1, t2 as u2 where u1.a(+) = u2.a; + +DROP TABLE t1,t2; + +--echo # +--echo # MDEV-36883: Oracle outer join syntax (+): operator (+) is not +--echo # processed in condition like "(t2.b(+) , t1.b) in (select ...)" +--echo # +create table t1 ( c int, b char(1)); +insert into t1 values (1,'b'); + +create table t2 ( a int , b char(1)); +insert into t2 values (1,'a'); + +create table t3 (c1 char(1), c2 char(2)); +insert into t3 values ('c','d'); +insert into t3 values ('c','d'); + +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +SELECT t2.b +FROM t1, t2 WHERE t1.c = t2.a(+) AND (t2.b(+), t1.b) IN (SELECT * from t3); + +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +SELECT t2.b +FROM t1, t2 WHERE t1.c = t2.a(+) AND (t2.b(+), t1.b) IN (('a','a'),('b','b')); + +--error ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC +SELECT t2.b +FROM t1, t2 WHERE t1.c = t2.a(+) AND (t2.b(+), t1.b) = (SELECT * from t3 +ORDER BY a LIMIT 1); + +drop tables t1,t2,t3; diff --git a/sql/CMakeLists.txt b/sql/CMakeLists.txt index 3dd5a13634d..175f2abe572 100644 --- a/sql/CMakeLists.txt +++ b/sql/CMakeLists.txt @@ -132,6 +132,7 @@ SET (SQL_SOURCE sql_error.cc sql_handler.cc sql_get_diagnostics.cc sql_help.cc sql_insert.cc sql_lex.cc sql_list.cc sql_load.cc sql_manager.cc + sql_oracle_outer_join.cc sql_parse.cc sql_bootstrap.cc sql_partition.cc sql_plugin.cc sql_prepare.cc sql_rename.cc debug_sync.cc debug.cc diff --git a/sql/item.cc b/sql/item.cc index f844f9a5108..711b578c28b 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -3512,6 +3512,11 @@ void Item_ident::print(String *str, enum_query_type query_type) str->append('.'); } append_identifier(thd, str, &field_name); + + if (with_ora_join()) + { + str->append(STRING_WITH_LEN(" (+)")); + } } /* ARGSUSED */ @@ -6332,6 +6337,22 @@ Item_field::fix_outer_field(THD *thd, Field **from_field, Item **reference) return 1; } +bool Item_field::check_ora_join(Item **reference, bool outer_ref_fixed) +{ + if(with_ora_join()) + { + if (outer_ref_fixed) // Oracle join operator is local + { + my_error(ER_INVALID_USE_OF_ORA_JOIN_OUTER_REF, MYF(0), name.str); + return TRUE; + } + // Keep flag about oracle join if view fied was resolved + if (reference[0] != this) // resolved to a new field + reference[0]->copy_flags(this, item_with_t::ORA_JOIN); + } + return FALSE; +} + /** Resolve the name of a column reference. @@ -6466,7 +6487,7 @@ bool Item_field::fix_fields(THD *thd, Item **reference) set_max_sum_func_level(thd, select); set_field(new_field); depended_from= (*((Item_field**)res))->depended_from; - return 0; + return check_ora_join(reference, false); } else { @@ -6493,7 +6514,7 @@ bool Item_field::fix_fields(THD *thd, Item **reference) its arguments are not defined. */ set_max_sum_func_level(thd, select); - return FALSE; + return check_ora_join(reference, false); } } } @@ -6548,7 +6569,7 @@ bool Item_field::fix_fields(THD *thd, Item **reference) Also we suppose that view can't be changed during PS/SP life. */ if (from_field == view_ref_found) - return FALSE; + return check_ora_join(reference, outer_fixed); set_field(from_field); } @@ -6596,6 +6617,8 @@ bool Item_field::fix_fields(THD *thd, Item **reference) } #endif base_flags|= item_base_t::FIXED; + if (check_ora_join(reference, outer_fixed)) + goto error; if (thd->variables.sql_mode & MODE_ONLY_FULL_GROUP_BY && !outer_fixed && !thd->lex->in_sum_func && select && @@ -6644,7 +6667,7 @@ mark_non_agg_field: select_lex->set_non_agg_field_used(true); } } - return FALSE; + return check_ora_join(reference, outer_fixed); error: context->process_error(thd); @@ -7806,6 +7829,17 @@ bool Item_null::send(Protocol *protocol, st_value *buffer) } +/* + Create a List consisting of one element - + a single Item_join_operator_plus instance. +*/ +List *Item_join_operator_plus::make_as_item_list(THD *thd) +{ + Item *item= new (thd->mem_root) Item_join_operator_plus(thd); + return item ? List::make(thd->mem_root, item) : nullptr; +} + + /** Check if an item is a constant one and can be cached. @@ -9666,6 +9700,14 @@ bool Item_direct_view_ref::fix_fields(THD *thd, Item **reference) return FALSE; } + +bool Item_direct_view_ref::add_maybe_null_after_ora_join_processor(void *arg) +{ + if (!maybe_null() && view->table && view->table->maybe_null) + set_maybe_null(); + return 0; +} + /* Prepare referenced outer field then call usual Item_direct_ref::fix_fields @@ -10175,6 +10217,115 @@ bool Item_default_value::val_native_result(THD *thd, Native *to) } +/* + We're processing an expression with a (+) operator somewhere. + We encounter reference to 'table.column' (with the(+) or not). + Add table to the oracle outer join structure we're building +*/ + +bool Item_ident::ora_join_add_table_ref(ora_join_processor_param *arg, + TABLE_LIST *table) +{ + DBUG_ASSERT(fixed()); + TABLE_LIST *err_table= NULL; + + if (with_ora_join()) + { + // This an item with (+) operator, the referred table is INNER. + if (arg->inner == NULL) + { + arg->inner= table; + // Make sure this table is not also in the list of OUTER tables. + List_iterator_fast it(arg->outer); + TABLE_LIST *t; + while ((t= it++)) + { + if (t == table) + { + err_table= t; + goto err; + } + } + } + else + { + // Cannot have two INNER tables, like t1.col=t2.col(+) + t3.col(+) + if (arg->inner != table) + { + err_table= arg->inner; + goto err; + } + } + } + else + { + // No (+) operator, this is an outer table. + List_iterator_fast it(arg->outer); + TABLE_LIST *t; + + // Check if this table is already in the list of outer tables + while ((t= it++)) + { + if (t == table) + break; + } + if (t == NULL) + { + // Check that this table is also used as INNER by this condition + if (table == arg->inner) + { + err_table= arg->inner; + goto err; + } + arg->outer.push_back(table); + } + } + return FALSE; +err: + // it is not marked all tables as outer or several inner or outer tables + if (table == err_table) + { + // self reference (simple case of cyclic reference) + my_error(ER_INVALID_USE_OF_ORA_JOIN_CYCLE, MYF(0)); + } + else + { + my_error(ER_INVALID_USE_OF_ORA_JOIN_ONE_TABLE, MYF(0), + err_table->alias.str, + table->alias.str, + (with_ora_join()?"INNER":"OUTER")); + } + return TRUE; +} + + +bool Item_field::ora_join_processor(void *arg) +{ + DBUG_ASSERT(field->table->pos_in_table_list); + return Item_ident::ora_join_add_table_ref((ora_join_processor_param *)arg, + field->table->pos_in_table_list); +} + + +bool Item_direct_view_ref::ora_join_processor(void *arg) +{ + DBUG_ASSERT(view); + return Item_ident::ora_join_add_table_ref((ora_join_processor_param *)arg, + view); +} + + +bool Item_ref::ora_join_processor(void *arg) +{ + if (with_ora_join()) + { + // It should not happened + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return TRUE; + } + return FALSE; +} + table_map Item_default_value::used_tables() const { if (!field || !field->default_value) diff --git a/sql/item.h b/sql/item.h index ce644a72fd5..1beb9de177a 100644 --- a/sql/item.h +++ b/sql/item.h @@ -97,6 +97,15 @@ public: }; +struct ora_join_processor_param +{ + TABLE_LIST *inner; + List outer; + /* TRUE means Oracle join operator was used inside some OR clause */ + bool or_present; +}; + + #ifdef DBUG_OFF static inline const char *dbug_print_item(Item *item) { return NULL; } #else @@ -709,7 +718,7 @@ struct subselect_table_finder_param /* Base flags (including IN) for an item */ -typedef uint8 item_flags_t; +typedef uint16 item_flags_t; enum class item_base_t : item_flags_t { @@ -742,8 +751,9 @@ enum class item_with_t : item_flags_t SUBQUERY= (1<<4), // If item contains a subquery ROWNUM_FUNC= (1<<5), // If ROWNUM function was used PARAM= (1<<6), // If user parameter was used - COMPLEX_DATA_TYPE= (1<<7) // If the expression is of a complex data type which + COMPLEX_DATA_TYPE= (1<<7),// If the expression is of a complex data type which // requires special handling on destruction + ORA_JOIN= (1<<8), // If Oracle join syntax was used }; @@ -809,6 +819,7 @@ static inline item_with_t operator~(const item_with_t a) typedef uint8 item_walk_flags; const item_walk_flags WALK_SUBQUERY= 1; const item_walk_flags WALK_NO_CACHE_PROCESS= (1<<1); +const item_walk_flags WALK_NO_REF= (1<<2); class Item :public Value_source, @@ -1070,6 +1081,8 @@ public: { return (bool) (with_flags & item_with_t::PARAM); } inline bool with_complex_data_types() const { return (bool) (with_flags & item_with_t::COMPLEX_DATA_TYPE); } + inline bool with_ora_join() const + { return (bool) (with_flags & item_with_t::ORA_JOIN); } inline void copy_flags(const Item *org, item_base_t mask) { base_flags= (item_base_t) (((item_flags_t) base_flags & @@ -2283,6 +2296,19 @@ public: is_expensive_cache= (int8)(-1); return 0; } + virtual bool ora_join_processor(void *arg) { return 0; } + /* + This marks the item as nullable. Note that if we'd want a method that + marks the item as not nullable (maybe_null=false) we'd need to process + carefully functions (e.g. json*) that can always return null even with + non-null arguments + */ + virtual bool add_maybe_null_after_ora_join_processor(void *arg) { return 0; } + virtual bool remove_ora_join_processor(void *arg) + { + with_flags&= ~item_with_t::ORA_JOIN; + return 0; + } virtual bool set_extraction_flag_processor(void *arg) { @@ -2892,6 +2918,24 @@ protected: } return false; } + bool is_any_arg_maybe_null() + { + for (uint i= 0; i < arg_count; i++) + { + if (args[i]->maybe_null()) + return true; + } + return false; + } + bool is_all_arg_maybe_null() + { + for (uint i= 0; i < arg_count; i++) + { + if (!args[i]->maybe_null()) + return false; + } + return true; + } bool transform_args(THD *thd, Item_transformer transformer, uchar *arg); void propagate_equal_fields(THD *, const Item::Context &, COND_EQUAL *); bool excl_dep_on_table(table_map tab_map) @@ -3701,6 +3745,10 @@ public: Collect outer references */ bool collect_outer_ref_processor(void *arg) override; + + bool ora_join_add_table_ref(ora_join_processor_param *arg, + TABLE_LIST *table); + friend bool insert_fields(THD *thd, Name_resolution_context *context, const LEX_CSTRING &db_name, const LEX_CSTRING &table_name, @@ -3933,6 +3981,20 @@ public: } return 0; } + bool ora_join_processor(void *arg) override; + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + /* + Before this operation field nullability can not be removed + (only can be set). + maybe_null() store the old nullability state, and + field->maybe_null() is the current state. + */ + DBUG_ASSERT(!maybe_null() || field->maybe_null()); + set_maybe_null(field->maybe_null()); + return 0; + } + bool check_ora_join(Item **reference, bool outer_ref_fixed); void cleanup() override; Item_equal *get_item_equal() override { return item_equal; } void set_item_equal(Item_equal *item_eq) override { item_equal= item_eq; } @@ -4064,6 +4126,27 @@ public: Item *do_build_clone(THD *thd) const override { return get_copy(thd); } }; + +/* + A pseudo-Item to parse Oracle style outer join operator: + WHERE t1.a = t2.b (+); +*/ +class Item_join_operator_plus: public Item_null +{ +public: + using Item_null::Item_null; + /* + Need to override as least one method to have an unique vtable, + to make dynamic_cast work. + */ + void print(String *str, enum_query_type) override + { + str->append("(+)"_LEX_CSTRING); + } + static List *make_as_item_list(THD *thd); +}; + + class Item_null_result :public Item_null { public: @@ -5853,6 +5936,13 @@ public: return true; return (this->*processor)(arg); } + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + // see Item::add_maybe_null_after_ora_join_processor + if (!maybe_null() && is_any_arg_maybe_null()) + set_maybe_null(); + return 0; + } /* Built-in schema, e.g. mariadb_schema, oracle_schema, maxdb_schema */ @@ -6074,6 +6164,8 @@ public: bool walk(Item_processor processor, void *arg, item_walk_flags flags) override { + if (flags & WALK_NO_REF) + return (this->*processor)(arg); if (ref && *ref) return (*ref)->walk(processor, arg, flags) || (this->*processor)(arg); @@ -6179,6 +6271,13 @@ public: return 0; return cleanup_processor(arg); } + bool ora_join_processor(void *arg) override; + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + if ((*ref)->maybe_null()) + set_maybe_null(); + return 0; + } Item *field_transformer_for_having_pushdown(THD *thd, uchar *arg) override { return (*ref)->field_transformer_for_having_pushdown(thd, arg); } }; @@ -6397,6 +6496,12 @@ public: Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } Item *do_build_clone(THD *) const override { return nullptr; } + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + if (orig_item->maybe_null()) + set_maybe_null(); + return 0; + } }; @@ -6473,6 +6578,8 @@ public: bool walk(Item_processor processor, void *arg, item_walk_flags flags) override { + if (flags & WALK_NO_REF) + return (this->*processor)(arg); return (*ref)->walk(processor, arg, flags) || (this->*processor)(arg); } @@ -6483,6 +6590,7 @@ public: view_arg->view_used_tables|= (*ref)->used_tables(); return 0; } + bool ora_join_processor(void *arg) override; bool excl_dep_on_table(table_map tab_map) override; bool excl_dep_on_grouping_fields(st_select_lex *sel) override; bool excl_dep_on_in_subq_left_part(Item_in_subselect *subq_pred) override; @@ -6627,6 +6735,7 @@ public: return 0; } void print(String *str, enum_query_type query_type) override; + bool add_maybe_null_after_ora_join_processor(void *arg) override; }; @@ -8417,6 +8526,8 @@ public: bool walk(Item_processor processor, void *arg, item_walk_flags flags) override { + if (flags & WALK_NO_REF) + return (this->*processor)(arg); return m_item->walk(processor, arg, flags) || (this->*processor)(arg); } diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index acc6bbee0db..14f423da3d2 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -5034,6 +5034,33 @@ void Item_func_in::mark_as_condition_AND_part(TABLE_LIST *embedding) } +bool Item_func_in::ora_join_processor(void *arg) +{ + if (with_ora_join()) + { + if (args[0]->cols() > 1 && args[0]->with_ora_join()) + { + // used in ROW operaton + my_error(ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC, MYF(0)); + return TRUE; + } + uint n= argument_count(); + DBUG_ASSERT(n >= 2); + // first argument (0) is right part of IN where oracle joins are allowed + for (uint i= 1; i < n; i++) + { + if (args[i]->with_ora_join()) + { + // used in right part of IN + my_error(ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC, MYF(0)); + return TRUE ; + } + } + } + return FALSE; +} + + class Func_handler_bit_or_int_to_ulonglong: public Item_handled_func::Handler_ulonglong { diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index e46c16ecd95..31f0410f034 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -279,6 +279,9 @@ public: { return negated_item(thd); } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } protected: Item_func_truth(THD *thd, Item *a, bool a_value, bool a_affirmative): @@ -887,6 +890,9 @@ public: } Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } }; @@ -1191,6 +1197,9 @@ public: } Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } }; @@ -1217,6 +1226,12 @@ public: fix_attributes(args, arg_count); return FALSE; } + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + if (!maybe_null() && is_all_arg_maybe_null()) + set_maybe_null(); + return 0; + } LEX_CSTRING func_name_cstring() const override { static LEX_CSTRING name= {STRING_WITH_LEN("coalesce") }; @@ -1309,6 +1324,12 @@ public: return TRUE; return FALSE; } + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + if (!maybe_null() && is_all_arg_maybe_null()) + set_maybe_null(); + return 0; + } LEX_CSTRING func_name_cstring() const override { static LEX_CSTRING name= {STRING_WITH_LEN("ifnull") }; @@ -2745,6 +2766,7 @@ public: Item* varchar_upper_cmp_transformer(THD *thd, uchar *arg) override; Item* vcol_subst_transformer(THD *thd, uchar *arg) override; + bool ora_join_processor(void *arg) override; }; class cmp_item_row :public cmp_item @@ -2827,6 +2849,9 @@ public: base_flags&= ~item_base_t::MAYBE_NULL; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } bool count_sargable_conds(void *arg) override; Item* vcol_subst_transformer(THD *thd, uchar *arg) override; @@ -3321,7 +3346,7 @@ public: void split_sum_func(THD *thd, Ref_ptr_array ref_pointer_array, List &fields, uint flags) override; friend int setup_conds(THD *thd, TABLE_LIST *tables, TABLE_LIST *leaves, - COND **conds); + COND **conds, List *all_fields); void copy_andor_arguments(THD *thd, Item_cond *item); bool walk(Item_processor processor, void *arg, item_walk_flags flags) override; @@ -3742,6 +3767,15 @@ public: table_map not_null_tables() const override { return and_tables_cache; } Item *copy_andor_structure(THD *thd) override; Item *neg_transformer(THD *thd) override; + bool ora_join_processor(void *arg) override + { + if (with_ora_join()) + { + // Oracle join operator is used in this OR clause. + ((ora_join_processor_param *) arg)->or_present= true; + } + return (FALSE); + } Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } }; diff --git a/sql/item_func.h b/sql/item_func.h index c3cc8b44a2a..90755f1e3d4 100644 --- a/sql/item_func.h +++ b/sql/item_func.h @@ -2624,6 +2624,9 @@ public: return name; } bool fix_length_and_dec(THD *thd) override; + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } bool eval_not_null_tables(void *) override { not_null_tables_cache= 0; @@ -2696,6 +2699,9 @@ public: bool fix_length_and_dec(THD *thd) override; Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } }; @@ -2941,6 +2947,9 @@ public: base_flags&= ~item_base_t::MAYBE_NULL; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } void print(String *str, enum_query_type query_type) override; bool check_vcol_func_processor(void *arg) override { @@ -3980,6 +3989,9 @@ public: base_flags&= ~item_base_t::MAYBE_NULL; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } bool check_vcol_func_processor(void *arg) override { return mark_unsupported_function(func_name(), "()", arg, VCOL_IMPOSSIBLE); @@ -4288,6 +4300,9 @@ public: base_flags&= ~item_base_t::MAYBE_NULL; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } bool check_vcol_func_processor(void *arg) override { return mark_unsupported_function(func_name(), "()", arg, VCOL_IMPOSSIBLE); @@ -4345,6 +4360,9 @@ public: max_length= 11; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } }; diff --git a/sql/item_row.h b/sql/item_row.h index 158b249cc1d..b9e7644e6aa 100644 --- a/sql/item_row.h +++ b/sql/item_row.h @@ -122,6 +122,17 @@ public: Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } Item *do_build_clone(THD *thd) const override; + + bool ora_join_processor(void *arg) override + { + if (with_ora_join()) + { + // Oracle join operator is used inside rows. + my_error(ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC, MYF(0)); + return(TRUE); + } + return (FALSE); + } }; #endif /* ITEM_ROW_INCLUDED */ diff --git a/sql/item_strfunc.h b/sql/item_strfunc.h index 7bf5f0c9c0f..596dbefef11 100644 --- a/sql/item_strfunc.h +++ b/sql/item_strfunc.h @@ -1223,6 +1223,9 @@ public: base_flags&= ~item_base_t::MAYBE_NULL; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } }; @@ -1344,6 +1347,9 @@ public: } Item *do_get_copy(THD *thd) const override { return get_item_copy(thd, this); } + // null do not depend on nullability of the argument + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } }; @@ -2058,6 +2064,9 @@ public: base_flags&= ~item_base_t::MAYBE_NULL; return FALSE; }; + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } table_map not_null_tables() const override { return 0; } Item* propagate_equal_fields(THD *thd, const Context &ctx, COND_EQUAL *cond) override diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 57a1f01294c..e14f1a01763 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -3614,11 +3614,13 @@ bool Item_in_subselect::fix_fields(THD *thd_arg, Item **ref) } } - if (left_expr && left_expr->fix_fields_if_needed(thd_arg, &left_expr)) + if (!left_expr || left_expr->fix_fields_if_needed(thd_arg, &left_expr)) goto err; else if (Item_subselect::fix_fields(thd_arg, ref)) goto err; + if (left_expr->with_ora_join()) + copy_flags(left_expr, item_with_t::ORA_JOIN); base_flags|= item_base_t::FIXED; thd->where= save_where; DBUG_RETURN(FALSE); diff --git a/sql/item_subselect.h b/sql/item_subselect.h index 1f6b5c85359..20246f1bbeb 100644 --- a/sql/item_subselect.h +++ b/sql/item_subselect.h @@ -791,6 +791,22 @@ public: Subq_materialization_tracker *get_materialization_tracker() const { return materialization_tracker; } + bool ora_join_processor(void *arg) override + { + if (left_expr->with_ora_join() && left_expr->cols() > 1) + { + // used in ROW operaton + my_error(ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC, MYF(0)); + return TRUE; + } + return FALSE; + } + bool add_maybe_null_after_ora_join_processor(void *arg) override + { + if (!maybe_null() && left_expr->maybe_null()) + set_maybe_null(); + return 0; + } friend class Item_ref_null_helper; friend class Item_is_not_null_test; friend class Item_in_optimizer; diff --git a/sql/item_sum.h b/sql/item_sum.h index e412b152887..2ddc92e96b0 100644 --- a/sql/item_sum.h +++ b/sql/item_sum.h @@ -807,6 +807,9 @@ public: null_value=0; return false; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } }; @@ -1271,6 +1274,9 @@ public: null_value= 0; return FALSE; } + // block standard processor for never null + bool add_maybe_null_after_ora_join_processor(void *arg) override + { return 0; } void cleanup() override { bits= reset_bits; diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 97c55b271e5..5a08312065b 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -12338,3 +12338,17 @@ ER_NULL_FOR_ASSOC_ARRAY_INDEX eng "NULL key used for associative array '%s'" ER_NEED_NAMED_ASSOCIATION eng "Initializing %s requires named association" +ER_INVALID_USE_OF_ORA_JOIN + eng "Invalid usage of (+) operator" +ER_INVALID_USE_OF_ORA_JOIN_CYCLE + eng "Invalid usage of (+) operator: cycle dependencies" +ER_INVALID_USE_OF_ORA_JOIN_OUTER_REF + eng "Invalid usage of (+) operator with outer reference %s" +ER_INVALID_USE_OF_ORA_JOIN_ONE_TABLE + eng "Invalid usage of (+) operator: both tables %s and %s are of %s type in the relation" +ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC + eng "Invalid usage of (+) operator: used in OR, IN or ROW operation" +ER_INVALID_USE_OF_ORA_JOIN_MIX + eng "Invalid usage of (+) operator: mixed with other type of join" +WARN_ORA_JOIN_IGNORED + eng "Oracle outer join operator (+) ignored in '%-.100s'" diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 29b6ddc1708..9d7c8ba8e27 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -17,6 +17,7 @@ /* Basic functions needed by many modules */ +#include "lex_ident_sys.h" #include "mariadb.h" #include "sql_base.h" // setup_table_map #include "sql_list.h" @@ -8903,15 +8904,17 @@ bool setup_on_expr(THD *thd, TABLE_LIST *table, bool is_update) return FALSE; } + /* Fix all conditions and outer join expressions. SYNOPSIS setup_conds() - thd thread handler - tables list of tables for name resolving (select_lex->table_list) - leaves list of leaves of join table tree (select_lex->leaf_tables) - conds WHERE clause + thd thread handler + tables list of tables for name resolving (select_lex->table_list) + leaves list of leaves of join table tree (select_lex->leaf_tables) + conds WHERE clause + all_fields SELECT list + hidden fields DESCRIPTION TODO @@ -8922,7 +8925,7 @@ bool setup_on_expr(THD *thd, TABLE_LIST *table, bool is_update) */ int setup_conds(THD *thd, TABLE_LIST *tables, List &leaves, - COND **conds) + COND **conds, List *all_fields) { SELECT_LEX *select_lex= thd->lex->current_select; TABLE_LIST *table= NULL; // For HP compilers @@ -8975,6 +8978,10 @@ int setup_conds(THD *thd, TABLE_LIST *tables, List &leaves, (*conds)->mark_as_condition_AND_part(NO_JOIN_NEST); if ((*conds)->fix_fields_if_needed_for_bool(thd, conds)) goto err_no_arena; + + if (setup_oracle_join(thd, conds, tables, select_lex->table_list, + &select_lex->top_join_list, all_fields)) + goto err_no_arena; } /* diff --git a/sql/sql_base.h b/sql/sql_base.h index 8b06d4638dc..0af7b440017 100644 --- a/sql/sql_base.h +++ b/sql/sql_base.h @@ -247,7 +247,7 @@ void update_non_unique_table_error(TABLE_LIST *update, const char *operation, TABLE_LIST *duplicate); int setup_conds(THD *thd, TABLE_LIST *tables, List &leaves, - COND **conds); + COND **conds, List *all_fields); void wrap_ident(THD *thd, Item **conds); int setup_ftfuncs(SELECT_LEX* select); void cleanup_ftfuncs(SELECT_LEX *select_lex); @@ -694,4 +694,11 @@ private: int m_unhandled_errors; uint first_error; }; + +bool setup_oracle_join(THD *thd, Item **conds, + TABLE_LIST *tables, + SQL_I_List &select_table_list, + List *select_join_list, + List *all_fields); + #endif /* SQL_BASE_INCLUDED */ diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index bd076905559..d74686c54c8 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -9092,6 +9092,34 @@ Item *LEX::create_item_ident_trigger_specific(THD *thd, } +/* + @detail + This is called when we've parsed Oracle's outer join syntax, that is + + [[db_name.]table_name.]column_name(+) + + Check if the parse context allows it, if yes, mark the Item_field with + ORA_JOIN flag and return it. +*/ + +bool LEX::mark_item_ident_for_ora_join(THD *thd, Item *item) +{ + Item_field *item_field; + DBUG_ASSERT(item); + + if ((thd->variables.sql_mode & MODE_ORACLE) && + current_select && current_select->parsing_place == IN_WHERE && + (item_field= dynamic_cast(item))) + { + item_field->with_flags|= item_with_t::ORA_JOIN; + return false; + } + + thd->parse_error(ER_SYNTAX_ERROR); + return true; +} + + Item *LEX::create_item_limit(THD *thd, const Lex_ident_cli_st *ca) { DBUG_ASSERT(thd->m_parser_state->m_lip.get_buf() <= ca->pos()); @@ -10566,6 +10594,15 @@ Item *LEX::make_item_func_call_generic(THD *thd, const Lex_ident_cli_st *cname, List *args) { + if (args && args->elements == 1 && + dynamic_cast(args->head())) + { + Item *item= create_item_ident(thd, cdb, cname); + if (!item || mark_item_ident_for_ora_join(thd, item)) + return nullptr; + return item; + } + Lex_ident_sys db(thd, cdb), name(thd, cname); if (db.is_null() || name.is_null()) return NULL; // EOM @@ -10661,6 +10698,15 @@ Item *LEX::make_item_func_call_generic(THD *thd, Lex_ident_cli_st *cfunc, List *args) { + if (args && args->elements == 1 && + dynamic_cast(args->head())) + { + Item *item= create_item_ident(thd, cdb, cpkg, cfunc); + if (!item || mark_item_ident_for_ora_join(thd, item)) + return nullptr; + return item; + } + Lex_ident_sys db(thd, cdb), pkg(thd, cpkg), func(thd, cfunc); Identifier_chain2 q_pkg_func(pkg, func); sp_name *qname; diff --git a/sql/sql_lex.h b/sql/sql_lex.h index fb5aa988616..3a744bc1dd0 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -4061,13 +4061,13 @@ public: const Lex_ident_sys_st &db, const Lex_ident_sys_st &table, const Lex_ident_sys_st &name); - Item *create_item_ident_nosp(THD *thd, Lex_ident_sys_st *name) + Item *create_item_ident_nosp(THD *thd, const Lex_ident_sys_st *name) { return create_item_ident_field(thd, Lex_ident_sys(), Lex_ident_sys(), *name); } Item *create_item_ident_sp(THD *thd, Lex_ident_sys_st *name, const char *start, const char *end); - Item *create_item_ident(THD *thd, Lex_ident_cli_st *cname) + Item *create_item_ident(THD *thd, const Lex_ident_cli_st *cname) { Lex_ident_sys name(thd, cname); if (name.is_null()) @@ -4195,6 +4195,8 @@ public: return nullptr; } + bool mark_item_ident_for_ora_join(THD *thd, Item *item); + /* Create items of this kind: SELECT name(args); -- e.g. spvar_assoc_array('key') diff --git a/sql/sql_oracle_outer_join.cc b/sql/sql_oracle_outer_join.cc new file mode 100644 index 00000000000..f459c4d8755 --- /dev/null +++ b/sql/sql_oracle_outer_join.cc @@ -0,0 +1,1147 @@ +/* Copyright (c) 2000, 2016, Oracle and/or its affiliates. + Copyright (c) 2010, 2024, MariaDB + + This program is free software; you can redistribute it and/or modify + it under the terms of the GNU General Public License as published by + the Free Software Foundation; version 2 of the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1335 USA */ + +#include "lex_ident_sys.h" +#include "mariadb.h" +#include "sql_base.h" +#include "sql_parse.h" // check_stack_overrun + +/* + Support for Oracle's outer join syntax. + + == Contents == + 1. Basic syntax + 1.1. Outer join operator + 1.2. Outer-joining tables + 1.3 Example 1: peer outer joins + 1.4 Example 2: chained outer joins + 1.5 Outer join graph + 2. Implementation + 2.1 Parser + 2.2 Conversion to LEFT JOIN tree + 2.2.1 Building the graph + 2.2.2 Ordering the graph + 2.2.3 Building the TABLE_LIST structure + 3. Debugging + + + == 1. Basic syntax == + + Oracle's outer join syntax is like this: + + set sql_mode='oracle'; + select * from t1, t2 where t1.col=t2.col(+) + + The (+) is the "outer join operator". It specifies that table t2 is outer- + joined (i.e. is INNER) and the predicate containing the (+) is the outer + join's ON expression. This makes the above query to be equivalent to: + + select * from t1.col left join t2 on t1.col=t2.col + + == 1.1. Outer join operator == + Outer join operators may occur only in the WHERE clause. The WHERE clause + may be one predicate or multiple predicates connected with AND. Each of the + predicates + - may reference only one outer-joined (aka the "INNER") table (all + references to its columns have "outer join operator") + - may reference zero, one or more "OUTER" tables (without outer join + operator). + + A predicate that refers to an INNER table and OUTER table(s) prescribes that + the INNER table is joined with outer join operation. + + A predicate that only refers to an INNER table (like "t1.col(+)=124") will be + added to the table's ON expression, provided there is another predicate that + prescribes that the inner table is joined with outer join operation + (otherwise, the predicate remains in the WHERE and a warning is issued). + + == 1.2. Outer-joining tables == + + If a query uses outer join operators, the FROM clause must be a simple + comma-separated list of tables (denoting inner join operations): + + FROM t1, t2, ..., tN + + If outer join operators prescribe that some table t_j is joined with outer + join, the FROM clause becomes: + + FROM (t1, ..., tbl) LEFT JOIN t_j ON outer_join_predicates, ... tN + + Here, all tables used by outer_join_predicates are moved to the left (ok to + do as inner join is commutative). + + == 1.3 Example 1: peer outer joins == + Consider a query: + + select * + from t1,t2,t3 + where t1.col=t2.col(+) and t1.col=t3.col(+) + + This has two outer join predicates + OUTER=t1, INNER=t2 + OUTER=t1, INNER=t3 + + The query can be transformed to + + select * + from (t1 left join t2 on t2.col=t1.col) left join t3 on t1.col=t3.col + + or an equvalent query: + + select * + from (t1 left join t3 on t3.col=t1.col) left join t2 on t1.col=t2.col + + MariaDB optimizer will try to preserve the original order the tables were + listed in the WHERE clause. + + == 1.4 Example 2: chained outer joins == + The query + + select ... + from t1,t2,t3 + where cond1(t1.col, t2.col(+)) and cond2(t2.col, t3.col(+)) + + has two outer join predicates + OUTER=t1, INNER=t2 + OUTER=t2, INNER=t3 + + The query is transformed into + + select ... + from + t1 + left join t2 on cond1(t1.col, t2.col) + left join t3 on cond2(t2.col, t3.col) + + Note that the result of transformation is + (t1 left join t2) left join t3 + and not + t1 left join (t2 left join t3) + + (these two expressions are in general not equivalent) There's always just one + table on the inner side of the outer join. + + == 1.5 Outer join graph == + If we take tables as vertexes and OUTER->INNER relationships as edges, then + we get a directed graph. + + The graph must not have cycles. A query that produces a graph with cycles + is aborted with error. + The graph may have alternative paths, like t1->t2->t3 and t1->t4->t3. + + In order to produce the query expression with LEFT JOIN syntax, one needs to + perform topological sorting of the graph. + Then, write out the graph vertices (tables) in an order such that all edges + would come from left to the right. + + == 2. Implementation == + + == 2.1 Parser == + The parser recognizes the "(+)" operator. After parsing, Item objects that + have a (+) operator somewhere inside have (item->with_flags() & ORA_JOIN) + flag set. + + == 2.2 Conversion to LEFT JOIN tree == + + At Name Resolution phase, we convert (+) operators into LEFT JOIN data + structures (that is, a tree of TABLE_LIST objects with ON expressions). + This is done in setup_oracle_join(). + + === 2.2.1 Building the graph === + First, we create an array of table_pos structures. These are the vertices + of the graph. + Then, we analyze the WHERE clause and construct graph's edges. + + == 2.2.2 Ordering the graph == + + Then, we walk the graph and construct a linked list of table_pos structures + (connected via table_pos::{next,prev}) so that they come in what we call + "LEFT JOIN syntax order". In decreasing order of importance, the criteria + are: + 1. Outer tables must come before their inner tables. + 2. Tables that are connected to the tables already in the order must come + before those who are not + 3. Tables that were listed earlier in the original FROM clause come before. + + == 2.2.3 Building the TABLE_LIST structure == + Then, we walk through the table_pos objects via {table_pos::next} edges and + create a parsed LEFT JOIN data sructure. + + For a chain of t1-t2-t3-t4-t5 we would create: + + ( + ( + ( + t1 + [left] join t2 on cond2 + ) + [left] join t3 on cond3 + ) + [left] join t4 on cond4 + ) + [left] join t5 on cond5 + + Each pair of () brackets is a TABLE_LIST object representing a join nest. It + has a NESTED_JOIN object which includes its two children. + + Some of the brackets are redundant, this is not a problem because + simplify_joins() will remove them. + + == 3. Debugging == + One can examine the conversion result by doing this: + + create view v1 as select ... + show create view v1; + + Unlike regular EXPLAIN, this bypasses simplify_joins() call. +*/ + + +/** + An outer join graph vertex. +*/ + +struct table_pos: public Sql_alloc +{ + /* + Links the tables in the "LEFT JOIN syntax order" + */ + table_pos *next; + table_pos *prev; + + /* Tables we have outgoing edges to. Duplicates are possible. */ + List inner_side; + + /* Incoming edges */ + List outer_side; + + /* ON condition expressions (to be AND-ed together) */ + List on_conds; + TABLE_LIST *table; + + /* Ordinal number of the table in the original FROM clause */ + int order; + + /* TRUE <=> this table is already linked (in the prev<=>next chain) */ + bool processed; + + /* TRUE <=> All tables in outer_side are already linked in prev/next */ + bool outer_processed; + + bool is_outer_of(table_pos *tab) + { + List_iterator_fast it(outer_side); + table_pos *t; + while((t= it++)) + { + if (t == tab) + return TRUE; + } + return FALSE; + } +}; + +static bool add_conditions_to_where(THD *thd, Item **conds, + List &&return_to_where); + +/* + Order the tables (which are inner_side peers of some table) + - INNER table comes before its OUTER + - then, tables that were later in the FROM clause come first +*/ + +static int table_pos_sort(table_pos *a, table_pos *b, void *arg) +{ + if (a->is_outer_of(b)) + return -1; + if (b->is_outer_of(a)) + return 1; + return b->order - a->order; +} + + +/** + @brief + Collect info about table relationships from a part of WHERE condition + + @detail + This processes an individual AND-part of the WHERE clause. + We catch these patterns: + + 1. Condition refers to one or more OUTER tables and one INNER table: + cond(outer_table1.col, outer_table2.col, ..., inner_table.col(+)) + + 2. Condition refers to just one inner table: + cond(inner_table.col(+), constants) + + We note one single inner table and zero or more outer tables and record + these dependencies in the table graph. + + Also, the predicates that will form the ON expression are collected in + table_list::on_conds. +*/ + +static bool +ora_join_process_expression(THD *thd, Item *cond, + table_pos *tab, uint n_tables) +{ + DBUG_ENTER("ora_join_process_expression"); + + struct ora_join_processor_param param; + param.inner= NULL; + param.outer.empty(); + param.or_present= FALSE; + + if (cond->walk(&Item::ora_join_processor, (void *)(¶m), WALK_NO_REF)) + DBUG_RETURN(TRUE); + + /* + There should be at least one table for inner part (outer can be absent in + case of constants) + */ + DBUG_ASSERT(param.inner != NULL); + table_pos *inner_tab= tab + param.inner->ora_join_table_no; + + if (param.outer.elements > 0) + { + if (param.or_present) + { + my_error(ER_INVALID_USE_OF_ORA_JOIN_WRONG_FUNC, MYF(0)); + DBUG_RETURN(TRUE); + } + { + // Permanent list can be used in AND + Query_arena_stmt on_stmt_arena(thd); + inner_tab->on_conds.push_back(cond); + } + List_iterator_fast it(param.outer); + TABLE_LIST *t; + while ((t= it++)) + { + table_pos *outer_tab= tab + t->ora_join_table_no; + outer_tab->inner_side.push_back(inner_tab); + inner_tab->outer_side.push_back(outer_tab); + } + } + else + { + // Permanent list can be used in AND + Query_arena_stmt on_stmt_arena(thd); + inner_tab->on_conds.push_back(cond); + } + + DBUG_RETURN(FALSE); +} + + +/** + @brief + Put the table @t into "LEFT JOIN syntax order" list after table @end. + + @detail + @t must not be already in that list. +*/ + +static void insert_element_after(table_pos *end, table_pos *t, + uint * const processed) +{ + DBUG_ASSERT(t->next == NULL); + DBUG_ASSERT(t->prev == NULL); + if (end) + { + if ((t->next= end->next)) + end->next->prev= t; + end->next= t; + t->prev= end; + } + t->processed= TRUE; + (*processed)++; +} + + +static bool process_outer_relations(THD* thd, + table_pos *tab, + table_pos *first, + uint * const processed, + uint n_tables); + + +/** + @brief + Check presence of directional cycles (starting from "tab" with beginning + of check in "beginning") in case we have non-directional cycle + + @bdetail + Recusively check if table "beginning" is reachable from table "tab" through + the table_pos::inner_side pointers. +*/ + +static bool check_directed_cycle(THD* thd, table_pos *tab, + table_pos* beginning, uint lvl, uint max) +{ + List_iterator_fast it(tab->inner_side); + table_pos *t; + uchar buff[STACK_BUFF_ALLOC]; // Max argument in function + if (check_stack_overrun(thd, STACK_MIN_SIZE, buff)) + return(TRUE);// Fatal error flag is set! + + if ((++lvl) >= max) + { + /* + We checked tables more times than tables we have => we have other cycle + reachable from "beginning" + + TODO: try to make such test + The loop of interest would like this: + + t1->t2->t3->t4->-+ + ^ | + | | + +--------+ + However for such graph we would first call + check_directed_cycle(tab=t3,beginning=t3) and detect the loop. + We won't get to the point where we we would call + check_directed_cycle(tab=t3,beginning=t1) + */ + return FALSE; + } + while ((t= it++)) + { + if (t == beginning) + return true; + if (check_directed_cycle(thd, t, beginning, lvl, max)) + return TRUE; + } + return FALSE; +} + + +/** + @brief + Table @tab has been added to the "LEFT JOIN syntax ordering". Add its + inner-side neighbors first, then add all their connections. + + @param tab Table for which to process + param processed Counter of processed tables. + @param n_tables Total number of tables in the join + + @return + FALSE OK + TRUE Error, found a circular loop in outer join relationships. +*/ + +static bool process_inner_relations(THD* thd, + table_pos *tab, + uint *const processed, + uint n_tables) +{ + if (tab->inner_side.elements > 0) + { + List_iterator_fast it(tab->inner_side); + table_pos *t; + + /* First, add all inner_side neighbors */ + while ((t= it++)) + { + if (t->processed) + { + /* + it is case of "non-cyclic" loop (or just processed already + branch) + + tab->t + ^ + | + t1--+ + (it would be t1 then t then tab and again probe t (from tab)) + + Check if it is also directional loop: + */ + if (check_directed_cycle(thd, t, t, 0, n_tables)) + { + /* + Found a circular dependency: + + t1->tab -> t -+ + ^ | + | | + +--....--+ + */ + my_error(ER_INVALID_USE_OF_ORA_JOIN_CYCLE, MYF(0)); + return TRUE; + } + } + else + insert_element_after(tab, t, processed); + } + + /* Second, process the connections of each neighbor */ + it.rewind(); + while ((t= it++)) + { + if (!t->outer_processed) + { + if (process_outer_relations(thd, t, tab, processed, n_tables)) + return TRUE; + } + } + } + return FALSE; +} + + +/* + @brief + Insert @tab into the "LEFT JOIN syntax ordering" list between @first and + @last. +*/ + +static +void insert_element_between(THD *thd, table_pos *tab, + table_pos *first, table_pos *last, + uint *const processed) +{ + table_pos *curr= last; + + DBUG_ASSERT(first != last); + // find place to insert + while (curr->prev != first && tab->order > curr->prev->order && + !curr->is_outer_of(curr->prev)) + curr= curr->prev; + + insert_element_after(curr->prev, tab, processed); +} + + +/* + @brief + Table @tab has been added to the "LEFT JOIN syntax ordering". Add its + outer-side neighbors and all their connections. + + @param tab Examine tab->outer_side and their connection. + @param first All outer-side connections must be added after "first" and + before the "tab". + + @detail + Outer-side neighbors need to be added *before* the table tab. +*/ + +static bool process_outer_relations(THD* thd, + table_pos *tab, + table_pos *first, + uint * const processed, + uint n_tables) +{ + uchar buff[STACK_BUFF_ALLOC]; // Max argument in function + if (check_stack_overrun(thd, STACK_MIN_SIZE, buff)) + return(TRUE);// Fatal error flag is set! + + tab->outer_processed= TRUE; + if (tab->outer_side.elements) + { + List_iterator_fast it(tab->outer_side); + table_pos *t; + while((t= it++)) + { + if (!t->processed) + { + /* + This (t3 in the example) table serves as inner table for several + others. + + For example we have such dependencies (outer to the right and inner + to the left): + SELECT * + FROM t1,t2,t3,t4 + WHERE t1.a=t2.a(+) AND t2.a=t3.a(+) AND + t4.a=t3.a(+); + + t1->t2-+ + | + +==>t3 + | + t4-----+ + + So we have built following list of left joins already (we + started from the first independent table we have found - t1 + and went by inner_side relation till table t3): + + first + | + *->t1 => t2 => t3 + ^ + | + t->t4 tab + + Now we go by list of unprocessed outer relation of t3 and put + them before t3. + So we have to put t4 between t1 and t2 or between t2 and t3 + (depends on its original position because we + are trying to keep original order where it is possible). + + t1 => t2 => t4 => t3 + + SELECT * + FROM t1 left join t2 on (t1.a=t2.a), + t4 + left join t3 on (t2.a=t3.a and t4.a=t3.a) + + We can also put it before t1, but as far as we have found t1 first + it have definitely early position in the original list of tables + than t4. + */ + insert_element_between(thd, t, first, tab, processed); + if (process_inner_relations(thd, t, processed, n_tables)) + return TRUE; + } + } + } + return process_inner_relations(thd, tab, processed, n_tables); +} + + +#ifndef DBUG_OFF +static void dbug_trace_table_pos(table_pos *t) +{ + DBUG_ENTER("dbug_trace_table_pos"); + DBUG_PRINT("table_pos", ("Table: %s", t->table->alias.str)); + List_iterator_fast iti(t->on_conds); + Item *item; + while ((item= iti++)) + { + StringBuffer expr; + item->print(&expr, QT_ORDINARY); + DBUG_PRINT("INFO", (" On_conds: %s", expr.c_ptr())); + } + List_iterator_fast itot(t->outer_side); + table_pos *tbl; + while ((tbl= itot++)) + DBUG_PRINT("INFO", (" Outer side: %s", tbl->table->alias.str)); + + List_iterator_fast itit(t->inner_side); + while ((tbl= itit++)) + DBUG_PRINT("INFO", (" Inner side: %s", tbl->table->alias.str)); + + DBUG_VOID_RETURN; +} + + +static void dbug_trace_table_entry(const char *prefix, + const char *legend, TABLE_LIST *t) +{ + if (t) + { + StringBuffer expr; + if (t->on_expr) + t->on_expr->print(&expr, QT_ORDINARY); + + DBUG_PRINT(prefix, ("%s Table: '%s' %p outer: %s on_expr: %s", legend, + (t->alias.str ? t->alias.str : ""), t, + (t->outer_join ? "YES" : "no"), + (t->on_expr ? expr.c_ptr() : "NULL"))); + } + else + DBUG_PRINT(prefix, ("%s Table: NULL", legend)); +} + + +static void dbug_trace_table_list(TABLE_LIST *t) +{ + DBUG_ENTER("dbug_trace_table_list"); + dbug_trace_table_entry("TABLE_LIST", "---", t); + dbug_trace_table_entry("INFO", "Embedding", t->embedding); + if (t->join_list) + { + DBUG_PRINT("INFO", ("Join list: %p elements %d", + t->join_list, t->join_list->elements)); + List_iterator_fast it(*t->join_list); + TABLE_LIST *tbl; + while ((tbl= it++)) + { + dbug_trace_table_entry("INFO", "join_list", tbl); + } + } + else + DBUG_PRINT("INFO", ("Join list: NULL")); + + DBUG_VOID_RETURN; +} +#endif + + +/** + @brief + Init array of graph vertexes + + @return + TRUE Error + FALSE Ok, conversion is either done or not needed. +*/ + +static bool init_tables_array(TABLE_LIST *tables, + uint n_tables, + table_pos *tab) +{ + table_pos *t= tab; + TABLE_LIST *table= tables; + uint i= 0; + DBUG_ENTER("init_tables_array"); + + /* + Create a graph vertex for each table. + Also note the original order of tables in the FROM clause. + */ + for (;table; i++, t++, table= table->next_local) + { + DBUG_ASSERT(i < n_tables); + if (table->outer_join || table->nested_join || table->natural_join || + table->embedding || table->straight) + { + // mixed with other JOIN operations + my_error(ER_INVALID_USE_OF_ORA_JOIN_MIX, MYF(0)); + DBUG_RETURN(TRUE); + } + t->next= t->prev= NULL; + t->inner_side.empty(); + t->outer_side.empty(); + t->on_conds.empty(); + t->table= table; + // psergey-todo: can't we keep ora_join_table_no in table_pos? + table->ora_join_table_no= t->order= i; + t->processed= t->outer_processed= FALSE; + } + DBUG_ASSERT(i == n_tables); + DBUG_RETURN(FALSE); +} + + +/** + @brief + Convert Oracle's outer join (+) operators into regular outer join + structures + + @param conds INOUT The WHERE condition + @param select_join_list INOUT Top-level join list + + @return + TRUE Error + FALSE Ok, conversion is either done or not needed. +*/ + +bool setup_oracle_join(THD *thd, Item **conds, + TABLE_LIST *tables, + SQL_I_List &select_table_list, + List *select_join_list, + List *all_fields) +{ + DBUG_ENTER("setup_oracle_join"); + uint n_tables= select_table_list.elements; + uint i= 0; + + if (!(*conds)->with_ora_join() || n_tables == 0) + DBUG_RETURN(FALSE); // no oracle joins + + table_pos *tab= (table_pos *) new(thd->mem_root) table_pos[n_tables]; + if (init_tables_array(tables, n_tables, tab)) + DBUG_RETURN(TRUE); // mixed with other joins + + + /* + Process the WHERE clause: + - Find Outer Join conditions + - Create graph edges from them + - Remove them from the WHERE clause + */ + if (is_cond_and(*conds)) + { + Item_cond_and *and_item= (Item_cond_and *)(*conds); + Item *item; + List_iterator it(*and_item->argument_list()); + while ((item= it++)) + { + if (item->with_ora_join()) + { + if (ora_join_process_expression(thd, item, tab, n_tables)) + DBUG_RETURN(TRUE); + item->walk(&Item::remove_ora_join_processor, 0, 0); + it.remove(); // will be moved to ON + } + } + } + else + { + if ((*conds)->with_ora_join()) + { + if (ora_join_process_expression(thd, (*conds), tab, n_tables)) + DBUG_RETURN(TRUE); + (*conds)->walk(&Item::remove_ora_join_processor, 0, 0); + *conds= NULL; // will be moved to ON + } + } + + /* + Check for inner tables that don't have outer tables; + Prepare for producing the ordering. + */ + List return_to_where; + return_to_where.empty(); + for (i= 0; i < n_tables; i++) + { + if (tab[i].on_conds.elements > 0 && + tab[i].outer_side.elements == 0) + { + /* + This table is marked as INNER but it has no matching OUTER tables. This + can happen for queries like: + + select * from t1,t2 where t2.a(+)=123; + + Issue a warning and move ON condition predicates back to the WHERE. + */ + List_iterator_fast it(tab[i].on_conds); + StringBuffer expr; + Item *item; + while ((item= it++)) + { + expr.set("", 0, system_charset_info); + item->print(&expr, QT_ORDINARY); + push_warning_printf(thd, Sql_condition::WARN_LEVEL_WARN, + WARN_ORA_JOIN_IGNORED, + ER_THD(thd, WARN_ORA_JOIN_IGNORED), + expr.c_ptr()); + + // The item will be moved into the WHERE clause + item->walk(&Item::remove_ora_join_processor, 0, 0); + } + return_to_where.append(&tab[i].on_conds); + tab[i].on_conds.empty(); + } + /* + Sort the outgoing edges in reverse order (those that should come + first are the last). This is because we will do this: + + for each T in tab[i].inner_side + insert_element_after(tab[i], T); + + after which the elements will be in the right order. + */ + if (tab[i].inner_side.elements > 1) + bubble_sort(&tab[i].inner_side, table_pos_sort, NULL); + +#ifndef DBUG_OFF + dbug_trace_table_pos(tab + i); + dbug_trace_table_list(tab[i].table); +#endif + } + + /* + Order the tables according to the "LEFT JOIN syntax order". + */ + table_pos *list= NULL; + table_pos *end= NULL; + uint processed= 0; + i= 0; + do + { + // Find the first independent table + for(; + i < n_tables && (tab[i].processed || tab[i].outer_side.elements != 0); + i++); + if (i >= n_tables) + break; + + // Set (list, end) to point to the list we've collected so far + if (list == NULL) + list= tab + i; + else + { + if (end == NULL) + end= list; + while(end->next) end= end->next; // go to the new end + } + + // Process "sub-graph" with this independent is top of one of branches + insert_element_after(end, tab + i, &processed); + process_inner_relations(thd, tab + i, &processed, n_tables); + } while (i < n_tables); + + if (processed < n_tables) + { + /* + Some tables are not processed but they all have incoming edges. + This can only happen if there are circular dependencies: + + t1 -> t2 -> t3 -+ + ^ | + | | + +--------------+ + */ + my_error(ER_INVALID_USE_OF_ORA_JOIN_CYCLE, MYF(0)); + DBUG_RETURN(TRUE); + } + +#ifndef DBUG_OFF + for (table_pos *t= list; t != NULL; t= t->next) + dbug_trace_table_pos(t); +#endif + + + /* + Now we build new permanent list of table according to our new order + + table1 [left inner] join table2 ... [left inner] join tableN + + which parses in: + + top_join_list of SELECT_LEX + | + nest_tableN-1 --nested_join-> NESTED_JOIN_N-1 + join_list of NESTED_JOIN_N-1 + /\ + tableN nest_tableN-2 + ... + join_list of of NESTED_JOIN_2 + /\ + table3 nest_table1 --nested_join-> NESTED_JOIN_1 + join_list of NESTED_JOIN1 + /\ + table2 table1 + + */ + TABLE_LIST *new_from= list->table; + if (n_tables > 1) // nothing to do with only one table + { + // changes are permanent + Query_arena_stmt on_stmt_arena(thd); + TABLE_LIST *prev_table= list->table; + TABLE_LIST *nest_table_lists; + NESTED_JOIN *nested_joins; + if (!(nest_table_lists= + (TABLE_LIST*)thd->calloc(ALIGN_SIZE(sizeof(TABLE_LIST)) * + (n_tables - 1) + + ALIGN_SIZE(sizeof(NESTED_JOIN)) * + (n_tables - 1)))) + { + DBUG_RETURN(TRUE); // EOM + } + nested_joins= (NESTED_JOIN *)(((char*)nest_table_lists) + + ALIGN_SIZE(sizeof(TABLE_LIST)) * + (n_tables - 1)); + for (uint i= 0; i < n_tables - 1; i++) + { + nest_table_lists[i].nested_join= nested_joins + i; + } + nested_joins[0].join_list.empty(); + nested_joins[0].join_list.push_front(list->table); + DBUG_ASSERT(list->table->embedding == NULL); + list->table->embedding= nest_table_lists; + list->table->join_list= &nested_joins->join_list; + DBUG_ASSERT(list->table->outer_join == 0); + uint i; + table_pos *curr; + for (i=0, curr= list->next; curr; i++, curr= curr->next) + { + DBUG_ASSERT(i <= n_tables - 2); + TABLE_LIST *next_embedding= ((i < n_tables - 2) ? + nest_table_lists + (i+1) : + NULL); + // join type + DBUG_ASSERT(curr->table->outer_join == 0); + DBUG_ASSERT(curr->table->on_expr == 0); + if (curr->outer_side.elements) + { + DBUG_ASSERT(curr->on_conds.elements > 0); + curr->table->outer_join|=JOIN_TYPE_LEFT; + // update maybe_null which was previously set in setup_table_map() + if (curr->table->table) + curr->table->table->maybe_null= JOIN_TYPE_LEFT; + if (curr->on_conds.elements == 1) + { + curr->table->on_expr= curr->on_conds.head(); + } + else + { + Item *item= new(thd->mem_root) Item_cond_and(thd, curr->on_conds); + if (!item) + DBUG_RETURN(TRUE); + item->top_level_item(); + curr->table->on_expr= item; + /* setup_on_expr() will call fix_fields() for on_expr */ + } + } + else + { + DBUG_ASSERT(curr->on_conds.elements == 0); + } + + // add real table + prev_table->next_local= curr->table; + nested_joins[i].join_list.push_front(curr->table); + DBUG_ASSERT(curr->table->embedding == NULL); + curr->table->embedding= nest_table_lists + i; + curr->table->join_list= &nested_joins[i].join_list; + // prepare fake table + nest_table_lists[i].alias= {STRING_WITH_LEN("(nest_last_join)")}; + nest_table_lists[i].embedding= next_embedding; + + if (next_embedding) + { + nested_joins[i+1].join_list.empty(); + nested_joins[i+1].join_list.push_front(nest_table_lists + i); + nest_table_lists[i].join_list= &nested_joins[i + 1].join_list; + } + else + { + DBUG_ASSERT(i == n_tables - 2); + // all tables should be there because query was without JOIN + // operators except oracle ones + DBUG_ASSERT(select_join_list->elements == n_tables); + select_join_list->empty(); + select_join_list->push_front(nest_table_lists + i); + nest_table_lists[i].join_list= select_join_list; + } + + prev_table= curr->table; + } + prev_table->next_local= NULL; + select_table_list.first= new_from; + select_table_list.next= &prev_table->next_local; + } + + DBUG_PRINT("INFO", ("new FROM clause: %p", new_from)); +#ifndef DBUG_OFF + for (TABLE_LIST *t= new_from; t; t= t->next_local) + { + dbug_trace_table_list(t); + } +#endif + + if (add_conditions_to_where(thd, conds, std::move(return_to_where))) + DBUG_RETURN(TRUE); + + // Refresh nullability of already fixed parts: + + // WHERE + if (conds[0]) + { + conds[0]->update_used_tables(); + conds[0]->walk(&Item::add_maybe_null_after_ora_join_processor, 0, 0); + } + // SELECT list and hidden fields + if (all_fields) + { + List_iterator it(*all_fields); + Item *item; + while((item= it++)) + { + item->update_used_tables(); + item->walk(&Item::add_maybe_null_after_ora_join_processor, 0, 0); + } + } + // parts of WHERE moved to ON (original ONs will be fixed later) + for (i= 0; i < n_tables; i++) + { + // we have to count becaust this lists are included in other lists + List_iterator it(*all_fields); + Item *item; + for (uint j= 0; j < tab[i].on_conds.elements && (item= it++); j++) + { + item->update_used_tables(); + item->walk(&Item::add_maybe_null_after_ora_join_processor, 0, 0); + } + } + + DBUG_RETURN(FALSE); +} + + +/* + @brief + Add conditions from return_to_where into *conds. + Then, normalize *conds: it can be an Item_cond_and with one or zero + children. + + @return + false OK + true Fatal error +*/ + +static bool add_conditions_to_where(THD *thd, Item **conds, + List &&return_to_where) +{ + // Make changes on statement's mem_root + Query_arena_stmt on_stmt_arena(thd); + uint number_of_cond_parts= return_to_where.elements; + if ((*conds) != NULL) + { + if (is_cond_and(*conds)) + { + uint elements= ((Item_cond_and *)(*conds))->argument_list()->elements; + switch (elements) + { + case 0: + (*conds)= NULL; + break; + case 1: + (*conds)= ((Item_cond_and *)(*conds))->argument_list()->head(); + number_of_cond_parts++; + break; + default: + number_of_cond_parts+= elements; + } + } + else + number_of_cond_parts++; + } + + if (number_of_cond_parts == 0) + { + /* Nothing is left in the WHERE */ + DBUG_ASSERT((*conds) == NULL); + } + else if (number_of_cond_parts == 1) + { + if ((*conds) == NULL) + { + DBUG_ASSERT(return_to_where.elements == 1); + (*conds)= return_to_where.head(); + } + else + { + // There is one remaining condition, it's in *conds. + DBUG_ASSERT(return_to_where.elements == 0); + DBUG_ASSERT((*conds) != NULL); + } + } + else + { + if ((*conds) == NULL || !is_cond_and(*conds)) + { + if (*conds) + return_to_where.push_back(*conds); + } + else + return_to_where.append(((Item_cond_and *)(*conds))->argument_list()); + + if (!((*conds)= new(thd->mem_root) Item_cond_and(thd, return_to_where))) + return true; + (*conds)->top_level_item(); + if ((*conds)->fix_fields(thd, conds)) + return true; + } + return false; +} + diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 2875a80895a..47ab4b3133a 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -954,7 +954,7 @@ setup_without_group(THD *thd, Ref_ptr_array ref_pointer_array, DBUG_ENTER("setup_without_group"); thd->lex->allow_sum_func.clear_bit(select->nest_level); - res= setup_conds(thd, tables, leaves, conds); + res= setup_conds(thd, tables, leaves, conds, &all_fields); /* it's not wrong to have non-aggregated columns in a WHERE */ select->set_non_agg_field_used(saved_non_agg_field_used); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 5b6f7507b58..11675d88101 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1594,6 +1594,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, size_t *yystacksize); %type expr_list opt_udf_expr_list udf_expr_list when_list when_list_opt_else ident_list ident_list_arg opt_expr_list + opt_udf_expr_list_or_join_operator + opt_expr_list_or_join_operator execute_using execute_params opt_sp_cparam_list @@ -11015,23 +11017,28 @@ function_call_generic: #ifdef HAVE_DLOPEN udf_func *udf= 0; LEX *lex= Lex; - Lex_ident_sys ident(thd, &$1); - - if (using_udf_functions && - (udf= find_udf(ident.str, ident.length)) && - udf->type == UDFTYPE_AGGREGATE) + if (using_udf_functions) { - if (unlikely(lex->current_select->inc_in_sum_expr())) + // find_udf expectes a 0-terminated string + const Lex_ident_sys sysname(thd, &$1); + if (sysname.is_null()) + MYSQL_YYABORT; // EOM + if ((udf= find_udf(sysname.str, sysname.length)) && + udf->type == UDFTYPE_AGGREGATE) { - thd->parse_error(); - MYSQL_YYABORT; + if (unlikely(lex->current_select->inc_in_sum_expr())) + { + thd->parse_error(); + MYSQL_YYABORT; + } } } /* Temporary placing the result of find_udf in $3 */ $$= udf; #endif } - opt_udf_expr_list ')' opt_object_member_access + + opt_udf_expr_list_or_join_operator ')' opt_object_member_access { const Type_handler *h; Create_func *builder; @@ -11055,9 +11062,19 @@ function_call_generic: This will be revised with WL#2128 (SQL PATH) */ - builder= Schema::find_implied(thd)-> - find_native_function_builder(thd, ident); - if (builder) + if ($4 && $4->elements == 1 && + dynamic_cast($4->head())) + { + if ($6.str) + { + thd->parse_error(); + MYSQL_YYABORT; + } + item= Lex->create_item_ident(thd, &$1); + if (!item || Lex->mark_item_ident_for_ora_join(thd, item)) + MYSQL_YYABORT; + } else if ((builder= Schema::find_implied(thd)-> + find_native_function_builder(thd, ident))) { item= builder->create_func(thd, &ident, $4); } @@ -11139,7 +11156,7 @@ function_call_generic: $1, $3))) MYSQL_YYABORT; } - | ident_cli '.' ident_cli '(' opt_expr_list ')' + | ident_cli '.' ident_cli '(' opt_expr_list_or_join_operator ')' { const Lex_ident_cli pos($1.pos(), $6.pos() - $1.pos() + 1); if (unlikely(!($$= Lex->make_item_func_or_method_call(thd, $1, @@ -11147,7 +11164,21 @@ function_call_generic: pos)))) MYSQL_YYABORT; } - | ident_cli '.' ident_cli '.' ident_cli '(' opt_expr_list ')' + | '.' ident_cli '.' ident_cli '(' '+' ')' + { + /* + This grammar branch is needed for symmetry with simple_ident, + to handle Oracle style outer join: + WHERE t1.a = .t2.a(+) + */ + Lex_ident_cli empty($2.pos(), 0); + List *list= Item_join_operator_plus::make_as_item_list(thd); + if (unlikely( + !list || + !($$= Lex->make_item_func_call_generic(thd, &empty, &$2, &$4, list)))) + MYSQL_YYABORT; + } + | ident_cli '.' ident_cli '.' ident_cli '(' opt_expr_list_or_join_operator ')' { if (unlikely(!($$= Lex->make_item_func_call_generic(thd, &$1, &$3, &$5, $7)))) MYSQL_YYABORT; @@ -11221,6 +11252,19 @@ opt_udf_expr_list: %endif ; +opt_udf_expr_list_or_join_operator: + opt_udf_expr_list + | remember_name '+' remember_end + { + /* + remember_name and remember_end are needed here + to avoid a shift/reduce conflict with the rule udf_expr. + */ + if (!($$= Item_join_operator_plus::make_as_item_list(thd))) + MYSQL_YYABORT; + } + ; + udf_expr_list: udf_expr { @@ -11865,6 +11909,15 @@ opt_expr_list: | expr_list { $$= $1;} ; +opt_expr_list_or_join_operator: + opt_expr_list + | '+' + { + if (!($$= Item_join_operator_plus::make_as_item_list(thd))) + MYSQL_YYABORT; + } + ; + expr_list: expr { @@ -16006,7 +16059,6 @@ order_ident: expr { $$=$1; } ; - simple_ident: ident_cli { diff --git a/sql/table.cc b/sql/table.cc index 8d9195505f6..07d71b47fdb 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -10643,7 +10643,7 @@ bool TR_table::query(ulonglong trx_id) Item *field= newx Item_field(thd, &slex.context, (*this)[FLD_TRX_ID]); Item *value= newx Item_int(thd, trx_id); COND *conds= newx Item_func_eq(thd, field, value); - if (unlikely((error= setup_conds(thd, this, dummy, &conds)))) + if (unlikely((error= setup_conds(thd, this, dummy, &conds, NULL)))) return false; select= make_select(table, 0, 0, conds, NULL, 0, &error); if (unlikely(error || !select)) @@ -10682,7 +10682,7 @@ bool TR_table::query(MYSQL_TIME &commit_time, bool backwards) conds= newx Item_func_ge(thd, field, value); else conds= newx Item_func_le(thd, field, value); - if (unlikely((error= setup_conds(thd, this, dummy, &conds)))) + if (unlikely((error= setup_conds(thd, this, dummy, &conds, NULL)))) return false; // FIXME: (performance) force index 'commit_timestamp' select= make_select(table, 0, 0, conds, NULL, 0, &error); diff --git a/sql/table.h b/sql/table.h index 4ca30274823..a4d851d56ee 100644 --- a/sql/table.h +++ b/sql/table.h @@ -2608,6 +2608,7 @@ struct TABLE_LIST Item_in_subselect *jtbm_subselect; /* TODO: check if this can be joined with tablenr_exec */ uint jtbm_table_no; + uint ora_join_table_no; SJ_MATERIALIZATION_INFO *sj_mat_info;