Commit 47a96b31 authored by unknown's avatar unknown

WL#1972 "Evaluate HAVING before SELECT"

- more tests, post-review changes, bug-fixes, simplifications, and improved comments


mysql-test/r/having.result:
  - added tests for subqueries with HAVING
  - added tests for few other discovered bugs
  - renamed tables to the more standard t1,t2,..
mysql-test/t/having.test:
  - added tests for subqueries with HAVING
  - added tests for few other discovered bugs
  - renamed tables to the more standard t1,t2,..
sql/item.cc:
  - Extended the name resolution to support nested HAVING clauses in nested sub-queries
  - Factored out the code that resolves a column ref against a single query
  - Fixed several logical bugs
  - Removed unused variables
  - More/better comments
sql/sql_base.cc:
  Corrected function spec.
parent c7bfc959
drop table if exists t1,t2; drop table if exists t1,t2,t3;
create table t1 (a int); create table t1 (a int);
select count(a) as b from t1 where a=0 having b > 0; select count(a) as b from t1 where a=0 having b > 0;
b b
...@@ -128,74 +128,76 @@ id description c ...@@ -128,74 +128,76 @@ id description c
1 test 0 1 test 0
2 test2 0 2 test2 0
drop table t1,t2,t3; drop table t1,t2,t3;
drop table if exists wl1972; create table t1 (col1 int, col2 varchar(5), col_t1 int);
create table wl1972 ( create table t2 (col1 int, col2 varchar(5), col_t2 int);
col1 int, create table t3 (col1 int, col2 varchar(5), col_t3 int);
col2 varchar(5) character set latin1 collate latin1_bin) insert into t1 values(10,'hello',10);
engine=innodb; insert into t1 values(20,'hello',20);
insert into wl1972 values(10,'hello'); insert into t1 values(30,'hello',30);
insert into wl1972 values(20,'hello'); insert into t1 values(10,'bye',10);
insert into wl1972 values(30,'hello'); insert into t1 values(10,'sam',10);
insert into wl1972 values(10,'bye'); insert into t1 values(10,'bob',10);
insert into wl1972 values(10,'sam'); insert into t2 select * from t1;
insert into wl1972 values(10,'bob'); insert into t3 select * from t1;
select count(*) from wl1972 group by col1 having col1 = 10; select count(*) from t1 group by col1 having col1 = 10;
count(*) count(*)
4 4
select count(*) as count_col1 from wl1972 group by col1 having col1 = 10; select count(*) as count_col1 from t1 group by col1 having col1 = 10;
count_col1 count_col1
4 4
select count(*) as count_col1 from wl1972 as t1 group by col1 having col1 = 10; select count(*) as count_col1 from t1 as tmp1 group by col1 having col1 = 10;
count_col1 count_col1
4 4
select count(*) from wl1972 group by col2 having col2 = 'hello'; select count(*) from t1 group by col2 having col2 = 'hello';
count(*) count(*)
3 3
select count(*) from wl1972 group by col2 having col1 = 10; select count(*) from t1 group by col2 having col1 = 10;
ERROR 42S22: Unknown column 'col1' in 'having clause' ERROR 42S22: Unknown column 'col1' in 'having clause'
select col1 as count_col1 from wl1972 as t1 group by col1 having col1 = 10; select col1 as count_col1 from t1 as tmp1 group by col1 having col1 = 10;
count_col1 count_col1
10 10
select col1 as count_col1 from wl1972 as t1 group by col1 having count_col1 = 10; select col1 as count_col1 from t1 as tmp1 group by col1 having count_col1 = 10;
count_col1 count_col1
10 10
select col1 as count_col1 from wl1972 as t1 group by count_col1 having col1 = 10; select col1 as count_col1 from t1 as tmp1 group by count_col1 having col1 = 10;
count_col1 count_col1
10 10
select col1 as count_col1 from wl1972 as t1 group by count_col1 having count_col1 = 10; select col1 as count_col1 from t1 as tmp1 group by count_col1 having count_col1 = 10;
count_col1 count_col1
10 10
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having col1 = 10; select col1 as count_col1,col2 from t1 as tmp1 group by col1,col2 having col1 = 10;
count_col1 col2 count_col1 col2
10 bob 10 bob
10 bye 10 bye
10 hello 10 hello
10 sam 10 sam
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having count_col1 = 10; select col1 as count_col1,col2 from t1 as tmp1 group by col1,col2 having count_col1 = 10;
count_col1 col2 count_col1 col2
10 bob 10 bob
10 bye 10 bye
10 hello 10 hello
10 sam 10 sam
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having col2 = 'hello'; select col1 as count_col1,col2 from t1 as tmp1 group by col1,col2 having col2 = 'hello';
count_col1 col2 count_col1 col2
10 hello 10 hello
20 hello 20 hello
30 hello 30 hello
select col1 as count_col1,col2 as group_col2 from wl1972 as t1 select col1 as count_col1,col2 as group_col2 from t1 as tmp1 group by col1,col2 having group_col2 = 'hello';
group by col1,col2 having group_col2 = 'hello';
count_col1 group_col2 count_col1 group_col2
10 hello 10 hello
20 hello 20 hello
30 hello 30 hello
select sum(col1) as co12 from wl1972 group by col2 having col2 10; select sum(col1) as co12 from t1 group by col2 having col2 10;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near '10' at line 1 ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near '10' at line 1
select sum(col1) as co2, count(col2) as cc from wl1972 group by col1 having col1 =10; select sum(col1) as co2, count(col2) as cc from t1 group by col1 having col1 =10;
co2 cc co2 cc
40 4 40 4
select t1.col1 from wl1972 as t1 where t1.col2 in select t2.col2 from t2 group by t2.col1, t2.col2 having t1.col1 <= 10;
(select t2.col2 from wl1972 as t2 ERROR 42S22: Unknown column 't1.col1' in 'having clause'
group by t2.col1,t2.col2 having t2.col1<=10); select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having t2.col1 <= 10);
col1 col1
10 10
20 20
...@@ -203,10 +205,12 @@ col1 ...@@ -203,10 +205,12 @@ col1
10 10
10 10
10 10
select t1.col1 from wl1972 as t1 where t1.col2 in select t1.col1 from t1
(select t2.col2 from wl1972 as t2 where t1.col2 in
group by t2.col1,t2.col2 having t2.col1<= (select t2.col2 from t2
(select min(t3.col1) from wl1972 as t3)); group by t2.col1, t2.col2
having t2.col1 <=
(select min(t3.col1) from t3));
col1 col1
10 10
20 20
...@@ -214,36 +218,106 @@ col1 ...@@ -214,36 +218,106 @@ col1
10 10
10 10
10 10
drop table wl1972; select t1.col1 from t1
create table wl1972 (s1 int); where t1.col2 in
insert into wl1972 values (1),(2),(3); (select t2.col2 from t2
select count(*) from wl1972 group by s1 having s1 is null; group by t2.col1, t2.col2 having t1.col1 <= 10);
col1
10
10
10
10
select t1.col1 as tmp_col from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having tmp_col <= 10);
tmp_col
10
10
10
10
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having col_t1 <= 10);
col1
10
10
10
10
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having col_t1 <= 10)
having col_t1 <= 20;
ERROR 42S22: Unknown column 'col_t1' in 'having clause'
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having col_t1 <= 10)
group by col_t1
having col_t1 <= 20;
col1
10
select col_t1, sum(col1) from t1
group by col_t1
having col_t1 > 10 and
exists (select sum(t2.col1) from t2
group by t2.col2 having t2.col2 > 'b');
col_t1 sum(col1)
20 20
30 30
select sum(col1) from t1
group by col_t1
having col_t1 in (select sum(t2.col1) from t2
group by t2.col2, t2.col1 having t2.col1 = t1.col1);
ERROR 42S22: Unknown column 't1.col1' in 'having clause'
select sum(col1) from t1
group by col_t1
having col_t1 in (select sum(t2.col1) from t2
group by t2.col2, t2.col1 having t2.col1 = col_t1);
sum(col1)
40
20
30
select t1.col1, t2.col1 from t1, t2 where t1.col1 = t2.col1
group by t1.col1, t2.col1 having col1 = 2;
ERROR 23000: Column 'col1' in having clause is ambiguous
select t1.col1*10+t2.col1 from t1,t2 where t1.col1=t2.col1
group by t1.col1, t2.col1 having col1 = 2;
ERROR 23000: Column 'col1' in having clause is ambiguous
drop table t1, t2, t3;
create table t1 (s1 int);
insert into t1 values (1),(2),(3);
select count(*) from t1 group by s1 having s1 is null;
count(*) count(*)
select s1*0 as s1 from wl1972 group by s1 having s1 <> 0; select s1*0 as s1 from t1 group by s1 having s1 <> 0;
s1 s1
0 0
0 0
0 0
select s1*0 from wl1972 group by s1 having s1 = 0; Warnings:
Warning 1052 Column 's1' in having clause is ambiguous
select s1*0 from t1 group by s1 having s1 = 0;
s1*0 s1*0
select s1 from wl1972 group by 1 having 1 = 0; select s1 from t1 group by 1 having 1 = 0;
s1 s1
select count(s1) from wl1972 group by s1 having count(1+1)=2; select count(s1) from t1 group by s1 having count(1+1)=2;
count(s1) count(s1)
select count(s1) from wl1972 group by s1 having s1*0=0; select count(s1) from t1 group by s1 having s1*0=0;
count(s1) count(s1)
1 1
1 1
1 1
select * from wl1972 a, wl1972 b group by a.s1 having s1 is null; select * from t1 a, t1 b group by a.s1 having s1 is null;
ERROR 23000: Column 's1' in having clause is ambiguous ERROR 23000: Column 's1' in having clause is ambiguous
drop table wl1972; drop table t1;
create table wl1972 (s1 char character set latin1 collate latin1_german1_ci); create table t1 (s1 char character set latin1 collate latin1_german1_ci);
insert into wl1972 values ('ü'),('y'); insert into t1 values ('ü'),('y');
Warnings: Warnings:
Warning 1265 Data truncated for column 's1' at row 1 Warning 1265 Data truncated for column 's1' at row 1
select s1,count(s1) from wl1972 select s1,count(s1) from t1
group by s1 collate latin1_swedish_ci having s1 = 'y'; group by s1 collate latin1_swedish_ci having s1 = 'y';
s1 count(s1) s1 count(s1)
y 1 y 1
drop table wl1972; drop table t1;
...@@ -2,7 +2,7 @@ ...@@ -2,7 +2,7 @@
# #
--disable_warnings --disable_warnings
drop table if exists t1,t2; drop table if exists t1,t2,t3;
--enable_warnings --enable_warnings
create table t1 (a int); create table t1 (a int);
...@@ -134,108 +134,180 @@ drop table t1,t2,t3; ...@@ -134,108 +134,180 @@ drop table t1,t2,t3;
# set global sql_mode='ansi'; # set global sql_mode='ansi';
# set session sql_mode='ansi'; # set session sql_mode='ansi';
--disable_warnings create table t1 (col1 int, col2 varchar(5), col_t1 int);
drop table if exists wl1972; create table t2 (col1 int, col2 varchar(5), col_t2 int);
--enable_warnings create table t3 (col1 int, col2 varchar(5), col_t3 int);
create table wl1972 (
col1 int,
col2 varchar(5) character set latin1 collate latin1_bin)
engine=innodb;
insert into wl1972 values(10,'hello');
insert into wl1972 values(20,'hello');
insert into wl1972 values(30,'hello');
insert into wl1972 values(10,'bye');
insert into wl1972 values(10,'sam');
insert into wl1972 values(10,'bob');
select count(*) from wl1972 group by col1 having col1 = 10; insert into t1 values(10,'hello',10);
insert into t1 values(20,'hello',20);
insert into t1 values(30,'hello',30);
insert into t1 values(10,'bye',10);
insert into t1 values(10,'sam',10);
insert into t1 values(10,'bob',10);
select count(*) as count_col1 from wl1972 group by col1 having col1 = 10; insert into t2 select * from t1;
insert into t3 select * from t1;
select count(*) as count_col1 from wl1972 as t1 group by col1 having col1 = 10;
select count(*) from wl1972 group by col2 having col2 = 'hello';
select count(*) from t1 group by col1 having col1 = 10;
select count(*) as count_col1 from t1 group by col1 having col1 = 10;
select count(*) as count_col1 from t1 as tmp1 group by col1 having col1 = 10;
select count(*) from t1 group by col2 having col2 = 'hello';
--error 1054 --error 1054
select count(*) from wl1972 group by col2 having col1 = 10; select count(*) from t1 group by col2 having col1 = 10;
select col1 as count_col1 from t1 as tmp1 group by col1 having col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by col1 having col1 = 10; select col1 as count_col1 from t1 as tmp1 group by col1 having count_col1 = 10;
select col1 as count_col1 from t1 as tmp1 group by count_col1 having col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by col1 having count_col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by count_col1 having col1 = 10;
# ANSI: should return SQLSTATE 42000 Syntax error or access violation # ANSI: should return SQLSTATE 42000 Syntax error or access violation
# MySQL: returns 10 - because of GROUP BY name resolution # MySQL: returns 10 - because of GROUP BY name resolution
select col1 as count_col1 from t1 as tmp1 group by count_col1 having count_col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by count_col1 having count_col1 = 10;
# ANSI: should return SQLSTATE 42000 Syntax error or access violation # ANSI: should return SQLSTATE 42000 Syntax error or access violation
# MySQL: returns 10 - because of GROUP BY name resolution # MySQL: returns 10 - because of GROUP BY name resolution
select col1 as count_col1,col2 from t1 as tmp1 group by col1,col2 having col1 = 10;
select col1 as count_col1,col2 from t1 as tmp1 group by col1,col2 having count_col1 = 10;
select col1 as count_col1,col2 from t1 as tmp1 group by col1,col2 having col2 = 'hello';
select col1 as count_col1,col2 as group_col2 from t1 as tmp1 group by col1,col2 having group_col2 = 'hello';
--error 1064
select sum(col1) as co12 from t1 group by col2 having col2 10;
select sum(col1) as co2, count(col2) as cc from t1 group by col1 having col1 =10;
--error 1054
select t2.col2 from t2 group by t2.col1, t2.col2 having t1.col1 <= 10;
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having col1 = 10;
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having count_col1 = 10; #
# queries with nested sub-queries
#
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having col2 = 'hello'; # the having column is resolved in the same query
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having t2.col1 <= 10);
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2
having t2.col1 <=
(select min(t3.col1) from t3));
# the having column is resolved in the SELECT clause of the outer query -
# works in ANSI
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having t1.col1 <= 10);
# the having column is resolved in the SELECT clause of the outer query -
# error in ANSI, works with MySQL extension
select t1.col1 as tmp_col from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having tmp_col <= 10);
# the having column is resolved in the FROM clause of the outer query -
# works in ANSI
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having col_t1 <= 10);
# nested queries with HAVING, inner having column resolved in outer FROM clause
# the outer having column is not referenced in GROUP BY which results in an error
--error 1054
select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having col_t1 <= 10)
having col_t1 <= 20;
select col1 as count_col1,col2 as group_col2 from wl1972 as t1 # both having columns are resolved in the GROUP clause of the outer query
group by col1,col2 having group_col2 = 'hello'; select t1.col1 from t1
where t1.col2 in
(select t2.col2 from t2
group by t2.col1, t2.col2 having col_t1 <= 10)
group by col_t1
having col_t1 <= 20;
--error 1064
select sum(col1) as co12 from wl1972 group by col2 having col2 10;
select sum(col1) as co2, count(col2) as cc from wl1972 group by col1 having col1 =10; #
# nested HAVING clauses
#
select t1.col1 from wl1972 as t1 where t1.col2 in # non-correlated subqueries
(select t2.col2 from wl1972 as t2 select col_t1, sum(col1) from t1
group by t2.col1,t2.col2 having t2.col1<=10); group by col_t1
having col_t1 > 10 and
exists (select sum(t2.col1) from t2
group by t2.col2 having t2.col2 > 'b');
select t1.col1 from wl1972 as t1 where t1.col2 in # correlated subqueries - inner having column 't1.col2' resolves to
(select t2.col2 from wl1972 as t2 # the outer FROM clause, which cannot be used because the outer query
group by t2.col1,t2.col2 having t2.col1<= # is grouped
(select min(t3.col1) from wl1972 as t3)); --error 1054
select sum(col1) from t1
group by col_t1
having col_t1 in (select sum(t2.col1) from t2
group by t2.col2, t2.col1 having t2.col1 = t1.col1);
# correlated subqueries - inner having column 'col_t1' resolves to
# the outer GROUP clause
select sum(col1) from t1
group by col_t1
having col_t1 in (select sum(t2.col1) from t2
group by t2.col2, t2.col1 having t2.col1 = col_t1);
drop table wl1972;
#
# queries with joins and ambiguous column names
#
--error 1052
select t1.col1, t2.col1 from t1, t2 where t1.col1 = t2.col1
group by t1.col1, t2.col1 having col1 = 2;
--error 1052
select t1.col1*10+t2.col1 from t1,t2 where t1.col1=t2.col1
group by t1.col1, t2.col1 having col1 = 2;
drop table t1, t2, t3;
# More queries to test ANSI compatibility # More queries to test ANSI compatibility
create table wl1972 (s1 int); create table t1 (s1 int);
insert into wl1972 values (1),(2),(3); insert into t1 values (1),(2),(3);
select count(*) from wl1972 group by s1 having s1 is null; select count(*) from t1 group by s1 having s1 is null;
select s1*0 as s1 from wl1972 group by s1 having s1 <> 0; select s1*0 as s1 from t1 group by s1 having s1 <> 0;
# ANSI requires: 3 rows # ANSI requires: 3 rows
# MySQL returns: 0 rows - because of GROUP BY name resolution # MySQL returns: 0 rows - because of GROUP BY name resolution
select s1*0 from wl1972 group by s1 having s1 = 0; select s1*0 from t1 group by s1 having s1 = 0;
select s1 from wl1972 group by 1 having 1 = 0; select s1 from t1 group by 1 having 1 = 0;
select count(s1) from wl1972 group by s1 having count(1+1)=2; select count(s1) from t1 group by s1 having count(1+1)=2;
# ANSI requires: 3 rows # ANSI requires: 3 rows
# MySQL returns: 0 rows - because of GROUP BY name resolution # MySQL returns: 0 rows - because of GROUP BY name resolution
select count(s1) from wl1972 group by s1 having s1*0=0; select count(s1) from t1 group by s1 having s1*0=0;
-- error 1052 -- error 1052
select * from wl1972 a, wl1972 b group by a.s1 having s1 is null; select * from t1 a, t1 b group by a.s1 having s1 is null;
# ANSI requires: 0 rows # ANSI requires: 0 rows
# MySQL returns: # MySQL returns:
# "ERROR 1052 (23000): Column 's1' in having clause is ambiguous" # "ERROR 1052 (23000): Column 's1' in having clause is ambiguous"
# I think the column is ambiguous in ANSI too. # I think the column is ambiguous in ANSI too.
# It is the same as: # It is the same as:
# select a.s1, b.s1 from wl1972 a, wl1972 b group by a.s1 having s1 is null; # select a.s1, b.s1 from t1 a, t1 b group by a.s1 having s1 is null;
# currently we first check SELECT, thus s1 is ambiguous. # currently we first check SELECT, thus s1 is ambiguous.
drop table wl1972; drop table t1;
create table wl1972 (s1 char character set latin1 collate latin1_german1_ci); create table t1 (s1 char character set latin1 collate latin1_german1_ci);
insert into wl1972 values ('ü'),('y'); insert into t1 values ('ü'),('y');
select s1,count(s1) from wl1972 select s1,count(s1) from t1
group by s1 collate latin1_swedish_ci having s1 = 'y'; group by s1 collate latin1_swedish_ci having s1 = 'y';
# ANSI requires: 1 row, with count(s1) = 2 # ANSI requires: 1 row, with count(s1) = 2
# MySQL returns: 1 row, with count(s1) = 1 # MySQL returns: 1 row, with count(s1) = 1
drop table wl1972; drop table t1;
...@@ -2320,14 +2320,22 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list) ...@@ -2320,14 +2320,22 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
else else
continue; continue;
if (cur_field->table_name && table_name && if (cur_field->table_name && table_name)
!strcmp(cur_field->table_name, table_name)) {
{ /* If field_name is qualified by a table name. */ /* If field_name is qualified by a table name. */
if (strcmp(cur_field->table_name, table_name))
/* Same field names, different tables. */
return NULL;
++cur_match_degree; ++cur_match_degree;
if (cur_field->db_name && db_name && if (cur_field->db_name && db_name)
!strcmp(cur_field->db_name, db_name)) {
/* If field_name is also qualified by a database name. */ /* If field_name is also qualified by a database name. */
if (strcmp(cur_field->db_name, db_name))
/* Same field names, different databases. */
return NULL;
++cur_match_degree; ++cur_match_degree;
}
} }
if (cur_match_degree > found_match_degree) if (cur_match_degree > found_match_degree)
...@@ -2335,8 +2343,21 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list) ...@@ -2335,8 +2343,21 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
found_match_degree= cur_match_degree; found_match_degree= cur_match_degree;
found_group= cur_group; found_group= cur_group;
} }
else if (found_group && (cur_match_degree == found_match_degree) &&
! (*(found_group->item))->eq(cur_field, 0))
{
/*
If the current resolve candidate matches equally well as the current
best match, they must reference the same column, otherwise the field
is ambiguous.
*/
my_printf_error(ER_NON_UNIQ_ERROR, ER(ER_NON_UNIQ_ERROR),
MYF(0), find_item->full_name(), current_thd->where);
return NULL;
}
} }
} }
if (found_group) if (found_group)
return found_group->item; return found_group->item;
else else
...@@ -2344,6 +2365,97 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list) ...@@ -2344,6 +2365,97 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
} }
/*
Resolve a column reference in a sub-select.
SYNOPSIS
resolve_ref_in_select_and_group()
thd current thread
ref column reference being resolved
select the sub-select that ref is resolved against
DESCRIPTION
Resolve a column reference (usually inside a HAVING clause) against the
SELECT and GROUP BY clauses of the query described by 'select'. The name
resolution algorithm searches both the SELECT and GROUP BY clauses, and in
case of a name conflict prefers GROUP BY column names over SELECT names. If
both clauses contain different fields with the same names, a warning is
issued that name of 'ref' is ambiguous. We extend ANSI SQL in that when no
GROUP BY column is found, then a HAVING name is resolved as a possibly
derived SELECT column.
NOTES
The resolution procedure is:
- Search for a column or derived column named col_ref_i [in table T_j]
in the SELECT clause of Q.
- Search for a column named col_ref_i [in table T_j]
in the GROUP BY clause of Q.
- If found different columns with the same name in GROUP BY and SELECT
- issue a warning and return the GROUP BY column,
- otherwise return the found SELECT column.
RETURN
NULL - there was an error, and the error was already reported
not_found_item - the item was not resolved, no error was reported
resolved item - if the item was resolved
*/
static Item**
resolve_ref_in_select_and_group(THD *thd, Item_ref *ref, SELECT_LEX *select)
{
Item **group_by_ref= NULL;
Item **select_ref= NULL;
ORDER *group_list= (ORDER*) select->group_list.first;
bool ambiguous_fields= FALSE;
uint counter;
/*
Search for a column or derived column named as 'ref' in the SELECT
clause of the current select.
*/
if (!(select_ref= find_item_in_list(ref, *(select->get_item_list()), &counter,
REPORT_EXCEPT_NOT_FOUND)))
return NULL; /* Some error occurred. */
/* If this is a non-aggregated field inside HAVING, search in GROUP BY. */
if (select->having_fix_field && !ref->with_sum_func && group_list)
{
group_by_ref= find_field_in_group_list(ref, group_list);
/* Check if the fields found in SELECT and GROUP BY are the same field. */
if (group_by_ref && (select_ref != not_found_item) &&
!((*group_by_ref)->eq(*select_ref, 0)))
{
ambiguous_fields= TRUE;
push_warning_printf(thd, MYSQL_ERROR::WARN_LEVEL_WARN, ER_NON_UNIQ_ERROR,
ER(ER_NON_UNIQ_ERROR), ref->full_name(),
current_thd->where);
}
}
if (select_ref != not_found_item || group_by_ref)
{
if (select_ref != not_found_item && !ambiguous_fields)
{
if (*select_ref && !(*select_ref)->fixed)
{
my_error(ER_ILLEGAL_REFERENCE, MYF(0), ref->name,
"forward reference in item list");
return NULL;
}
return (select->ref_pointer_array + counter);
}
else if (group_by_ref)
return group_by_ref;
else
DBUG_ASSERT(FALSE);
}
else
return (Item**) not_found_item;
}
/* /*
Resolve the name of a column reference. Resolve the name of a column reference.
...@@ -2356,38 +2468,30 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list) ...@@ -2356,38 +2468,30 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
DESCRIPTION DESCRIPTION
The method resolves the column reference represented by 'this' as a column The method resolves the column reference represented by 'this' as a column
present in one of: GROUP BY clause, SELECT clause, outer queries. It is present in one of: GROUP BY clause, SELECT clause, outer queries. It is
used for columns in the HAVING clause which are not under aggregate used typically for columns in the HAVING clause which are not under
functions. aggregate functions.
NOTES NOTES
The general idea behind the name resolution algorithm is that it searches
both the SELECT and GROUP BY clauses, and in case of a name conflict
prefers GROUP BY column names over SELECT names. We extend ANSI SQL in that
when no GROUP BY column is found, then a HAVING name is resolved as a
possibly derived SELECT column.
The name resolution algorithm used is: The name resolution algorithm used is:
resolve_extended([T_j].col_ref_i) resolve_extended([T_j].col_ref_i)
{ {
Search for a column or derived column named col_ref_i [in table T_j] Search for a column or derived column named col_ref_i [in table T_j]
in the SELECT list of Q. in the SELECT and GROUP clauses of Q.
Search for a column named col_ref_i [in table T_j]
in the GROUP BY clause of Q.
If found different columns with the same name in GROUP BY and SELECT
issue a warning and return the GROUP BY column,
otherwise return the found SELECT column.
if such a column is NOT found AND // Lookup in outer queries. if such a column is NOT found AND // Lookup in outer queries.
there are outer queries there are outer queries
{ {
for each outer query Q_k beginning from the inner-most one for each outer query Q_k beginning from the inner-most one
{ {
search for a column or derived column named col_ref_i Search for a column or derived column named col_ref_i
[in table T_j] in the SELECT list of Q_k; [in table T_j] in the SELECT and GROUP clauses of Q_k.
if such a column is not found
if such a column is not found AND
- Q_k is not a group query AND
- Q_k is not inside an aggregate function
OR
- Q_(k-1) is not in a HAVING or SELECT clause of Q_k
{ {
search for a column or derived column named col_ref_i search for a column or derived column named col_ref_i
[in table T_j] in the FROM clause of Q_k; [in table T_j] in the FROM clause of Q_k;
...@@ -2407,214 +2511,157 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list) ...@@ -2407,214 +2511,157 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
bool Item_ref::fix_fields(THD *thd, TABLE_LIST *tables, Item **reference) bool Item_ref::fix_fields(THD *thd, TABLE_LIST *tables, Item **reference)
{ {
DBUG_ASSERT(fixed == 0); DBUG_ASSERT(fixed == 0);
uint counter;
SELECT_LEX *current_sel= thd->lex->current_select; SELECT_LEX *current_sel= thd->lex->current_select;
List<Item> *select_fields= current_sel->get_item_list();
bool is_having_field= current_sel->having_fix_field;
Item **group_by_ref= NULL;
bool ambiguous_fields= FALSE;
if (!ref) if (!ref)
{ {
TABLE_LIST *table_list;
bool upward_lookup= 0;
SELECT_LEX_UNIT *prev_unit= current_sel->master_unit(); SELECT_LEX_UNIT *prev_unit= current_sel->master_unit();
SELECT_LEX *outer_sel= prev_unit->outer_select(); SELECT_LEX *outer_sel= prev_unit->outer_select();
ORDER *group_list= (ORDER*) current_sel->group_list.first;
bool ambiguous_fields= FALSE;
Item **group_by_ref= NULL;
/* if (!(ref= resolve_ref_in_select_and_group(thd, this, current_sel)))
Search for a column or derived column named as 'this' in the SELECT return TRUE; /* Some error occured (e.g. ambigous names). */
clause of current_select.
*/
if (!(ref= find_item_in_list(this, *select_fields, &counter,
REPORT_EXCEPT_NOT_FOUND)))
return TRUE; /* Some error occurred. */
/* If this is a non-aggregated field inside HAVING, search in GROUP BY. */
if (is_having_field && !this->with_sum_func)
{
group_by_ref= find_field_in_group_list(this, (ORDER*)
current_sel->group_list.first);
/* Check if the fields found in SELECT and GROUP BY are the same field. */
if (group_by_ref && ref != (Item **) not_found_item &&
!((*group_by_ref)->eq(*ref, 0)))
{
ambiguous_fields= TRUE;
push_warning_printf(thd, MYSQL_ERROR::WARN_LEVEL_WARN,
ER_NON_UNIQ_ERROR, ER(ER_NON_UNIQ_ERROR),
this->full_name(), current_thd->where);
} if (ref == not_found_item) /* This reference was not resolved. */
}
/*
If we didn't find such a column in the current query, and if there is an
outer select, and it is not a derived table (which do not support the
use of outer fields for now), search the outer select(s) for a column
named as 'this'.
*/
if (!group_by_ref && (ref == (Item **) not_found_item) && outer_sel &&
(current_sel->master_unit()->first_select()->linkage !=
DERIVED_TABLE_TYPE))
{ {
/* /*
We can't join the columns of the outer & current selects, because of If there is an outer select, and it is not a derived table (which do
scope of view rules. For example if both tables (outer & current) have not support the use of outer fields for now), try to resolve this
field 'field' it is not a mistake to refer to this field without reference in the outer select(s).
qualifying it with a table name, but if we join tables in one list it
will cause error ER_NON_UNIQ_ERROR in find_item_in_list. We treat each subselect as a separate namespace, so that different
subselects may contain columns with the same names. The subselects are
searched starting from the innermost.
*/ */
upward_lookup= 1; if (outer_sel && (current_sel->master_unit()->first_select()->linkage !=
Field *tmp= (Field*) not_found_field; DERIVED_TABLE_TYPE))
SELECT_LEX *last=0;
for ( ; outer_sel ;
outer_sel= (prev_unit= outer_sel->master_unit())->outer_select())
{ {
last= outer_sel; TABLE_LIST *table_list;
Item_subselect *prev_subselect_item= prev_unit->item; Field *tmp= (Field*) not_found_field;
SELECT_LEX *last= 0;
/* Search in the SELECT list of the current outer sub-select. */
if (outer_sel->resolve_mode == SELECT_LEX::SELECT_MODE &&
(ref= find_item_in_list(this, outer_sel->item_list,
&counter,
REPORT_EXCEPT_NOT_FOUND)) !=
(Item **)not_found_item)
{
if (*ref && (*ref)->fixed) // Avoid crash in case of error
{
prev_subselect_item->used_tables_cache|= (*ref)->used_tables();
prev_subselect_item->const_item_cache&= (*ref)->const_item();
}
break;
}
/* Search in the tables in the FROM clause of the outer select. */ for ( ; outer_sel ;
table_list= outer_sel->get_table_list(); outer_sel= (prev_unit= outer_sel->master_unit())->outer_select())
if (outer_sel->resolve_mode == SELECT_LEX::INSERT_MODE && table_list) {
{ last= outer_sel;
/* It is primary INSERT st_select_lex => skip the first table. */ Item_subselect *prev_subselect_item= prev_unit->item;
table_list= table_list->next_local;
} /* Search in the SELECT and GROUP lists of the outer select. */
enum_parsing_place place= prev_subselect_item->parsing_place; if (outer_sel->resolve_mode == SELECT_LEX::SELECT_MODE)
/*
Check table fields only if the subquery is used somewhere out of
HAVING or SELECT list, or outer SELECT does not use grouping
(i.e. tables are accessible)
*/
if (((place != IN_HAVING &&
place != SELECT_LIST) ||
(outer_sel->with_sum_func == 0 &&
outer_sel->group_list.elements == 0)) &&
(tmp= find_field_in_tables(thd, this,
table_list, reference,
IGNORE_EXCEPT_NON_UNIQUE, TRUE)) !=
not_found_field)
{
if (tmp)
{ {
if (tmp != view_ref_found) if (!(ref= resolve_ref_in_select_and_group(thd, this, outer_sel)))
return TRUE; /* Some error occured (e.g. ambigous names). */
if (ref != not_found_item)
{ {
prev_subselect_item->used_tables_cache|= tmp->table->map; DBUG_ASSERT(*ref && (*ref)->fixed);
prev_subselect_item->const_item_cache= 0; /*
Avoid crash in case of error.
TODO: what does this comment mean?
*/
prev_subselect_item->used_tables_cache|= (*ref)->used_tables();
prev_subselect_item->const_item_cache&= (*ref)->const_item();
break;
} }
else }
/* Search in the tables of the FROM clause of the outer select. */
table_list= outer_sel->get_table_list();
if (outer_sel->resolve_mode == SELECT_LEX::INSERT_MODE && table_list)
{
/* It is primary INSERT st_select_lex => skip the first table. */
table_list= table_list->next_local;
}
enum_parsing_place place= prev_subselect_item->parsing_place;
/*
Check table fields only if the subquery is used somewhere out of
HAVING or SELECT list, or outer SELECT does not use grouping
(i.e. tables are accessible).
TODO:
Here we could first find the field anyway, and then test this
condition, so that we can give a better error message -
ER_WRONG_FIELD_WITH_GROUP, instead of the less informative
ER_BAD_FIELD_ERROR which we produce now.
*/
if (((place != IN_HAVING && place != SELECT_LIST) ||
(!outer_sel->with_sum_func &&
outer_sel->group_list.elements == 0)))
{
if ((tmp= find_field_in_tables(thd, this, table_list, reference,
IGNORE_EXCEPT_NON_UNIQUE, TRUE)) !=
not_found_field)
{ {
prev_subselect_item->used_tables_cache|= if (tmp != view_ref_found)
(*reference)->used_tables(); {
prev_subselect_item->const_item_cache&= prev_subselect_item->used_tables_cache|= tmp->table->map;
(*reference)->const_item(); prev_subselect_item->const_item_cache= 0;
}
else
{
prev_subselect_item->used_tables_cache|=
(*reference)->used_tables();
prev_subselect_item->const_item_cache&=
(*reference)->const_item();
}
break;
} }
} }
break;
}
// Reference is not found => depend from outer (or just error) /* Reference is not found => depend on outer (or just error). */
prev_subselect_item->used_tables_cache|= OUTER_REF_TABLE_BIT; prev_subselect_item->used_tables_cache|= OUTER_REF_TABLE_BIT;
prev_subselect_item->const_item_cache= 0; prev_subselect_item->const_item_cache= 0;
if (outer_sel->master_unit()->first_select()->linkage == if (outer_sel->master_unit()->first_select()->linkage ==
DERIVED_TABLE_TYPE) DERIVED_TABLE_TYPE)
break; /* Do not consider derived tables. */ break; /* Do not consider derived tables. */
} }
if (!ref) DBUG_ASSERT(ref);
return TRUE; if (!tmp)
else if (!tmp) return TRUE;
return TRUE; else if (ref == not_found_item && tmp == not_found_field)
else if (ref == (Item **)not_found_item && tmp == not_found_field) {
{ my_printf_error(ER_BAD_FIELD_ERROR, ER(ER_BAD_FIELD_ERROR), MYF(0),
if (upward_lookup) this->full_name(), current_thd->where);
{ ref= 0;
/* We can't say exactly what was absent (a table or a field). */ return TRUE;
my_printf_error(ER_BAD_FIELD_ERROR, ER(ER_BAD_FIELD_ERROR), MYF(0), }
full_name(), thd->where); else if (tmp != not_found_field)
} {
else ref= 0; // To prevent "delete *ref;" on ~Item_ref() of this item
{ if (tmp != view_ref_found)
// Call to report error {
find_item_in_list(this, *select_fields, &counter, Item_field* fld= new Item_field(tmp);
REPORT_ALL_ERRORS); if (!((*reference)= fld))
} return TRUE;
ref= 0; mark_as_dependent(thd, last, current_sel, fld);
return TRUE; register_item_tree_changing(reference);
} return FALSE;
else if (tmp != not_found_field) }
{ /*
ref= 0; // To prevent "delete *ref;" on ~Item_ref() of this item We can leave expression substituted from view for next PS/SP
if (tmp != view_ref_found) re-execution (i.e. do not register this substitution for reverting
{ on cleanup() (register_item_tree_changing())), because this subtree
Item_field* fld; will be fix_field'ed during setup_tables()->setup_ancestor()
if (!((*reference)= fld= new Item_field(tmp))) (i.e. before all other expressions of query, and references on
return TRUE; tables which do not present in query will not make problems.
mark_as_dependent(thd, last, current_sel, fld);
register_item_tree_changing(reference); Also we suppose that view can't be changed during PS/SP life.
return FALSE; */
} }
/* else
We can leave expression substituted from view for next PS/SP {
re-execution (i.e. do not register this substitution for reverting on DBUG_ASSERT(*ref && (*ref)->fixed);
cleanup() (register_item_tree_changing())), because this subtree will mark_as_dependent(thd, last, current_sel, this);
be fix_field'ed during setup_tables()->setup_ancestor() (i.e. before }
all other expressions of query, and references on tables which do not
present in query will not make problems.
Also we suppose that view can't be changed during PS/SP life.
*/
}
else
{
if (!(*ref)->fixed)
{
my_error(ER_ILLEGAL_REFERENCE, MYF(0), name,
"forward reference in item list");
return TRUE;
}
mark_as_dependent(thd, last, current_sel,
this);
ref= last->ref_pointer_array + counter;
} }
}
else if (!group_by_ref && ref == (Item **) not_found_item)
{
my_printf_error(ER_BAD_FIELD_ERROR, ER(ER_BAD_FIELD_ERROR), MYF(0),
this->full_name(), current_thd->where);
return TRUE;
}
else
{
if (ref != (Item **) not_found_item && !ambiguous_fields)
ref= current_sel->ref_pointer_array + counter;
else if (group_by_ref)
ref= group_by_ref;
else else
DBUG_ASSERT(FALSE);
if (!(*ref)->fixed)
{ {
my_error(ER_ILLEGAL_REFERENCE, MYF(0), name, /* The current reference cannot be resolved in this query. */
"forward reference in item list"); my_printf_error(ER_BAD_FIELD_ERROR, ER(ER_BAD_FIELD_ERROR), MYF(0),
return TRUE; this->full_name(), current_thd->where);
return TRUE;
} }
} }
} }
...@@ -2625,15 +2672,18 @@ bool Item_ref::fix_fields(THD *thd, TABLE_LIST *tables, Item **reference) ...@@ -2625,15 +2672,18 @@ bool Item_ref::fix_fields(THD *thd, TABLE_LIST *tables, Item **reference)
with sub-select's / derived tables, while it prevents this with sub-select's / derived tables, while it prevents this
check when Item_ref is created in an expression involving check when Item_ref is created in an expression involving
summing function, which is to be placed in the user variable. summing function, which is to be placed in the user variable.
TODO: this comment is impossible to understand.
*/ */
if (((*ref)->with_sum_func && name && if (((*ref)->with_sum_func && name &&
(depended_from || (depended_from ||
!(current_sel->linkage != GLOBAL_OPTIONS_TYPE && is_having_field))) || !(current_sel->linkage != GLOBAL_OPTIONS_TYPE &&
current_sel->having_fix_field))) ||
!(*ref)->fixed) !(*ref)->fixed)
{ {
my_error(ER_ILLEGAL_REFERENCE, MYF(0), name, my_error(ER_ILLEGAL_REFERENCE, MYF(0), name,
((*ref)->with_sum_func? ((*ref)->with_sum_func?
"reference on group function": "reference to group function":
"forward reference in item list")); "forward reference in item list"));
return TRUE; return TRUE;
} }
......
...@@ -2186,10 +2186,9 @@ Field *find_field_in_real_table(THD *thd, TABLE *table, ...@@ -2186,10 +2186,9 @@ Field *find_field_in_real_table(THD *thd, TABLE *table,
check_privileges need to check privileges check_privileges need to check privileges
RETURN VALUES RETURN VALUES
0 No field was found, or the found field is not unique, or 0 If error: the found field is not unique, or there are
there are no sufficient access priviliges for the no sufficient access priviliges for the found field,
found field, or the field is qualified with non-existing or the field is qualified with non-existing table.
table.
not_found_field The function was called with report_error == not_found_field The function was called with report_error ==
(IGNORE_ERRORS || IGNORE_EXCEPT_NON_UNIQUE) and a (IGNORE_ERRORS || IGNORE_EXCEPT_NON_UNIQUE) and a
field was not found. field was not found.
......
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