Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in / Register
Toggle navigation
M
MariaDB
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
nexedi
MariaDB
Commits
2a840c60
Commit
2a840c60
authored
Mar 28, 2008
by
unknown
Browse files
Options
Browse Files
Download
Plain Diff
Merge epotemkin@bk-internal.mysql.com:/home/bk/mysql-5.1-bugteam
into moonbone.local:/work/27219-bug-5.1
parents
ff5df7df
490de4d8
Changes
10
Hide whitespace changes
Inline
Side-by-side
Showing
10 changed files
with
395 additions
and
35 deletions
+395
-35
mysql-test/r/group_by.result
mysql-test/r/group_by.result
+146
-0
mysql-test/t/group_by.test
mysql-test/t/group_by.test
+117
-0
sql/item.cc
sql/item.cc
+24
-4
sql/item_subselect.cc
sql/item_subselect.cc
+14
-0
sql/item_sum.cc
sql/item_sum.cc
+64
-0
sql/item_sum.h
sql/item_sum.h
+7
-0
sql/mysql_priv.h
sql/mysql_priv.h
+7
-0
sql/sql_lex.cc
sql/sql_lex.cc
+1
-2
sql/sql_lex.h
sql/sql_lex.h
+10
-0
sql/sql_select.cc
sql/sql_select.cc
+5
-29
No files found.
mysql-test/r/group_by.result
View file @
2a840c60
...
...
@@ -1128,6 +1128,152 @@ id c1 c2
4 2 3
1 5 1
DROP TABLE t1;
#
# Bug#27219: Aggregate functions in ORDER BY.
#
SET @save_sql_mode=@@sql_mode;
SET @@sql_mode='ONLY_FULL_GROUP_BY';
CREATE TABLE t1 (a INT, b INT, c INT DEFAULT 0);
INSERT INTO t1 (a, b) VALUES (3,3), (2,2), (3,3), (2,2), (3,3), (4,4);
CREATE TABLE t2 SELECT * FROM t1;
SELECT 1 FROM t1 ORDER BY COUNT(*);
1
1
SELECT 1 FROM t1 ORDER BY COUNT(*) + 1;
1
1
SELECT 1 FROM t1 ORDER BY COUNT(*) + a;
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT 1 FROM t1 ORDER BY COUNT(*), 1;
1
1
SELECT 1 FROM t1 ORDER BY COUNT(*), a;
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT 1 FROM t1 ORDER BY SUM(a);
1
1
SELECT 1 FROM t1 ORDER BY SUM(a + 1);
1
1
SELECT 1 FROM t1 ORDER BY SUM(a) + 1;
1
1
SELECT 1 FROM t1 ORDER BY SUM(a), b;
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT a FROM t1 ORDER BY COUNT(b);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1 ORDER BY (SELECT SUM(t2.a) FROM t2);
a
3
2
3
2
3
4
SELECT t1.a FROM t1 ORDER BY (SELECT SUM(t2.a), t2.a FROM t2);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1 ORDER BY (SELECT SUM(t2.a) FROM t2 ORDER BY t2.a);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1 ORDER BY (SELECT t2.a FROM t2 ORDER BY SUM(t2.b) LIMIT 1);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1
WHERE t1.a = (SELECT t2.a FROM t2 ORDER BY SUM(t2.b) LIMIT 1);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1 GROUP BY t1.a
HAVING t1.a = (SELECT t2.a FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1 GROUP BY t1.a
HAVING t1.a IN (SELECT t2.a FROM t2 ORDER BY SUM(t1.b));
a
2
3
4
SELECT t1.a FROM t1 GROUP BY t1.a
HAVING t1.a IN (SELECT t2.a FROM t2 ORDER BY t2.a, SUM(t2.b));
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1 GROUP BY t1.a
HAVING t1.a > ANY (SELECT t2.a FROM t2 ORDER BY t2.a, SUM(t2.b));
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1
WHERE t1.a = (SELECT t2.a FROM t2 ORDER BY SUM(t1.b));
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT 1 FROM t1 GROUP BY t1.a
HAVING (SELECT AVG(SUM(t1.b) + 1) FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
1
1
1
1
SELECT 1 FROM t1 GROUP BY t1.a
HAVING (SELECT AVG(SUM(t1.b) + t2.b) FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
1
1
1
1
SELECT 1 FROM t1 GROUP BY t1.a
HAVING (SELECT AVG(t1.b + t2.b) FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
1
1
1
1
SELECT 1 FROM t1 GROUP BY t1.a
HAVING (SELECT AVG(SUM(t1.b) + 1) FROM t2 ORDER BY t2.a LIMIT 1);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT 1 FROM t1 GROUP BY t1.a
HAVING (SELECT AVG(SUM(t1.b) + t2.b) FROM t2 ORDER BY t2.a LIMIT 1);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT 1 FROM t1 GROUP BY t1.a
HAVING (SELECT AVG(t1.b + t2.b) FROM t2 ORDER BY t2.a LIMIT 1);
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
SELECT t1.a FROM t1
WHERE t1.a = (SELECT t2.a FROM t2 GROUP BY t2.a
ORDER BY SUM(t2.b), SUM(t1.b) LIMIT 1);
a
4
SELECT t1.a, SUM(t1.b) FROM t1
WHERE t1.a = (SELECT SUM(t2.b) FROM t2 GROUP BY t2.a
ORDER BY SUM(t2.b), SUM(t1.b) LIMIT 1)
GROUP BY t1.a;
a SUM(t1.b)
4 4
SELECT t1.a, SUM(t1.b) FROM t1
WHERE t1.a = (SELECT SUM(t2.b) FROM t2
ORDER BY SUM(t2.b) + SUM(t1.b) LIMIT 1)
GROUP BY t1.a;
a SUM(t1.b)
SELECT t1.a, SUM(t1.b) FROM t1
WHERE t1.a = (SELECT SUM(t2.b) FROM t2
ORDER BY SUM(t2.b + t1.a) LIMIT 1)
GROUP BY t1.a;
a SUM(t1.b)
SELECT t1.a FROM t1 GROUP BY t1.a
HAVING (1, 1) = (SELECT SUM(t1.a), t1.a FROM t2 LIMIT 1);
a
select avg (
(select
(select sum(outr.a + innr.a) from t1 as innr limit 1) as tt
from t1 as outr order by outr.a limit 1))
from t1 as most_outer;
avg (
(select
(select sum(outr.a + innr.a) from t1 as innr limit 1) as tt
from t1 as outr order by outr.a limit 1))
29.0000
select avg (
(select (
(select sum(outr.a + innr.a) from t1 as innr limit 1)) as tt
from t1 as outr order by count(outr.a) limit 1)) as tt
from t1 as most_outer;
ERROR 42000: Mixing of GROUP columns (MIN(),MAX(),COUNT(),...) with no GROUP columns is illegal if there is no GROUP BY clause
select (select sum(outr.a + t1.a) from t1 limit 1) as tt from t1 as outr order by outr.a;
tt
29
29
35
35
35
41
SET sql_mode=@save_sql_mode;
DROP TABLE t1, t2;
End of 5.0 tests
CREATE TABLE t1 (a INT, b INT,
PRIMARY KEY (a),
...
...
mysql-test/t/group_by.test
View file @
2a840c60
...
...
@@ -823,6 +823,123 @@ SELECT * FROM t1 GROUP BY c2 ORDER BY c2 DESC, c1 DESC;
DROP
TABLE
t1
;
--
echo
#
--
echo
# Bug#27219: Aggregate functions in ORDER BY.
--
echo
#
SET
@
save_sql_mode
=@@
sql_mode
;
SET
@@
sql_mode
=
'ONLY_FULL_GROUP_BY'
;
CREATE
TABLE
t1
(
a
INT
,
b
INT
,
c
INT
DEFAULT
0
);
INSERT
INTO
t1
(
a
,
b
)
VALUES
(
3
,
3
),
(
2
,
2
),
(
3
,
3
),
(
2
,
2
),
(
3
,
3
),
(
4
,
4
);
CREATE
TABLE
t2
SELECT
*
FROM
t1
;
SELECT
1
FROM
t1
ORDER
BY
COUNT
(
*
);
SELECT
1
FROM
t1
ORDER
BY
COUNT
(
*
)
+
1
;
--
error
1140
SELECT
1
FROM
t1
ORDER
BY
COUNT
(
*
)
+
a
;
SELECT
1
FROM
t1
ORDER
BY
COUNT
(
*
),
1
;
--
error
1140
SELECT
1
FROM
t1
ORDER
BY
COUNT
(
*
),
a
;
SELECT
1
FROM
t1
ORDER
BY
SUM
(
a
);
SELECT
1
FROM
t1
ORDER
BY
SUM
(
a
+
1
);
SELECT
1
FROM
t1
ORDER
BY
SUM
(
a
)
+
1
;
--
error
1140
SELECT
1
FROM
t1
ORDER
BY
SUM
(
a
),
b
;
--
error
1140
SELECT
a
FROM
t1
ORDER
BY
COUNT
(
b
);
SELECT
t1
.
a
FROM
t1
ORDER
BY
(
SELECT
SUM
(
t2
.
a
)
FROM
t2
);
--
error
1140
SELECT
t1
.
a
FROM
t1
ORDER
BY
(
SELECT
SUM
(
t2
.
a
),
t2
.
a
FROM
t2
);
--
error
1140
SELECT
t1
.
a
FROM
t1
ORDER
BY
(
SELECT
SUM
(
t2
.
a
)
FROM
t2
ORDER
BY
t2
.
a
);
--
error
1140
SELECT
t1
.
a
FROM
t1
ORDER
BY
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
SUM
(
t2
.
b
)
LIMIT
1
);
--
error
1140
SELECT
t1
.
a
FROM
t1
WHERE
t1
.
a
=
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
SUM
(
t2
.
b
)
LIMIT
1
);
--
error
1140
SELECT
t1
.
a
FROM
t1
GROUP
BY
t1
.
a
HAVING
t1
.
a
=
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
SUM
(
t2
.
a
)
LIMIT
1
);
SELECT
t1
.
a
FROM
t1
GROUP
BY
t1
.
a
HAVING
t1
.
a
IN
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
SUM
(
t1
.
b
));
--
error
1140
SELECT
t1
.
a
FROM
t1
GROUP
BY
t1
.
a
HAVING
t1
.
a
IN
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
t2
.
a
,
SUM
(
t2
.
b
));
--
error
1140
SELECT
t1
.
a
FROM
t1
GROUP
BY
t1
.
a
HAVING
t1
.
a
>
ANY
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
t2
.
a
,
SUM
(
t2
.
b
));
--
error
1140
SELECT
t1
.
a
FROM
t1
WHERE
t1
.
a
=
(
SELECT
t2
.
a
FROM
t2
ORDER
BY
SUM
(
t1
.
b
));
SELECT
1
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
SELECT
AVG
(
SUM
(
t1
.
b
)
+
1
)
FROM
t2
ORDER
BY
SUM
(
t2
.
a
)
LIMIT
1
);
SELECT
1
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
SELECT
AVG
(
SUM
(
t1
.
b
)
+
t2
.
b
)
FROM
t2
ORDER
BY
SUM
(
t2
.
a
)
LIMIT
1
);
SELECT
1
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
SELECT
AVG
(
t1
.
b
+
t2
.
b
)
FROM
t2
ORDER
BY
SUM
(
t2
.
a
)
LIMIT
1
);
--
error
1140
SELECT
1
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
SELECT
AVG
(
SUM
(
t1
.
b
)
+
1
)
FROM
t2
ORDER
BY
t2
.
a
LIMIT
1
);
--
error
1140
SELECT
1
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
SELECT
AVG
(
SUM
(
t1
.
b
)
+
t2
.
b
)
FROM
t2
ORDER
BY
t2
.
a
LIMIT
1
);
--
error
1140
SELECT
1
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
SELECT
AVG
(
t1
.
b
+
t2
.
b
)
FROM
t2
ORDER
BY
t2
.
a
LIMIT
1
);
# Both SUMs are aggregated in the subquery, no mixture:
SELECT
t1
.
a
FROM
t1
WHERE
t1
.
a
=
(
SELECT
t2
.
a
FROM
t2
GROUP
BY
t2
.
a
ORDER
BY
SUM
(
t2
.
b
),
SUM
(
t1
.
b
)
LIMIT
1
);
# SUM(t1.b) is aggregated in the subquery, no mixture:
SELECT
t1
.
a
,
SUM
(
t1
.
b
)
FROM
t1
WHERE
t1
.
a
=
(
SELECT
SUM
(
t2
.
b
)
FROM
t2
GROUP
BY
t2
.
a
ORDER
BY
SUM
(
t2
.
b
),
SUM
(
t1
.
b
)
LIMIT
1
)
GROUP
BY
t1
.
a
;
# 2nd SUM(t1.b) is aggregated in the subquery, no mixture:
SELECT
t1
.
a
,
SUM
(
t1
.
b
)
FROM
t1
WHERE
t1
.
a
=
(
SELECT
SUM
(
t2
.
b
)
FROM
t2
ORDER
BY
SUM
(
t2
.
b
)
+
SUM
(
t1
.
b
)
LIMIT
1
)
GROUP
BY
t1
.
a
;
# SUM(t2.b + t1.a) is aggregated in the subquery, no mixture:
SELECT
t1
.
a
,
SUM
(
t1
.
b
)
FROM
t1
WHERE
t1
.
a
=
(
SELECT
SUM
(
t2
.
b
)
FROM
t2
ORDER
BY
SUM
(
t2
.
b
+
t1
.
a
)
LIMIT
1
)
GROUP
BY
t1
.
a
;
SELECT
t1
.
a
FROM
t1
GROUP
BY
t1
.
a
HAVING
(
1
,
1
)
=
(
SELECT
SUM
(
t1
.
a
),
t1
.
a
FROM
t2
LIMIT
1
);
select
avg
(
(
select
(
select
sum
(
outr
.
a
+
innr
.
a
)
from
t1
as
innr
limit
1
)
as
tt
from
t1
as
outr
order
by
outr
.
a
limit
1
))
from
t1
as
most_outer
;
--
error
1140
select
avg
(
(
select
(
(
select
sum
(
outr
.
a
+
innr
.
a
)
from
t1
as
innr
limit
1
))
as
tt
from
t1
as
outr
order
by
count
(
outr
.
a
)
limit
1
))
as
tt
from
t1
as
most_outer
;
select
(
select
sum
(
outr
.
a
+
t1
.
a
)
from
t1
limit
1
)
as
tt
from
t1
as
outr
order
by
outr
.
a
;
SET
sql_mode
=@
save_sql_mode
;
DROP
TABLE
t1
,
t2
;
--
echo
End
of
5.0
tests
# Bug #21174: Index degrades sort performance and
# optimizer does not honor IGNORE INDEX.
...
...
sql/item.cc
View file @
2a840c60
...
...
@@ -4003,9 +4003,9 @@ bool Item_field::fix_fields(THD *thd, Item **reference)
}
if
((
ret
=
fix_outer_field
(
thd
,
&
from_field
,
reference
))
<
0
)
goto
error
;
else
if
(
!
ret
)
return
FALSE
;
outer_fixed
=
TRUE
;
if
(
!
ret
)
goto
mark_non_agg_field
;
}
else
if
(
!
from_field
)
goto
error
;
...
...
@@ -4017,9 +4017,9 @@ bool Item_field::fix_fields(THD *thd, Item **reference)
int
ret
;
if
((
ret
=
fix_outer_field
(
thd
,
&
from_field
,
reference
))
<
0
)
goto
error
;
if
(
!
ret
)
return
FALSE
;
outer_fixed
=
1
;
if
(
!
ret
)
goto
mark_non_agg_field
;
}
/*
...
...
@@ -4103,6 +4103,26 @@ bool Item_field::fix_fields(THD *thd, Item **reference)
thd
->
lex
->
current_select
->
non_agg_fields
.
push_back
(
this
);
marker
=
thd
->
lex
->
current_select
->
cur_pos_in_select_list
;
}
mark_non_agg_field:
if
(
fixed
&&
thd
->
variables
.
sql_mode
&
MODE_ONLY_FULL_GROUP_BY
)
{
/*
Mark selects according to presence of non aggregated fields.
Fields from outer selects added to the aggregate function
outer_fields list as its unknown at the moment whether it's
aggregated or not.
*/
if
(
!
thd
->
lex
->
in_sum_func
)
cached_table
->
select_lex
->
full_group_by_flag
|=
NON_AGG_FIELD_USED
;
else
{
if
(
outer_fixed
)
thd
->
lex
->
in_sum_func
->
outer_fields
.
push_back
(
this
);
else
if
(
thd
->
lex
->
in_sum_func
->
nest_level
!=
thd
->
lex
->
current_select
->
nest_level
)
cached_table
->
select_lex
->
full_group_by_flag
|=
NON_AGG_FIELD_USED
;
}
}
return
FALSE
;
error:
...
...
sql/item_subselect.cc
View file @
2a840c60
...
...
@@ -1498,6 +1498,19 @@ Item_in_subselect::select_in_like_transformer(JOIN *join, Comp_creator *func)
DBUG_ENTER
(
"Item_in_subselect::select_in_like_transformer"
);
{
/*
IN/SOME/ALL/ANY subqueries aren't support LIMIT clause. Without it
ORDER BY clause becomes meaningless thus we drop it here.
*/
SELECT_LEX
*
sl
=
current
->
master_unit
()
->
first_select
();
for
(;
sl
;
sl
=
sl
->
next_select
())
{
if
(
sl
->
join
)
sl
->
join
->
order
=
0
;
}
}
if
(
changed
)
{
DBUG_RETURN
(
RES_OK
);
...
...
@@ -1532,6 +1545,7 @@ Item_in_subselect::select_in_like_transformer(JOIN *join, Comp_creator *func)
transformed
=
1
;
arena
=
thd
->
activate_stmt_arena_if_needed
(
&
backup
);
/*
Both transformers call fix_fields() only for Items created inside them,
and all that items do not make permanent changes in current item arena
...
...
sql/item_sum.cc
View file @
2a840c60
...
...
@@ -68,6 +68,7 @@ bool Item_sum::init_sum_func_check(THD *thd)
aggr_sel
=
NULL
;
max_arg_level
=
-
1
;
max_sum_func_level
=
-
1
;
outer_fields
.
empty
();
return
FALSE
;
}
...
...
@@ -176,6 +177,7 @@ bool Item_sum::check_sum_func(THD *thd, Item **ref)
MYF
(
0
));
return
TRUE
;
}
if
(
in_sum_func
)
{
/*
...
...
@@ -196,6 +198,68 @@ bool Item_sum::check_sum_func(THD *thd, Item **ref)
set_if_bigger
(
in_sum_func
->
max_sum_func_level
,
aggr_level
);
set_if_bigger
(
in_sum_func
->
max_sum_func_level
,
max_sum_func_level
);
}
/*
Check that non-aggregated fields and sum functions aren't mixed in the
same select in the ONLY_FULL_GROUP_BY mode.
*/
if
(
outer_fields
.
elements
)
{
Item_field
*
field
;
/*
Here we compare the nesting level of the select to which an outer field
belongs to with the aggregation level of the sum function. All fields in
the outer_fields list are checked.
If the nesting level is equal to the aggregation level then the field is
aggregated by this sum function.
If the nesting level is less than the aggregation level then the field
belongs to an outer select. In this case if there is an embedding sum
function add current field to functions outer_fields list. If there is
no embedding function then the current field treated as non aggregated
and the select it belongs to is marked accordingly.
If the nesting level is greater than the aggregation level then it means
that this field was added by an inner sum function.
Consider an example:
select avg ( <-- we are here, checking outer.f1
select (
select sum(outer.f1 + inner.f1) from inner
) from outer)
from most_outer;
In this case we check that no aggregate functions are used in the
select the field belongs to. If there are some then an error is
raised.
*/
List_iterator
<
Item_field
>
of
(
outer_fields
);
while
((
field
=
of
++
))
{
SELECT_LEX
*
sel
=
field
->
cached_table
->
select_lex
;
if
(
sel
->
nest_level
<
aggr_level
)
{
if
(
in_sum_func
)
{
/*
Let upper function decide whether this field is a non
aggregated one.
*/
in_sum_func
->
outer_fields
.
push_back
(
field
);
}
else
sel
->
full_group_by_flag
|=
NON_AGG_FIELD_USED
;
}
if
(
sel
->
nest_level
>
aggr_level
&&
(
sel
->
full_group_by_flag
&
SUM_FUNC_USED
)
&&
!
sel
->
group_list
.
elements
)
{
my_message
(
ER_MIX_OF_GROUP_FUNC_AND_FIELDS
,
ER
(
ER_MIX_OF_GROUP_FUNC_AND_FIELDS
),
MYF
(
0
));
return
TRUE
;
}
}
}
aggr_sel
->
full_group_by_flag
|=
SUM_FUNC_USED
;
update_used_tables
();
thd
->
lex
->
in_sum_func
=
in_sum_func
;
return
FALSE
;
...
...
sql/item_sum.h
View file @
2a840c60
...
...
@@ -239,6 +239,13 @@ class Item_sum :public Item_result_field
int8
max_arg_level
;
/* max level of unbound column references */
int8
max_sum_func_level
;
/* max level of aggregation for embedded functions */
bool
quick_group
;
/* If incremental update of fields */
/*
This list is used by the check for mixing non aggregated fields and
sum functions in the ONLY_FULL_GROUP_BY_MODE. We save all outer fields
directly or indirectly used under this function it as it's unclear
at the moment of fixing outer field whether it's aggregated or not.
*/
List
<
Item_field
>
outer_fields
;
protected:
table_map
used_tables_cache
;
...
...
sql/mysql_priv.h
View file @
2a840c60
...
...
@@ -1406,6 +1406,13 @@ SQL_SELECT *make_select(TABLE *head, table_map const_tables,
bool
allow_null_cond
,
int
*
error
);
extern
Item
**
not_found_item
;
/*
A set of constants used for checking non aggregated fields and sum
functions mixture in the ONLY_FULL_GROUP_BY_MODE.
*/
#define NON_AGG_FIELD_USED 1
#define SUM_FUNC_USED 2
/*
This enumeration type is used only by the function find_item_in_list
to return the info on how an item has been resolved against a list
...
...
sql/sql_lex.cc
View file @
2a840c60
...
...
@@ -1601,6 +1601,7 @@ void st_select_lex::init_select()
non_agg_fields
.
empty
();
cond_value
=
having_value
=
Item
::
COND_UNDEF
;
inner_refs_list
.
empty
();
full_group_by_flag
=
0
;
}
/*
...
...
@@ -1836,8 +1837,6 @@ bool st_select_lex::test_limit()
"LIMIT & IN/ALL/ANY/SOME subquery"
);
return
(
1
);
}
// no sense in ORDER BY without LIMIT
order_list
.
empty
();
return
(
0
);
}
...
...
sql/sql_lex.h
View file @
2a840c60
...
...
@@ -692,6 +692,16 @@ class st_select_lex: public st_select_lex_node
joins on the right.
*/
List
<
String
>
*
prev_join_using
;
/*
Bitmap used in the ONLY_FULL_GROUP_BY_MODE to prevent mixture of aggregate
functions and non aggregated fields when GROUP BY list is absent.
Bits:
0 - non aggregated fields are used in this select,
defined as NON_AGG_FIELD_USED.
1 - aggregate functions are used in this select,
defined as SUM_FUNC_USED.
*/
uint8
full_group_by_flag
;
void
init_query
();
void
init_select
();
st_select_lex_unit
*
master_unit
();
...
...
sql/sql_select.cc
View file @
2a840c60
...
...
@@ -585,37 +585,13 @@ JOIN::prepare(Item ***rref_pointer_array,
/*
Check if there are references to un-aggregated columns when computing
aggregate functions with implicit grouping (there is no GROUP BY).
TODO: Add check of calculation of GROUP functions and fields:
SELECT COUNT(*)+table.col1 from table1;
*/
if
(
thd
->
variables
.
sql_mode
&
MODE_ONLY_FULL_GROUP_BY
)
if
(
thd
->
variables
.
sql_mode
&
MODE_ONLY_FULL_GROUP_BY
&&
!
group_list
&&
select_lex
->
full_group_by_flag
==
(
NON_AGG_FIELD_USED
|
SUM_FUNC_USED
))
{
if
(
!
group_list
)
{
uint
flag
=
0
;
List_iterator_fast
<
Item
>
it
(
fields_list
);
Item
*
item
;
while
((
item
=
it
++
))
{
if
(
item
->
with_sum_func
)
flag
|=
1
;
else
if
(
!
(
flag
&
2
)
&&
!
item
->
const_during_execution
())
flag
|=
2
;
}
if
(
having
)
{
if
(
having
->
with_sum_func
)
flag
|=
1
;
else
if
(
!
having
->
const_during_execution
())
flag
|=
2
;
}
if
(
flag
==
3
)
{
my_message
(
ER_MIX_OF_GROUP_FUNC_AND_FIELDS
,
ER
(
ER_MIX_OF_GROUP_FUNC_AND_FIELDS
),
MYF
(
0
));
DBUG_RETURN
(
-
1
);
}
}
my_message
(
ER_MIX_OF_GROUP_FUNC_AND_FIELDS
,
ER
(
ER_MIX_OF_GROUP_FUNC_AND_FIELDS
),
MYF
(
0
));
DBUG_RETURN
(
-
1
);
}
{
/* Caclulate the number of groups */
...
...
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment