From 6726f7c58f35ad6407370bc3ca06961776671a9e Mon Sep 17 00:00:00 2001 From: Iqbal Hassan Date: Mon, 23 Dec 2024 00:11:26 +0800 Subject: [PATCH] MDEV-13817: Add support for oracle's left join syntax - the ( + ) in sql_mode=oracle This implements the support for oracle's left join syntax by transforming the where clause of the query to a join condition in the parser. --- .../compat/oracle/r/oracle_outer_join.result | 272 +++++++++ .../compat/oracle/t/oracle_outer_join.test | 241 ++++++++ sql/item.h | 5 +- sql/lex.h | 1 + sql/share/errmsg-utf8.txt | 6 +- sql/sql_lex.cc | 30 + sql/sql_lex.h | 2 + sql/sql_parse.cc | 524 ++++++++++++++++++ sql/sql_parse.h | 2 + sql/sql_yacc.yy | 36 +- 10 files changed, 1108 insertions(+), 11 deletions(-) create mode 100644 mysql-test/suite/compat/oracle/r/oracle_outer_join.result create mode 100644 mysql-test/suite/compat/oracle/t/oracle_outer_join.test diff --git a/mysql-test/suite/compat/oracle/r/oracle_outer_join.result b/mysql-test/suite/compat/oracle/r/oracle_outer_join.result new file mode 100644 index 0000000000000..0073aec65cee0 --- /dev/null +++ b/mysql-test/suite/compat/oracle/r/oracle_outer_join.result @@ -0,0 +1,272 @@ +# +# MDEV-13817 add support for oracle's left join syntax - the ( + ) +# +SET sql_mode=ORACLE; +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 +# +# 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 +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 +# +# Use unmarked fields in OR condition +# +SELECT * FROM tj2,tj1 WHERE tj1.a = tj2.c(+) AND (tj2.d=3 OR tj2.d * 2=3); +a b c d +2 2 2 3 +# +# 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 +# +# Use different tables per `AND` operand +# +SELECT * FROM tj1,tj2,tj3 WHERE tj1.a = tj2.c(+) AND tj1.a = tj3.e(+); +a b e f c d +2 2 NULL NULL 2 3 +1 1 1 4 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 e f c d +1 1 1 4 2 3 +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(+); +e f a b c d +1 4 1 1 2 3 +1 4 2 2 NULL NULL +# +# 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 +# +# Table not referenced in where condition (must be cross-joined) +# +SELECT * FROM tj1, tj2, tj3 WHERE tj1.a + 1 = tj2.c(+); +a b e f c d +1 1 1 4 2 3 +2 2 1 4 NULL NULL +# +# 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; +ERROR HY000: Invalid usage of (+) operator +# +# 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 +# +# 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. +# +SELECT * FROM tj1, tj2 WHERE tj2.c(+) = 1; +a b c d +1 1 NULL NULL +2 2 NULL NULL +SELECT * FROM tj1, tj2 WHERE tj1.a(+) = 1; +c d a b +2 3 1 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 +SELECT * FROM tj1, tj2 WHERE tj1.a NOT IN (tj2.c(+), tj2.d(+)); +ERROR HY000: Invalid usage of (+) operator +# +# 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 +SELECT * FROM tj1 INNER JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +ERROR HY000: Invalid usage of (+) operator +SELECT * FROM tj1 NATURAL JOIN tj2 WHERE tj1.a = tj2.c(+); +ERROR HY000: Invalid usage of (+) operator +# +# 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 42S02: Unknown table 'tj3' +# +# '.' 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; +a b c d +3 3 2 3 +4 4 NULL NULL +# +# DB qualifed ident with oracle outer join (non-aliased) +# +SELECT * FROM test.tj2, tj1 WHERE test.tj2.c(+) = tj1.a - 1; +a b c d +3 3 2 3 +4 4 NULL NULL +# +# 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 42S02: Unknown table 'tj2' +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; diff --git a/mysql-test/suite/compat/oracle/t/oracle_outer_join.test b/mysql-test/suite/compat/oracle/t/oracle_outer_join.test new file mode 100644 index 0000000000000..a75db2cc9c92e --- /dev/null +++ b/mysql-test/suite/compat/oracle/t/oracle_outer_join.test @@ -0,0 +1,241 @@ +--echo # +--echo # MDEV-13817 add support for oracle's left join syntax - the ( + ) +--echo # + +SET sql_mode=ORACLE; + + +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; + +--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 +SELECT * FROM tj2,tj1 WHERE tj1.a = tj2.c(+) OR tj2.d=4; +--error ER_INVALID_USE_OF_ORA_JOIN +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 +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 +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 +SELECT * FROM tj1 WHERE tj1.a(+) = 1; + +--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 +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 # +SELECT * FROM tj1, tj2 WHERE tj2.c(+) = 1; +SELECT * FROM tj1, tj2 WHERE tj1.a(+) = 1; + +--echo # +--echo # Outer join in 'IN' condition +--echo # ORA-01719 +--echo # +--error ER_INVALID_USE_OF_ORA_JOIN +SELECT * FROM tj1, tj2 WHERE tj1.a IN (tj2.c(+), tj2.d(+)); +--error ER_INVALID_USE_OF_ORA_JOIN +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 +SELECT * FROM tj1 LEFT JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +--error ER_INVALID_USE_OF_ORA_JOIN +SELECT * FROM tj1 INNER JOIN tj2 ON tj2.c = 1 WHERE tj1.a = tj2.c(+); +--error ER_INVALID_USE_OF_ORA_JOIN +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_TABLE_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_TABLE_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; diff --git a/sql/item.h b/sql/item.h index 0c3589d8a2373..02a2be2d18f81 100644 --- a/sql/item.h +++ b/sql/item.h @@ -791,7 +791,8 @@ enum class item_with_t : item_flags_t SUM_FUNC= (1<<3), // If item contains a sum func SUBQUERY= (1<<4), // If item containts a sub query ROWNUM_FUNC= (1<<5), // If ROWNUM function was used - PARAM= (1<<6) // If user parameter was used + PARAM= (1<<6), // If user parameter was used + ORA_JOIN= (1<<7), // If Oracle join syntax was used }; @@ -1108,6 +1109,8 @@ class Item :public Value_source, { return (bool) (with_flags & item_with_t::ROWNUM_FUNC); } inline bool with_param() const { return (bool) (with_flags & item_with_t::PARAM); } + 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 & diff --git a/sql/lex.h b/sql/lex.h index d420430545f29..df0515f5a5d44 100644 --- a/sql/lex.h +++ b/sql/lex.h @@ -55,6 +55,7 @@ SYMBOL symbols[] = { { "<<", SYM(SHIFT_LEFT)}, { ">>", SYM(SHIFT_RIGHT)}, { "<=>", SYM(EQUAL_SYM)}, + { "(+)", SYM(ORACLE_JOIN)}, { "ACCESSIBLE", SYM(ACCESSIBLE_SYM)}, { "ACCOUNT", SYM(ACCOUNT_SYM)}, { "ACTION", SYM(ACTION)}, diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index adb7227ed8282..41fc66e1092b5 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -10226,10 +10226,8 @@ ER_UNUSED_7 eng "You should never see it" spa "Nunca debería vd de ver esto" sw "Hupaswi kuiona kamwe" -ER_UNUSED_8 - eng "You should never see it" - spa "Nunca debería vd de ver esto" - sw "Hupaswi kuiona kamwe" +ER_INVALID_USE_OF_ORA_JOIN + eng "Invalid usage of (+) operator" ER_DATA_OVERFLOW 22003 chi "转换'%-.128s'到%-.32s时溢出。值截断" eng "Got overflow when converting '%-.128s' to %-.32s. Value truncated" diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 5bf41c2b86381..c6e61bebf261e 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -2067,6 +2067,15 @@ int Lex_input_stream::lex_one_token(YYSTYPE *yylval, THD *thd) next_state= MY_LEX_START; return PERCENT_ORACLE_SYM; } + if (c == '(' && (m_thd->variables.sql_mode & MODE_ORACLE)) + { + if (yyPeek() == '+' && yyPeekn(1) == ')') + { + yySkipn(2); + next_state= MY_LEX_START; + return ORACLE_JOIN; + } + } if (c == '[' && (m_thd->variables.sql_mode & MODE_MSSQL)) return scan_ident_delimited(thd, &yylval->ident_cli, ']'); /* Fall through */ @@ -8604,6 +8613,27 @@ Item *LEX::create_item_ident(THD *thd, } +bool LEX::mark_item_ident_for_ora_join(THD *thd, Item *item) +{ + DBUG_ASSERT(item); + + if (thd->variables.sql_mode & MODE_ORACLE) + { + if (current_select && current_select->parsing_place == IN_WHERE) + { + if (Item_field *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()); diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 47dfdc048ad7f..dd3ccc785a0a5 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -4060,6 +4060,8 @@ struct LEX: public Query_tables_list return a.is_null() ? NULL : create_item_ident(thd, &a, &b, &c); } + bool mark_item_ident_for_ora_join(THD *thd, Item *item); + /* Create an item for "NEXT VALUE FOR sequence_name" */ diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 7513e3e5b8f69..156162049bebb 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -8966,6 +8966,530 @@ Item *normalize_cond(THD *thd, Item *cond) return cond; } +struct Qualified_table_ident: public Sql_alloc +{ + Qualified_table_ident(Lex_ident_db *db, Lex_ident_table *table) + : db(db), + table(table) + { + } + + Qualified_table_ident(TABLE_LIST *table_list) + : db(&table_list->db), + table(&table_list->table_name), + alias(&table_list->alias), + is_alias(table_list->is_alias) + { + } + + int cmp(const Qualified_table_ident &rhs) const + { + auto cs= db->charset_info(); + LEX_CSTRING *lhs_db= db, *rhs_db= rhs.db; + + if (is_alias) + { + if (rhs.is_alias) + return cs->strnncoll(*alias, *rhs.alias); + return cs->strnncoll(*alias, *rhs.table); + } + else if (rhs.is_alias) + { + return cs->strnncoll(*table, *rhs.alias); + } + + if (lhs_db->str == nullptr) + { + lhs_db= ¤t_thd->db; + } + if (rhs_db->str == nullptr) + { + rhs_db= ¤t_thd->db; + } + + auto db_cmp= cs->strnncoll(*lhs_db, *rhs_db); + if (db_cmp == 0) + return cs->strnncoll(*table, *rhs.table); + return db_cmp; + } + + static bool cmp_eq(Qualified_table_ident *a, Qualified_table_ident *b) + { + return a->cmp(*b) == 0; + } + + Lex_ident_db *db; + Lex_ident_table *table; + Lex_ident_table *alias= nullptr; + bool is_alias= false; +}; + +struct Lex_ident_table_cmp_less +{ + bool operator()(const Qualified_table_ident& lhs, + const Qualified_table_ident& rhs) const + { + return lhs.cmp(rhs) < 0; + } +}; + +class Ora_join_enumerator : public Field_enumerator +{ +public: + Ora_join_enumerator(THD *thd): + thd(thd), + marked(new (thd->mem_root) List()), + unmarked(new (thd->mem_root) List()) + { + } + ~Ora_join_enumerator() + { + delete marked; + delete unmarked; + } + + bool initialized() const + { + return marked && unmarked; + } + void visit_field(Item_field *item) override + { + Qualified_table_ident *ident= + new (thd->mem_root) Qualified_table_ident(&item->db_name, + &item->table_name); + if (item->with_ora_join()) + marked->add_unique(ident, Qualified_table_ident::cmp_eq); + else + unmarked->add_unique(ident, Qualified_table_ident::cmp_eq); + } + + THD *thd; + + /* + List of table idents marked with (+) + Ideally we should use table_map type, but we don't have a quick way to + get the map until a field has been created for the Item_field + */ + List *marked; + /* + List of table idents not marked with (+) + */ + List *unmarked; +}; + +struct Ora_join +{ + Ora_join(THD *thd) + : thd(thd), + where(nullptr), + where_and(nullptr) + { + } + + THD *thd; + + std::map, + Lex_ident_table_cmp_less> join_depends; + std::map, + Lex_ident_table_cmp_less> join_conditions; + + /* + The final WHERE clause of the query, this may be NULL if there is no + WHERE clause, or a single item (i.e. Item_func_eq) or a list of items + (Item_cond_and). + */ + Item *where; + + /* + Contains a list of predicates that are ANDed together to form the + WHERE clause of the query. + */ + Item_cond_and *where_and; + + void add_dependency(Qualified_table_ident &ident, List &depends) + { + auto &deps= join_depends[ident]; + for (auto depend: depends) + deps.push_back(depend); + } + + /* + If parent of the item is Item_cond_and, add the item to the list of + predicates, otherwise assign the item to the where clause as is. + */ + void assign_where(THD *thd, Item *item) + { + if (where_and) + where_and->add(item, thd->mem_root); + else + where= item; + } + + /* + Sort the tables in the query based on the join dependencies + */ + bool sort(THD *thd, List& sorted) const + { + std::map indegree; + + for (auto &pair: join_depends) + { + indegree[pair.first]= 0; + } + + /* + Calculate indegree of each node + */ + for (auto &pair: join_depends) + { + for (auto depend: pair.second) + { + indegree[depend]++; + } + } + + /* + Set of all nodes with no incoming edges + */ + List q; + for (auto &pair: indegree) + { + if (pair.second == 0) + q.push_back(new (thd->mem_root) Qualified_table_ident(pair.first)); + } + + /* + Kahn's algorithm + */ + while (q.elements != 0) + { + auto table= q.pop(); + sorted.push_front(table); + + DBUG_ASSERT(join_depends.count(*table) > 0); + for (auto depend: join_depends.at(*table)) + { + indegree[depend]--; + if (indegree[depend] == 0) + q.push_back(new (thd->mem_root) Qualified_table_ident(depend)); + } + } + + /* + Check for cycles + */ + if (sorted.elements != indegree.size()) + return true; + + return false; + } + + bool traverse(Item *item) + { + if (Item_cond_and *cond_and= dynamic_cast(item)) + { + where_and= new (thd->mem_root) Item_cond_and(thd); + if (!where_and) + return true; + + List* args= cond_and->argument_list(); + List_iterator it(*args); + for (Item *arg= it++; arg; arg= it++) + { + if (traverse(arg)) + return true; + } + + auto count= where_and->argument_list()->elements; + if (count == 1) + where= where_and->argument_list()->head(); + else if (count > 1) + where= where_and; + } + else if (Item_cond_or *cond_or= dynamic_cast(item)) + { + // Ensure that either all or none of the arguments are marked with (+) + List* args= cond_or->argument_list(); + List_iterator it(*args); + List marked; + List unmarked; + for (Item *arg= it++; arg; arg= it++) + { + Ora_join_enumerator c(thd); + if (!c.initialized()) + return true; + arg->walk(&Item::enumerate_field_refs_processor, false, &c); + + if (c.marked->elements == 0) + { + if (marked.elements != 0) + { + /* We can't have a mix of marked and unmarked fields */ + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + } + else if (c.marked->elements > 1) + { + /* We can't have more than one field marked with (+) */ + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + else + marked.add_unique(c.marked->head(), &Qualified_table_ident::cmp_eq); + + /* Create a list of all unmarked fields for dependency tracking */ + List_iterator it(*c.unmarked); + for (auto unmarked_table= it++; unmarked_table; unmarked_table= it++) + unmarked.add_unique(unmarked_table, &Qualified_table_ident::cmp_eq); + } + + if (marked.elements > 1) + { + /* We can't have more than one field marked with (+) */ + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + else if (marked.elements == 1) + { + auto table= marked.head(); + join_conditions[*table].push_back(item); + add_dependency(*table, unmarked); + } + else + { + assign_where(thd, item); + } + } + else + { + Ora_join_enumerator c(thd); + if (!c.initialized()) + return true; + item->walk(&Item::enumerate_field_refs_processor, false, &c); + + if (c.marked->elements == 0) + { + /* We couldn't find any fields marked with (+) */ + assign_where(thd, item); + } + else if (c.marked->elements > 1) + { + /* We can't have more than one field marked with (+) */ + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + else + { + /* We found a field marked with (+) */ + if (dynamic_cast(item)) + { + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + + auto table= c.marked->head(); + join_conditions[*table].push_back(item); + add_dependency(*table, *c.unmarked); + } + } + + return false; + } + + bool has_outer_join() const + { + for (auto &join: join_conditions) + { + if (join.second.size() > 0) + return true; + } + return false; + } +}; + +/* + Transform the select query if the WHERE clause contains (+) operator + into ANSI join syntax (LEFT OUTER JOIN). + + i.e. + SELECT * FROM t1, t2 WHERE t1.a = t2.a (+) AND t1.b = t2.b (+) + is transformed into + SELECT * FROM t1 LEFT OUTER JOIN t2 ON t1.a = t2.a AND t1.b = t2.b + + Not all combinations of (+) operator are allowed, the following + are not allowed: + - (+) operator with IN operator + - (+) operator with OR operator + - Exception to this is when both operands of the OR operator + contain the same table marked with (+) + - (+) operator with multiple tables in the same predicate + - All tables has fields marked with (+) operator (i.e. no tables + without the (+) operator) + In addition, using (+) operator with ANSI joins is not allowed. + Limitations above are similar to Oracle's limitations. + + We traverse the WHERE clause and mark all fields with (+) operator + and each marked predicate will be stored to create the ON clause. + Unmarked predicates are ANDed together to form the WHERE clause, hence the + limitation of (+) operator with OR operator. + + We also track the dependencies between the tables to ensure that + the tables are joined in the correct order. Dependency in this case is defined + as a table that is marked with (+) operator and is used in a predicate + with a table that is not marked with (+) operator. + For example, in the query + SELECT * FROM t1, t2, t3 WHERE t1.a = t2.a (+) AND t2.b = t3.b (+) + t2 is dependent on t1 and t3 is dependent on t2. + +*/ +bool process_ora_outer_join(THD *thd, SELECT_LEX *select, + Item *cond, Item **transformed_cond) +{ + Ora_join j(thd); + + /* + Initialize the map elements with keys from the table_list which contains + aliases and table names + */ + for (TABLE_LIST *ptr= select->table_list.first; ptr; ptr= ptr->next_local) + { + Qualified_table_ident ident(ptr); + j.join_depends[ident]; + j.join_conditions[ident]; + } + + if (j.traverse(cond)) + return true; + + if (!j.has_outer_join()) + return false; + + if (select->table_list.elements == 1) + { + /* We can't use (+) operator when there is only a single table */ + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + + /* + Check if we have ANSI joins + */ + Qualified_table_ident independent(nullptr, nullptr); + for (TABLE_LIST *ptr= select->table_list.first; ptr; ptr= ptr->next_local) + { + if (ptr->on_expr || ptr->natural_join) + { + /* We can't mix (+) with ON or NATURAL JOINs */ + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + + Qualified_table_ident ident(ptr); + + if (j.join_depends[ident].size() == 0 && + j.join_conditions[ident].size() == 0) + independent= ident; + } + + if (independent.table) + { + for (TABLE_LIST *ptr= select->table_list.first; ptr; ptr= ptr->next_local) + { + Qualified_table_ident ident(ptr); + if (j.join_depends[ident].size() == 0 && + j.join_conditions[ident].size() != 0) + { + /* + We have a table with on condition but no dependencies + make it depend on at least one independent table. + */ + j.join_depends[ident].push_back(independent); + } + } + } + + List sorted; + if (j.sort(thd, sorted)) + { + my_error(ER_INVALID_USE_OF_ORA_JOIN, MYF(0)); + return true; + } + + select->join_list->empty(); + + TABLE_LIST *prev= NULL, *prev_name_res= NULL; + List_iterator it(sorted); + for (auto table= it++; table; table= it++) + { + bool found= false; + for (TABLE_LIST *ptr= select->table_list.first; ptr; ptr= ptr->next_local) + { + Qualified_table_ident ident(ptr); + if (table->cmp(ident) == 0) + { + found= true; + ptr->next_name_resolution_table= NULL; + + if (j.join_conditions[*table].size() > 0) + { + select->add_joined_table(ptr); + if (j.join_conditions[*table].size() > 1) + { + /* + We have multiple conditions for this table, we need to + join them together with an AND expression + */ + Item_cond_and *and_expr= new (thd->mem_root) Item_cond_and(thd); + for (Item *item: j.join_conditions[*table]) + { + and_expr->add(item, thd->mem_root); + } + add_join_on(thd, ptr, and_expr); + } + else + { + add_join_on(thd, ptr, j.join_conditions[*table][0]); + } + ptr->on_context= &select->context; + ptr->outer_join|=JOIN_TYPE_LEFT; + + prev= select->nest_last_join(thd); + } + else if (prev) + { + select->add_joined_table(ptr); + prev= select->nest_last_join(thd); + } + else + prev= ptr; + + if (prev_name_res) + prev_name_res->next_name_resolution_table= ptr; + + select->add_joined_table(prev); + prev_name_res= ptr; + + break; + } + } + + if (!found) + { + my_error(ER_BAD_TABLE_ERROR, MYF(0), table->table->str); + return true; + } + + DBUG_ASSERT(prev); + } + + *transformed_cond= j.where; + + return false; +} + /** Add an ON condition to the second operand of a JOIN ... ON. diff --git a/sql/sql_parse.h b/sql/sql_parse.h index f280d3cce8af4..07c8bb1021077 100644 --- a/sql/sql_parse.h +++ b/sql/sql_parse.h @@ -126,6 +126,8 @@ void init_update_queries(void); Item *normalize_cond(THD *thd, Item *cond); Item *negate_expression(THD *thd, Item *expr); bool check_stack_overrun(THD *thd, long margin, uchar *dummy); +bool process_ora_outer_join(THD *thd, SELECT_LEX *select, + Item *cond, Item **transformed_cond); /* Variables */ diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 6a231c32c5998..5f53ecdee8436 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -432,6 +432,7 @@ bool my_yyoverflow(short **a, YYSTYPE **b, size_t *yystacksize); %token AND_AND_SYM /* OPERATOR */ %token DOT_DOT_SYM /* OPERATOR */ %token EQUAL_SYM /* OPERATOR */ +%token ORACLE_JOIN /* OPERATOR */ %token GE /* OPERATOR */ %token LE /* OPERATOR */ %token MYSQL_CONCAT_SYM /* OPERATOR */ @@ -1477,6 +1478,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, size_t *yystacksize); opt_recursive opt_format_xid opt_for_portion_of_time_clause ignorability +%type opt_oracle_join + %type create_or_replace opt_if_not_exists @@ -12431,10 +12434,18 @@ opt_where_clause: search_condition { SELECT_LEX *select= Select; - select->where= normalize_cond(thd, $3); + + Item *cond= $3; + if (thd->variables.sql_mode & MODE_ORACLE) + { + if (unlikely(process_ora_outer_join(thd, select, cond, &cond))) + MYSQL_YYABORT; + } + + select->where= normalize_cond(thd, cond); select->parsing_place= NO_MATTER; - if ($3) - $3->top_level_item(); + if (cond) + cond->top_level_item(); } ; @@ -15785,6 +15796,10 @@ order_ident: expr { $$=$1; } ; +opt_oracle_join: + _empty { $$= 0; } + | ORACLE_JOIN { $$= 1; } + ; simple_ident: ident_cli @@ -15792,21 +15807,30 @@ simple_ident: if (unlikely(!($$= Lex->create_item_ident(thd, &$1)))) MYSQL_YYABORT; } - | ident_cli '.' ident_cli + | ident_cli '.' ident_cli opt_oracle_join { if (unlikely(!($$= Lex->create_item_ident(thd, &$1, &$3)))) MYSQL_YYABORT; + + if ($4 && Lex->mark_item_ident_for_ora_join(thd, $$)) + MYSQL_YYABORT; } - | '.' ident_cli '.' ident_cli + | '.' ident_cli '.' ident_cli opt_oracle_join { Lex_ident_cli empty($2.pos(), 0); if (unlikely(!($$= Lex->create_item_ident(thd, &empty, &$2, &$4)))) MYSQL_YYABORT; + + if ($5 && Lex->mark_item_ident_for_ora_join(thd, $$)) + MYSQL_YYABORT; } - | ident_cli '.' ident_cli '.' ident_cli + | ident_cli '.' ident_cli '.' ident_cli opt_oracle_join { if (unlikely(!($$= Lex->create_item_ident(thd, &$1, &$3, &$5)))) MYSQL_YYABORT; + + if ($6 && Lex->mark_item_ident_for_ora_join(thd, $$)) + MYSQL_YYABORT; } | COLON_ORACLE_SYM ident_cli '.' ident_cli {