Skip to content

Commit

Permalink
Bug#21350125: Wrong results when ORDER BY is removed
Browse files Browse the repository at this point in the history
This is a regression from the bug fix for bug no. 14358878.
The fix for that bug was basically to add the nullable property
for any Item_direct_view_ref object that would wrap an Item
selected from a derived table/view reference placed on the
inner side of an outer join, and letting the null value be
calculated at run time by looking at the NULL status of the first
table of the derived table.

This works well when the derived table is a single table, or an
inner join, or a left outer join. However, if the derived table
is itself a right outer join, the first table of the derived table
may be the inner table of the right outer join, and that table may
contain a NULL row even though the derived table as a whole is
producing a row.

Thus, we can get a NULL indication even though the derived table
is producing a row, if the inner table of the right outer join that
is part of that derived table is null-extended.

The solution to the problem is to locate a table within the
derived table that is not outer-joined within the derived table,
ie locate a table that does not have the outer_join property set.
A new function TABLE_LIST::any_outer_leaf_table() is implemented
to locate such a table.

Notice that this bug is limited to derived tables: A view has the
same properties as a derived table, but there is one important
difference: When the view is created, its join nests are normalized
so that right joins are converted into left joins. Hence, the
first table of the derived table nest will always be an "outer" table,
which is good for our calculation. An alternative solution might thus
be to normalize derived tables like views.

(Derived tables are indeed right-join normalized, but the normalization
is limited to the join_list structures, and not the table_list
structures, which are used when navigating tables contained in
a view/derived table. Whereas views are normalized when written to
stored dictionary and table_list is reconstructed based on the
normalized form when view is included into a query.)
  • Loading branch information
roylyseng committed Sep 11, 2015
1 parent 5497302 commit 4c4d41c
Show file tree
Hide file tree
Showing 5 changed files with 275 additions and 2 deletions.
155 changes: 155 additions & 0 deletions mysql-test/r/derived.result
Original file line number Diff line number Diff line change
Expand Up @@ -3548,3 +3548,158 @@ GROUP BY JSON_QUOTE(JSON_EXTRACT(field1,'$.intc'))
field1
set sql_mode=default;
DROP TABLE t1, t2;
# Bug#21350125: Wrong results when ORDER BY is removed
CREATE TABLE t1 (
c1n varchar(1) NOT NULL,
c1k varchar(2) DEFAULT NULL,
KEY c1k (c1k)
);
INSERT INTO t1 VALUES ('j','jj'),('r','rr');
CREATE TABLE t2 (
c2k varchar(1) NOT NULL,
c2n varchar(2) DEFAULT NULL,
KEY c2k (c2k)
);
INSERT INTO t2 VALUES
('f','ff'),('t','tt'),('c','cc'),('c','cc'),('r','rr'),('k','kk');
CREATE TABLE empty (dummy INTEGER);
CREATE VIEW vr AS
SELECT t2.c2n AS v_field
FROM t1 RIGHT JOIN t2
ON t2.c2k = t1.c1k;
CREATE VIEW vl AS
SELECT t2.c2n AS v_field
FROM t2 LEFT JOIN t1
ON t2.c2k = t1.c1k;
SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN t2
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;
field1
ff
tt
cc
cc
cc
cc
rr
kk
prepare s from 'SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN t2
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field';
execute s;
field1
ff
tt
cc
cc
cc
cc
rr
kk
deallocate prepare s;
SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t2 LEFT JOIN t1
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;
field1
ff
tt
cc
cc
cc
cc
rr
kk
prepare s from 'SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t2 LEFT JOIN t1
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field';
execute s;
field1
ff
tt
cc
cc
cc
cc
rr
kk
deallocate prepare s;
SELECT alias1.v_field AS field1
FROM vl AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.v_field;
field1
ff
tt
cc
cc
cc
cc
rr
kk
SELECT alias1.v_field AS field1
FROM vr AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.v_field;
field1
ff
tt
cc
cc
cc
cc
rr
kk
SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN
(empty RIGHT JOIN t2
ON TRUE)
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;
field1
ff
tt
cc
cc
cc
cc
rr
kk
SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN
(t2 LEFT JOIN empty
ON TRUE)
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;
field1
ff
tt
cc
cc
cc
cc
rr
kk
DROP VIEW vl, vr;
DROP TABLE t1, t2, empty;
100 changes: 100 additions & 0 deletions mysql-test/t/derived.test
Original file line number Diff line number Diff line change
Expand Up @@ -2426,3 +2426,103 @@ set sql_mode=default;

