Commit 4e59d30d authored by unknown's avatar unknown

Fix for BUG#21007.

The problem was that store_top_level_join_columns() incorrectly assumed
that the left/right neighbor of a nested join table reference can be only
at the same level in the join tree.

The fix checks if the current nested join table reference has no immediate
left/right neighbor, and if so chooses the left/right neighbors of the
nearest upper level, where these references are != NULL.


mysql-test/r/group_min_max.result:
  Test for BUG#21007.
mysql-test/t/group_min_max.test:
  Test for BUG#21007.
sql/sql_base.cc:
  After computing and materializing the columns of all NATURAL joins in a FROM clause,
  the procedure store_top_level_join_columns() has to change the current natural join
  into a leaf table reference for name resolution. For this it needs to make the left
  neighbor point to the natural join table reference, and the natural join itself point
  to its left neighbor.
  
  This fix correctly determines the left/right neighbors of a table reference, even if
  the neghbors are at higher levels in the nested join tree. The rule is that if a table
  reference has no immediate left/right neighbors, we recursively pick the left/right
  neighbor of the level(s) above.
parent 8f5681c9
...@@ -2099,3 +2099,46 @@ SOUTH EAST SOUTH EAST ...@@ -2099,3 +2099,46 @@ SOUTH EAST SOUTH EAST
SOUTH WEST SOUTH WEST SOUTH WEST SOUTH WEST
WESTERN WESTERN WESTERN WESTERN
DROP TABLE t1; DROP TABLE t1;
CREATE TABLE t1 (id1 INT, id2 INT);
CREATE TABLE t2 (id2 INT, id3 INT, id5 INT);
CREATE TABLE t3 (id3 INT, id4 INT);
CREATE TABLE t4 (id4 INT);
CREATE TABLE t5 (id5 INT, id6 INT);
CREATE TABLE t6 (id6 INT);
INSERT INTO t1 VALUES(1,1);
INSERT INTO t2 VALUES(1,1,1);
INSERT INTO t3 VALUES(1,1);
INSERT INTO t4 VALUES(1);
INSERT INTO t5 VALUES(1,1);
INSERT INTO t6 VALUES(1);
SELECT * FROM
t1
NATURAL JOIN
(t2 JOIN (t3 NATURAL JOIN t4, t5 NATURAL JOIN t6)
ON (t3.id3 = t2.id3 AND t5.id5 = t2.id5));
id2 id1 id3 id5 id4 id3 id6 id5
1 1 1 1 1 1 1 1
SELECT * FROM
t1
NATURAL JOIN
(((t3 NATURAL JOIN t4) join (t5 NATURAL JOIN t6) on t3.id4 = t5.id5) JOIN t2
ON (t3.id3 = t2.id3 AND t5.id5 = t2.id5));
id2 id1 id4 id3 id6 id5 id3 id5
1 1 1 1 1 1 1 1
SELECT * FROM t1 NATURAL JOIN ((t3 join (t5 NATURAL JOIN t6)) JOIN t2);
id2 id1 id3 id4 id6 id5 id3 id5
1 1 1 1 1 1 1 1
SELECT * FROM
(t2 JOIN (t3 NATURAL JOIN t4, t5 NATURAL JOIN t6)
ON (t3.id3 = t2.id3 AND t5.id5 = t2.id5))
NATURAL JOIN
t1;
id2 id3 id5 id4 id3 id6 id5 id1
1 1 1 1 1 1 1 1
SELECT * FROM
(t2 JOIN ((t3 NATURAL JOIN t4) join (t5 NATURAL JOIN t6)))
NATURAL JOIN
t1;
id2 id3 id5 id4 id3 id6 id5 id1
1 1 1 1 1 1 1 1
DROP TABLE t1,t2,t3,t4,t5,t6;
...@@ -746,3 +746,51 @@ EXPLAIN SELECT DISTINCT a,a FROM t1 ORDER BY a; ...@@ -746,3 +746,51 @@ EXPLAIN SELECT DISTINCT a,a FROM t1 ORDER BY a;
SELECT DISTINCT a,a FROM t1 ORDER BY a; SELECT DISTINCT a,a FROM t1 ORDER BY a;
DROP TABLE t1; DROP TABLE t1;
#
# Bug #21007: NATURAL JOIN (any JOIN (2 x NATURAL JOIN)) crashes the server
#
CREATE TABLE t1 (id1 INT, id2 INT);
CREATE TABLE t2 (id2 INT, id3 INT, id5 INT);
CREATE TABLE t3 (id3 INT, id4 INT);
CREATE TABLE t4 (id4 INT);
CREATE TABLE t5 (id5 INT, id6 INT);
CREATE TABLE t6 (id6 INT);
INSERT INTO t1 VALUES(1,1);
INSERT INTO t2 VALUES(1,1,1);
INSERT INTO t3 VALUES(1,1);
INSERT INTO t4 VALUES(1);
INSERT INTO t5 VALUES(1,1);
INSERT INTO t6 VALUES(1);
-- original bug query
SELECT * FROM
t1
NATURAL JOIN
(t2 JOIN (t3 NATURAL JOIN t4, t5 NATURAL JOIN t6)
ON (t3.id3 = t2.id3 AND t5.id5 = t2.id5));
-- inner join swapped
SELECT * FROM
t1
NATURAL JOIN
(((t3 NATURAL JOIN t4) join (t5 NATURAL JOIN t6) on t3.id4 = t5.id5) JOIN t2
ON (t3.id3 = t2.id3 AND t5.id5 = t2.id5));
-- one join less, no ON cond
SELECT * FROM t1 NATURAL JOIN ((t3 join (t5 NATURAL JOIN t6)) JOIN t2);
-- wrong error message: 'id2' - ambiguous column
SELECT * FROM
(t2 JOIN (t3 NATURAL JOIN t4, t5 NATURAL JOIN t6)
ON (t3.id3 = t2.id3 AND t5.id5 = t2.id5))
NATURAL JOIN
t1;
SELECT * FROM
(t2 JOIN ((t3 NATURAL JOIN t4) join (t5 NATURAL JOIN t6)))
NATURAL JOIN
t1;
DROP TABLE t1,t2,t3,t4,t5,t6;
...@@ -4041,36 +4041,48 @@ store_top_level_join_columns(THD *thd, TABLE_LIST *table_ref, ...@@ -4041,36 +4041,48 @@ store_top_level_join_columns(THD *thd, TABLE_LIST *table_ref,
if (table_ref->nested_join) if (table_ref->nested_join)
{ {
List_iterator_fast<TABLE_LIST> nested_it(table_ref->nested_join->join_list); List_iterator_fast<TABLE_LIST> nested_it(table_ref->nested_join->join_list);
TABLE_LIST *cur_left_neighbor= nested_it++; TABLE_LIST *same_level_left_neighbor= nested_it++;
TABLE_LIST *cur_right_neighbor= NULL; TABLE_LIST *same_level_right_neighbor= NULL;
/* Left/right-most neighbors, possibly at higher levels in the join tree. */
TABLE_LIST *real_left_neighbor, *real_right_neighbor;
while (cur_left_neighbor) while (same_level_left_neighbor)
{ {
TABLE_LIST *cur_table_ref= cur_left_neighbor; TABLE_LIST *cur_table_ref= same_level_left_neighbor;
cur_left_neighbor= nested_it++; same_level_left_neighbor= nested_it++;
/* /*
The order of RIGHT JOIN operands is reversed in 'join list' to The order of RIGHT JOIN operands is reversed in 'join list' to
transform it into a LEFT JOIN. However, in this procedure we need transform it into a LEFT JOIN. However, in this procedure we need
the join operands in their lexical order, so below we reverse the the join operands in their lexical order, so below we reverse the
join operands. Notice that this happens only in the first loop, and join operands. Notice that this happens only in the first loop,
not in the second one, as in the second loop cur_left_neighbor == NULL. and not in the second one, as in the second loop
This is the correct behavior, because the second loop same_level_left_neighbor == NULL.
sets cur_table_ref reference correctly after the join operands are This is the correct behavior, because the second loop sets
cur_table_ref reference correctly after the join operands are
swapped in the first loop. swapped in the first loop.
*/ */
if (cur_left_neighbor && if (same_level_left_neighbor &&
cur_table_ref->outer_join & JOIN_TYPE_RIGHT) cur_table_ref->outer_join & JOIN_TYPE_RIGHT)
{ {
/* This can happen only for JOIN ... ON. */ /* This can happen only for JOIN ... ON. */
DBUG_ASSERT(table_ref->nested_join->join_list.elements == 2); DBUG_ASSERT(table_ref->nested_join->join_list.elements == 2);
swap_variables(TABLE_LIST*, cur_left_neighbor, cur_table_ref); swap_variables(TABLE_LIST*, same_level_left_neighbor, cur_table_ref);
} }
/*
Pick the parent's left and right neighbors if there are no immediate
neighbors at the same level.
*/
real_left_neighbor= (same_level_left_neighbor) ?
same_level_left_neighbor : left_neighbor;
real_right_neighbor= (same_level_right_neighbor) ?
same_level_right_neighbor : right_neighbor;
if (cur_table_ref->nested_join && if (cur_table_ref->nested_join &&
store_top_level_join_columns(thd, cur_table_ref, store_top_level_join_columns(thd, cur_table_ref,
cur_left_neighbor, cur_right_neighbor)) real_left_neighbor, real_right_neighbor))
goto err; goto err;
cur_right_neighbor= cur_table_ref; same_level_right_neighbor= cur_table_ref;
} }
} }
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment