Commit 5f81fbb3 authored by unknown's avatar unknown

Fix for BUG#13127.

The problem was in the way table references are pre-filtered when
resolving a qualified field. When resolving qualified table references
we search recursively in the operands of the join. If there is
natural/using join with a merge view, the first call to find_field_in_table_ref
makes a recursive call to itself with the view as the new table reference
to search for the column. However the view has both nested_join and
join_columns != NULL so it skipped the test whether the view name matches
the field qualifier. As a result the field was found in the view since the
view already has a field with the same name. Thus the field was incorrectly
resolved as the view field.


mysql-test/r/select.result:
  Test for BUG#13127.
mysql-test/t/select.test:
  Test for BUG#13127.
sql/sql_base.cc:
  The patch contains two independent changes:
  
  - When searching for qualified fields, include merge views and information schema tables
  used with SHOW (both using TABLE_LIST::field_translation to represent result fields) in
  the test that compares the qualifying table with the name of the table reference being
  searched. This change fixes the bug.
  
  - Do not search the materialized list of columns of a NATURAL/USING join if 'table_list'
  is a stored table or merge view. Instead search directly in the table or view as if it
  is not under a natural join. This is a performance improvement since if 'table_list'
  is a stored table, then the search can utilize the name hash for table names.
parent 8607842e
...@@ -2960,3 +2960,72 @@ x x ...@@ -2960,3 +2960,72 @@ x x
4 4 4 4
4 5 4 5
drop table t1,t2,t3; drop table t1,t2,t3;
create table t1 (id char(16) not null default '', primary key (id));
insert into t1 values ('100'),('101'),('102');
create table t2 (id char(16) default null);
insert into t2 values (1);
create view v1 as select t1.id from t1;
create view v2 as select t2.id from t2;
create view v3 as select (t1.id+2) as id from t1 natural left join t2;
select t1.id from t1 left join v2 using (id);
id
100
101
102
select t1.id from v2 right join t1 using (id);
id
100
101
102
select t1.id from t1 left join v3 using (id);
id
100
101
102
select * from t1 left join v2 using (id);
id
100
101
102
select * from v2 right join t1 using (id);
id
100
101
102
select * from t1 left join v3 using (id);
id
100
101
102
select v1.id from v1 left join v2 using (id);
id
100
101
102
select v1.id from v2 right join v1 using (id);
id
100
101
102
select v1.id from v1 left join v3 using (id);
id
100
101
102
select * from v1 left join v2 using (id);
id
100
101
102
select * from v2 right join v1 using (id);
id
100
101
102
select * from v1 left join v3 using (id);
id
100
101
102
drop table t1, t2;
drop view v1, v2, v3;
...@@ -2535,3 +2535,33 @@ insert into t2 values (1, 1), (2, 1), (3, 3), (4, 6), (5, 6); ...@@ -2535,3 +2535,33 @@ insert into t2 values (1, 1), (2, 1), (3, 3), (4, 6), (5, 6);
insert into t3 values (1), (2), (3), (4), (5); insert into t3 values (1), (2), (3), (4), (5);
select t1.x, t3.x from t1, t2, t3 where t1.x = t2.x and t3.x >= t1.y and t3.x <= t2.y; select t1.x, t3.x from t1, t2, t3 where t1.x = t2.x and t3.x >= t1.y and t3.x <= t2.y;
drop table t1,t2,t3; drop table t1,t2,t3;
#
# Bug #13127 LEFT JOIN against a VIEW returns NULL instead of correct value
#
create table t1 (id char(16) not null default '', primary key (id));
insert into t1 values ('100'),('101'),('102');
create table t2 (id char(16) default null);
insert into t2 values (1);
create view v1 as select t1.id from t1;
create view v2 as select t2.id from t2;
create view v3 as select (t1.id+2) as id from t1 natural left join t2;
# all queries must return the same result
select t1.id from t1 left join v2 using (id);
select t1.id from v2 right join t1 using (id);
select t1.id from t1 left join v3 using (id);
select * from t1 left join v2 using (id);
select * from v2 right join t1 using (id);
select * from t1 left join v3 using (id);
select v1.id from v1 left join v2 using (id);
select v1.id from v2 right join v1 using (id);
select v1.id from v1 left join v3 using (id);
select * from v1 left join v2 using (id);
select * from v2 right join v1 using (id);
select * from v1 left join v3 using (id);
drop table t1, t2;
drop view v1, v2, v3;
...@@ -2948,6 +2948,18 @@ find_field_in_table(THD *thd, TABLE *table, const char *name, uint length, ...@@ -2948,6 +2948,18 @@ find_field_in_table(THD *thd, TABLE *table, const char *name, uint length,
belongs - differs from 'table_list' only for belongs - differs from 'table_list' only for
NATURAL_USING joins. NATURAL_USING joins.
DESCRIPTION
Find a field in a table reference depending on the type of table
reference. There are three types of table references with respect
to the representation of their result columns:
- an array of Field_translator objects for MERGE views and some
information_schema tables,
- an array of Field objects (and possibly a name hash) for stored
tables,
- a list of Natural_join_column objects for NATURAL/USING joins.
This procedure detects the type of the table reference 'table_list'
and calls the corresponding search routine.
RETURN RETURN
0 field is not found 0 field is not found
view_ref_found found value in VIEW (real result is in *ref) view_ref_found found value in VIEW (real result is in *ref)
...@@ -2971,16 +2983,30 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list, ...@@ -2971,16 +2983,30 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list,
/* /*
Check that the table and database that qualify the current field name Check that the table and database that qualify the current field name
are the same as the table we are going to search for the field. are the same as the table reference we are going to search for the field.
This is done differently for NATURAL/USING joins or nested joins that
are operands of NATURAL/USING joins because there we can't simply We exclude from the test below NATURAL/USING joins and any nested join
compare the qualifying table and database names with the ones of that is an operand of NATURAL/USING join, because each column in such
'table_list' because each field in such a join may originate from a joins may potentially originate from a different table. However, base
different table. tables and views that are under some NATURAL/USING join are searched
as usual base tables/views.
We include explicitly table references with a 'field_translation' table,
because if there are views over natural joins we don't want to search
inside the view, but we want to search directly in the view columns
which are represented as a 'field_translation'.
TODO: Ensure that table_name, db_name and tables->db always points to TODO: Ensure that table_name, db_name and tables->db always points to
something ! something !
*/ */
if (!(table_list->nested_join && table_list->join_columns) && if (/* Exclude natural joins and nested joins underlying natural joins. */
(!(table_list->nested_join && table_list->join_columns) ||
/* Include merge views and information schema tables. */
table_list->field_translation) &&
/*
Test if the field qualifiers match the table reference we plan
to search.
*/
table_name && table_name[0] && table_name && table_name[0] &&
(my_strcasecmp(table_alias_charset, table_list->alias, table_name) || (my_strcasecmp(table_alias_charset, table_list->alias, table_name) ||
(db_name && db_name[0] && table_list->db && table_list->db[0] && (db_name && db_name[0] && table_list->db && table_list->db[0] &&
...@@ -2988,25 +3014,48 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list, ...@@ -2988,25 +3014,48 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list,
DBUG_RETURN(0); DBUG_RETURN(0);
*actual_table= NULL; *actual_table= NULL;
if (table_list->field_translation) if (table_list->field_translation)
{ {
/* 'table_list' is a view or an information schema table. */
if ((fld= find_field_in_view(thd, table_list, name, item_name, length, if ((fld= find_field_in_view(thd, table_list, name, item_name, length,
ref, check_grants_view, ref, check_grants_view,
register_tree_change))) register_tree_change)))
*actual_table= table_list; *actual_table= table_list;
} }
else if (table_list->nested_join && table_list->join_columns) else if (!(table_list->nested_join && table_list->join_columns))
{ {
/* /*
If this is a NATURAL/USING join, or an operand of such join which is a 'table_list' is a stored table. It is so because the only type of nested
join itself, and the field name is qualified, then search for the field join passed to this procedure is a NATURAL/USING join or an operand of a
in the operands of the join. NATURAL/USING join.
*/
if ((fld= find_field_in_table(thd, table_list->table, name, length,
check_grants_table, allow_rowid,
cached_field_index_ptr)))
*actual_table= table_list;
#ifndef NO_EMBEDDED_ACCESS_CHECKS
/* check for views with temporary table algorithm */
if (check_grants_view && table_list->view &&
fld && fld != WRONG_GRANT &&
check_grant_column(thd, &table_list->grant,
table_list->view_db.str,
table_list->view_name.str,
name, length))
fld= WRONG_GRANT;
#endif
}
else
{
/*
'table_list' is a NATURAL/USING join, or an operand of such join that
is a nested join itself.
If the field name we search for is qualified, then search for the field
in the table references used by NATURAL/USING the join.
*/ */
if (table_name && table_name[0]) if (table_name && table_name[0])
{ {
/*
Qualified field; Search for it in the tables used by the natural join.
*/
List_iterator<TABLE_LIST> it(table_list->nested_join->join_list); List_iterator<TABLE_LIST> it(table_list->nested_join->join_list);
TABLE_LIST *table; TABLE_LIST *table;
while ((table= it++)) while ((table= it++))
...@@ -3032,23 +3081,6 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list, ...@@ -3032,23 +3081,6 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list,
check_grants_table || check_grants_view, check_grants_table || check_grants_view,
register_tree_change, actual_table); register_tree_change, actual_table);
} }
else
{
if ((fld= find_field_in_table(thd, table_list->table, name, length,
check_grants_table, allow_rowid,
cached_field_index_ptr)))
*actual_table= table_list;
#ifndef NO_EMBEDDED_ACCESS_CHECKS
/* check for views with temporary table algorithm */
if (check_grants_view && table_list->view &&
fld && fld != WRONG_GRANT &&
check_grant_column(thd, &table_list->grant,
table_list->view_db.str,
table_list->view_name.str,
name, length))
fld= WRONG_GRANT;
#endif
}
DBUG_RETURN(fld); DBUG_RETURN(fld);
} }
......
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