mirror of
https://github.com/MariaDB/server.git
synced 2025-07-29 05:21:33 +03:00
Fixed bug#18739: non-standard HAVING extension was allowed in strict ANSI sql mode.
The SQL standard doesn't allow to use in HAVING clause fields that are not present in GROUP BY clause and not under any aggregate function in the HAVING clause. However, mysql allows using such fields. This extension assume that the non-grouping fields will have the same group-wise values. Otherwise, the result will be unpredictable. This extension allowed in strict MODE_ONLY_FULL_GROUP_BY sql mode results in misunderstanding of HAVING capabilities. The new error message ER_NON_GROUPING_FIELD_USED message is added. It says "non-grouping field '%-.64s' is used in %-.64s clause". This message is supposed to be used for reporting errors when some field is not found in the GROUP BY clause but have to be present there. Use cases for this message are this bug and when a field is present in a SELECT item list not under any aggregate function and there is GROUP BY clause present which doesn't mention that field. It renders the ER_WRONG_FIELD_WITH_GROUP error message obsolete as being more descriptive. The resolve_ref_in_select_and_group() function now reports the ER_NON_GROUPING_FIELD_FOUND error if the strict mode is set and the field for HAVING clause is found in the SELECT item list only. sql/share/errmsg.txt: Added the new ER_NON_GROUPING_FIELD_USED error message for the bug#14169. mysql-test/t/having.test: Added test case for the bug#18739: non-standard HAVING extension was allowed in strict ANSI sql mode. mysql-test/r/having.result: Added test case for the bug#18739: non-standard HAVING extension was allowed in strict ANSI sql mode. sql/sql_select.cc: Added TODO comment to change the ER_WRONG_FIELD_WITH_GROUP to more detailed ER_NON_GROUPING_FIELD_USED message. sql/item.cc: Fixed bug#18739: non-standard HAVING extension was allowed in strict ANSI sql mode. The resolve_ref_in_select_and_group() function now reports the ER_NON_GROUPING_FIELD_FOUND error if the strict MODE_ONLY_FULL_GROUP_BY mode is set and the field for HAVING clause is found in the SELECT item list only.
This commit is contained in:
@ -392,3 +392,16 @@ HAVING HU.PROJ.CITY = HU.STAFF.CITY);
|
||||
EMPNUM GRADE*1000
|
||||
E3 13000
|
||||
DROP SCHEMA HU;
|
||||
USE test;
|
||||
create table t1(f1 int);
|
||||
select f1 from t1 having max(f1)=f1;
|
||||
f1
|
||||
select f1 from t1 group by f1 having max(f1)=f1;
|
||||
f1
|
||||
set session sql_mode='ONLY_FULL_GROUP_BY';
|
||||
select f1 from t1 having max(f1)=f1;
|
||||
ERROR 42000: non-grouping field 'f1' is used in HAVING clause
|
||||
select f1 from t1 group by f1 having max(f1)=f1;
|
||||
f1
|
||||
set session sql_mode='';
|
||||
drop table t1;
|
||||
|
@ -393,3 +393,16 @@ SELECT EMPNUM, GRADE*1000
|
||||
HAVING HU.PROJ.CITY = HU.STAFF.CITY);
|
||||
|
||||
DROP SCHEMA HU;
|
||||
USE test;
|
||||
#
|
||||
# Bug#18739: non-standard HAVING extension was allowed in strict ANSI sql mode.
|
||||
#
|
||||
create table t1(f1 int);
|
||||
select f1 from t1 having max(f1)=f1;
|
||||
select f1 from t1 group by f1 having max(f1)=f1;
|
||||
set session sql_mode='ONLY_FULL_GROUP_BY';
|
||||
--error 1461
|
||||
select f1 from t1 having max(f1)=f1;
|
||||
select f1 from t1 group by f1 having max(f1)=f1;
|
||||
set session sql_mode='';
|
||||
drop table t1;
|
||||
|
18
sql/item.cc
18
sql/item.cc
@ -3153,7 +3153,8 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
|
||||
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.
|
||||
derived SELECT column. This extension is allowed only if the
|
||||
MODE_ONLY_FULL_GROUP_BY sql mode isn't enabled.
|
||||
|
||||
NOTES
|
||||
The resolution procedure is:
|
||||
@ -3163,7 +3164,9 @@ static Item** find_field_in_group_list(Item *find_item, ORDER *group_list)
|
||||
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.
|
||||
- otherwise
|
||||
- if the MODE_ONLY_FULL_GROUP_BY mode is enabled return error
|
||||
- else return the found SELECT column.
|
||||
|
||||
|
||||
RETURN
|
||||
@ -3208,6 +3211,17 @@ resolve_ref_in_select_and_group(THD *thd, Item_ident *ref, SELECT_LEX *select)
|
||||
}
|
||||
}
|
||||
|
||||
if (thd->variables.sql_mode & MODE_ONLY_FULL_GROUP_BY &&
|
||||
select_ref != not_found_item && !group_by_ref)
|
||||
{
|
||||
/*
|
||||
Report the error if fields was found only in the SELECT item list and
|
||||
the strict mode is enabled.
|
||||
*/
|
||||
my_error(ER_NON_GROUPING_FIELD_USED, MYF(0),
|
||||
ref->name, "HAVING");
|
||||
return NULL;
|
||||
}
|
||||
if (select_ref != not_found_item || group_by_ref)
|
||||
{
|
||||
if (select_ref != not_found_item && !ambiguous_fields)
|
||||
|
@ -5611,3 +5611,5 @@ ER_TABLE_NEEDS_UPGRADE
|
||||
eng "Table upgrade required. Please do \"REPAIR TABLE `%-.32s`\" to fix it!"
|
||||
ER_SP_NO_AGGREGATE 42000
|
||||
eng "AGGREGATE is not supported for stored functions"
|
||||
ER_NON_GROUPING_FIELD_USED 42000
|
||||
eng "non-grouping field '%-.64s' is used in %-.64s clause"
|
||||
|
@ -12613,6 +12613,10 @@ setup_group(THD *thd, Item **ref_pointer_array, TABLE_LIST *tables,
|
||||
if (item->type() != Item::SUM_FUNC_ITEM && !item->marker &&
|
||||
!item->const_item())
|
||||
{
|
||||
/*
|
||||
TODO: change ER_WRONG_FIELD_WITH_GROUP to more detailed
|
||||
ER_NON_GROUPING_FIELD_USED
|
||||
*/
|
||||
my_error(ER_WRONG_FIELD_WITH_GROUP, MYF(0), item->full_name());
|
||||
return 1;
|
||||
}
|
||||
|
Reference in New Issue
Block a user