Fix for bug#4302 "ambiguos order by when renamed column is identical to another in result"

When in find_item_in_list() we are looking for item we should take into account unaliased 
names of the fields but only if item with such aliased name is not found.
Also we should ignore aliases when looking for fully specified field.
parent 31c0ecb2
......@@ -116,7 +116,7 @@ col1
2
3
2
select col1 as id from t1 order by t1.id;
select col1 as id from t1 order by id;
id
1
1
......@@ -126,16 +126,16 @@ id
2
2
3
select concat(col1) as id from t1 order by t1.id;
select concat(col1) as id from t1 order by id;
id
2
2
1
1
1
2
3
2
2
2
3
drop table t1;
CREATE TABLE t1 (id int auto_increment primary key,aika varchar(40),aikakentta timestamp);
insert into t1 (aika) values ('Keskiviikko');
......@@ -660,3 +660,66 @@ a b c d
1 1 12 -1
1 1 2 0
drop table t1, t2;
create table t1 (col1 int, col int);
create table t2 (col2 int, col int);
insert into t1 values (1,1),(2,2),(3,3);
insert into t2 values (1,3),(2,2),(3,1);
select t1.* , t2.col as t2_col from t1 left join t2 on (t1.col1=t2.col2)
order by col;
col1 col t2_col
1 1 3
2 2 2
3 3 1
select col1 as col, col from t1 order by col;
ERROR 23000: Column 'col' in order clause is ambiguous
select t1.col as c1, t2.col as c2 from t1, t2 where t1.col1=t2.col2
order by col;
ERROR 23000: Column 'col' in order clause is ambiguous
select t1.col as c1, t2.col as c2 from t1, t2 where t1.col1=t2.col2
order by col;
ERROR 23000: Column 'col' in order clause is ambiguous
select col1 from t1, t2 where t1.col1=t2.col2 order by col;
ERROR 23000: Column 'col' in order clause is ambiguous
select t1.col as t1_col, t2.col from t1, t2 where t1.col1=t2.col2
order by col;
t1_col col
3 1
2 2
1 3
select col2 as c, col as c from t2 order by col;
c c
3 1
2 2
1 3
select col2 as col, col as col2 from t2 order by col;
col col2
1 3
2 2
3 1
select t1.col as t1_col, t2.col2 from t1, t2 where t1.col1=t2.col2
order by col;
t1_col col2
1 1
2 2
3 3
select t2.col2, t2.col, t2.col from t2 order by col;
col2 col col
3 1 1
2 2 2
1 3 3
select t2.col2 as col from t2 order by t2.col;
col
3
2
1
select t2.col2 as col, t2.col from t2 order by t2.col;
col col
3 1
2 2
1 3
select t2.col2, t2.col, t2.col from t2 order by t2.col;
col2 col col
3 1 1
2 2 2
1 3 3
drop table t1, t2;
......@@ -97,8 +97,8 @@ create table t1 (id int not null,col1 int not null,col2 int not null,index(col1)
insert into t1 values(1,2,2),(2,2,1),(3,1,2),(4,1,1),(5,1,4),(6,2,3),(7,3,1),(8,2,4);
select * from t1 order by col1,col2;
select col1 from t1 order by id;
select col1 as id from t1 order by t1.id;
select concat(col1) as id from t1 order by t1.id;
select col1 as id from t1 order by id;
select concat(col1) as id from t1 order by id;
drop table t1;
#
......@@ -445,3 +445,44 @@ insert into t1 select 1, b, c + (@row:=@row - 1) * 10, d - @row from t2 limit 10
select * from t1 where a=1 and b in (1) order by c, b, a;
select * from t1 where a=1 and b in (1);
drop table t1, t2;
#
# Bug #4302
# Ambiguos order by when renamed column is identical to another in result.
# Should not fail and prefer column from t1 for sorting.
#
create table t1 (col1 int, col int);
create table t2 (col2 int, col int);
insert into t1 values (1,1),(2,2),(3,3);
insert into t2 values (1,3),(2,2),(3,1);
select t1.* , t2.col as t2_col from t1 left join t2 on (t1.col1=t2.col2)
order by col;
#
# Let us also test various ambiguos and potentially ambiguos cases
# related to aliases
#
--error 1052
select col1 as col, col from t1 order by col;
--error 1052
select t1.col as c1, t2.col as c2 from t1, t2 where t1.col1=t2.col2
order by col;
--error 1052
select t1.col as c1, t2.col as c2 from t1, t2 where t1.col1=t2.col2
order by col;
--error 1052
select col1 from t1, t2 where t1.col1=t2.col2 order by col;
select t1.col as t1_col, t2.col from t1, t2 where t1.col1=t2.col2
order by col;
select col2 as c, col as c from t2 order by col;
select col2 as col, col as col2 from t2 order by col;
select t1.col as t1_col, t2.col2 from t1, t2 where t1.col1=t2.col2
order by col;
select t2.col2, t2.col, t2.col from t2 order by col;
select t2.col2 as col from t2 order by t2.col;
select t2.col2 as col, t2.col from t2 order by t2.col;
select t2.col2, t2.col, t2.col from t2 order by t2.col;
drop table t1, t2;
......@@ -2101,10 +2101,12 @@ find_item_in_list(Item *find, List<Item> &items, uint *counter,
find_item_error_report_type report_error)
{
List_iterator<Item> li(items);
Item **found=0,*item;
Item **found=0, **found_unaliased= 0, *item;
const char *db_name=0;
const char *field_name=0;
const char *table_name=0;
bool found_unaliased_non_uniq= 0;
uint unaliased_counter;
if (find->type() == Item::FIELD_ITEM || find->type() == Item::REF_ITEM)
{
field_name= ((Item_ident*) find)->field_name;
......@@ -2117,41 +2119,87 @@ find_item_in_list(Item *find, List<Item> &items, uint *counter,
if (field_name && item->type() == Item::FIELD_ITEM)
{
Item_field *item_field= (Item_field*) item;
/*
In case of group_concat() with ORDER BY condition in the QUERY
item_field can be field of temporary table without item name
(if this field created from expression argument of group_concat()),
=> we have to check presence of name before compare
*/
if (item_field->name &&
(!my_strcasecmp(system_charset_info, item_field->name, field_name) ||
!my_strcasecmp(system_charset_info,
item_field->field_name, field_name)))
if (!item_field->name)
continue;
if (table_name)
{
if (!table_name)
/*
If table name is specified we should find field 'field_name' in
table 'table_name'. According to SQL-standard we should ignore
aliases in this case. Note that we should prefer fields from the
select list over other fields from the tables participating in
this select in case of ambiguity.
QQ: Why do we use simple strcmp for table name comparison here ?
*/
if (!my_strcasecmp(system_charset_info, item_field->field_name,
field_name) &&
!strcmp(item_field->table_name, table_name) &&
(!db_name || (item_field->db_name &&
!strcmp(item_field->db_name, db_name))))
{
if (found)
{
if ((*found)->eq(item,0))
continue; // Same field twice (Access?)
if ((*found)->eq(item, 0))
continue; // Same field twice
if (report_error != IGNORE_ERRORS)
my_printf_error(ER_NON_UNIQ_ERROR,ER(ER_NON_UNIQ_ERROR),MYF(0),
find->full_name(), current_thd->where);
my_printf_error(ER_NON_UNIQ_ERROR, ER(ER_NON_UNIQ_ERROR),
MYF(0), find->full_name(), current_thd->where);
return (Item**) 0;
}
found= li.ref();
*counter= i;
}
else
}
else if (!my_strcasecmp(system_charset_info, item_field->name,
field_name))
{
if (!strcmp(item_field->table_name,table_name) &&
(!db_name || (db_name && item_field->db_name &&
!strcmp(item_field->db_name, db_name))))
/*
If table name was not given we should scan through aliases
(or non-aliased fields) first. We are also checking unaliased
name of the field in then next else-if, to be able to find
instantly field (hidden by alias) if no suitable alias (or
non-aliased field) was found.
*/
if (found)
{
if ((*found)->eq(item, 0))
continue; // Same field twice
if (report_error != IGNORE_ERRORS)
my_printf_error(ER_NON_UNIQ_ERROR, ER(ER_NON_UNIQ_ERROR),
MYF(0), find->full_name(), current_thd->where);
return (Item**) 0;
}
found= li.ref();
*counter= i;
break;
}
else if (!my_strcasecmp(system_charset_info, item_field->field_name,
field_name))
{
/*
We will use un-aliased field or react on such ambiguities only if
we won't be able to find aliased field.
Again if we have ambiguity with field outside of select list
we should prefer fields from select list.
*/
if (found_unaliased)
{
if ((*found_unaliased)->eq(item, 0))
continue; // Same field twice
found_unaliased_non_uniq= 1;
}
else
{
found_unaliased= li.ref();
unaliased_counter= i;
}
}
}
......@@ -2165,6 +2213,21 @@ find_item_in_list(Item *find, List<Item> &items, uint *counter,
break;
}
}
if (!found)
{
if (found_unaliased_non_uniq)
{
if (report_error != IGNORE_ERRORS)
my_printf_error(ER_NON_UNIQ_ERROR, ER(ER_NON_UNIQ_ERROR), MYF(0),
find->full_name(), current_thd->where);
return (Item **) 0;
}
if (found_unaliased)
{
found= found_unaliased;
*counter= unaliased_counter;
}
}
if (found)
return found;
else if (report_error != REPORT_EXCEPT_NOT_FOUND)
......
......@@ -7978,13 +7978,18 @@ find_order_in_list(THD *thd, Item **ref_pointer_array,
return 0;
}
uint counter;
Item **item= find_item_in_list(itemptr, fields, &counter, IGNORE_ERRORS);
if (item)
Item **item= find_item_in_list(itemptr, fields, &counter,
REPORT_EXCEPT_NOT_FOUND);
if (!item)
return 1;
if (item != not_found_item)
{
order->item= ref_pointer_array + counter;
order->in_field_list=1;
return 0;
}
order->in_field_list=0;
Item *it= *order->item;
/*
......
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