DROP TABLE t1, t2;

--echo # Bug#21350125: Wrong results when ORDER BY is removed

CREATE TABLE t1 (
c1n varchar(1) NOT NULL,
c1k varchar(2) DEFAULT NULL,
KEY c1k (c1k)
);

INSERT INTO t1 VALUES ('j','jj'),('r','rr');

CREATE TABLE t2 (
c2k varchar(1) NOT NULL,
c2n varchar(2) DEFAULT NULL,
KEY c2k (c2k)
);

INSERT INTO t2 VALUES
('f','ff'),('t','tt'),('c','cc'),('c','cc'),('r','rr'),('k','kk');

CREATE TABLE empty (dummy INTEGER);

CREATE VIEW vr AS
SELECT t2.c2n AS v_field
FROM t1 RIGHT JOIN t2
ON t2.c2k = t1.c1k;

CREATE VIEW vl AS
SELECT t2.c2n AS v_field
FROM t2 LEFT JOIN t1
ON t2.c2k = t1.c1k;

# Check with derived tables, and that LEFT JOIN and RIGHT JOIN are equivalent.
# Check prepared statements too.

let $query=
SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN t2
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;

eval $query;
eval prepare s from '$query';

execute s;
deallocate prepare s;

let $query=
SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t2 LEFT JOIN t1
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;

eval $query;
eval prepare s from '$query';

execute s;
deallocate prepare s;

# Check that use of views give same result as derived tables.

SELECT alias1.v_field AS field1
FROM vl AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.v_field;

SELECT alias1.v_field AS field1
FROM vr AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.v_field;

# Check more complicated join nests

SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN
(empty RIGHT JOIN t2
ON TRUE)
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;

SELECT alias1.dt_field AS field1
FROM (SELECT t2.c2n AS dt_field
FROM t1 RIGHT JOIN
(t2 LEFT JOIN empty
ON TRUE)
ON t2.c2k = t1.c1k
) AS alias1
RIGHT JOIN t2 AS alias2
ON alias2.c2n = alias1.dt_field;

DROP VIEW vl, vr;
DROP TABLE t1, t2, empty;
2 changes: 1 addition & 1 deletion sql/item.cc
Original file line number Diff line number Diff line change
Expand Up @@ -8659,7 +8659,7 @@ bool Item_direct_view_ref::fix_fields(THD *thd, Item **reference)
if (cached_table->is_inner_table_of_outer_join())
{
maybe_null= true;
first_inner_table= cached_table->first_leaf_table();
first_inner_table= cached_table->any_outer_leaf_table();
// @todo delete this when WL#6570 is implemented
(*ref)->maybe_null= true;
}
Expand Down
2 changes: 1 addition & 1 deletion sql/item.h
Original file line number Diff line number Diff line change
Expand Up @@ -4204,7 +4204,7 @@ class Item_direct_view_ref :public Item_direct_ref
if (cached_table->is_inner_table_of_outer_join())
{
maybe_null= true;
first_inner_table= cached_table->first_leaf_table();
first_inner_table= cached_table->any_outer_leaf_table();
// @todo delete this when WL#6570 is implemented
(*ref)->maybe_null= true;
}
Expand Down
18 changes: 18 additions & 0 deletions sql/table.h
Original file line number Diff line number Diff line change
Expand Up @@ -1918,6 +1918,24 @@ struct TABLE_LIST
tr= tr->merge_underlying_list;
return tr;
}

/// Return any leaf table that is not an inner table of an outer join
/// @todo when WL#6570 is implemented, replace with first_leaf_table()
TABLE_LIST *any_outer_leaf_table()
{
TABLE_LIST *tr= this;
while (tr->merge_underlying_list)
{
tr= tr->merge_underlying_list;
/*
"while" is used, however, an "if" might be sufficient since there is
no more than one inner table in a join nest (with outer_join true).
*/
while (tr->outer_join)
tr= tr->next_local;
}
return tr;
}
/**
Set the LEX object of a view (will also define this as a view).
@note: The value 1 is used to indicate a view but without a valid
Expand Down

0 comments on commit 4c4d41c

Please sign in to comment.