List:Commits« Previous MessageNext Message »
From:<gshchepa Date:March 28 2008 9:53am
Subject:bk commit into 5.0 tree (gshchepa:1.2601) BUG#27219
View as plain text  
Below is the list of changes that have just been committed into a local
5.0 repository of gshchepa.  When gshchepa does a push these changes
will be propagated to the main repository and, within 24 hours after the
push, to the public repository.
For information on how to access the public repository
see http://dev.mysql.com/doc/mysql/en/installing-source-tree.html

ChangeSet@stripped, 2008-03-28 13:53:24+04:00, gshchepa@stripped +10 -0
  Bug#27219: Aggregate functions in ORDER BY.
  
  Mixing aggregate functions and non-grouping columns is not allowed in the
  ONLY_FULL_GROUP_BY mode. However in some cases the error wasn't thrown because
  of insufficient check.
  
  In order to check more thoroughly the new algorithm employs a list of outer
  fields used in a sum function and a SELECT_LEX::full_group_by_flag.
  Each non-outer field checked to find out whether it's aggregated or not and
  the current select is marked accordingly.
  All outer fields that are used under an aggregate function are added to the
  Item_sum::outer_fields list and later checked by the Item_sum::check_sum_func
  function.

  mysql-test/r/group_by.result@stripped, 2008-03-28 13:46:40+04:00, gshchepa@stripped +146 -0
    Added a test case for the bug#27219: Aggregate functions in ORDER BY.

  mysql-test/t/group_by.test@stripped, 2008-03-28 13:46:41+04:00, gshchepa@stripped +117 -0
    Added a test case for the bug#27219: Aggregate functions in ORDER BY.

  sql/item.cc@stripped, 2008-03-28 13:46:42+04:00, gshchepa@stripped +24 -4
    Bug#27219: Aggregate functions in ORDER BY.
    Now the Item_field::fix_fields function checks whether the field is aggregated
    or not and marks its select_lex accordingly.

  sql/item_subselect.cc@stripped, 2008-03-28 13:46:43+04:00, gshchepa@stripped +17 -0
    Bug#27219: Aggregate functions in ORDER BY.
    The Item_in_subselect::select_in_like_transformer function now drops
    ORDER BY clause in all selects in a subquery.

  sql/item_sum.cc@stripped, 2008-03-28 13:46:43+04:00, gshchepa@stripped +64 -0
    Bug#27219: Aggregate functions in ORDER BY.
    Now the Item_sum::check_sum_func function now checks whether fields in the
    outer_fields list are aggregated or not and marks selects accordingly.

  sql/item_sum.h@stripped, 2008-03-28 13:46:44+04:00, gshchepa@stripped +7 -0
    Bug#27219: Aggregate functions in ORDER BY.
    The outer_fields list is added to the Item_sum class.

  sql/mysql_priv.h@stripped, 2008-03-28 13:46:44+04:00, gshchepa@stripped +7 -0
    Bug#27219: Aggregate functions in ORDER BY.
    Defined a set of constants used in the new check for mixing non aggregated
    fields and sum functions in the ONLY_FULL_GROUP_BY_MODE.

  sql/sql_lex.cc@stripped, 2008-03-28 13:46:45+04:00, gshchepa@stripped +1 -2
    Bug#27219: Aggregate functions in ORDER BY.
    Initialization of the full_group_by_flag bitmap.
    SELECT_LEX::test_limit function doesn't reset ORDER BY
    clause anymore.

  sql/sql_lex.h@stripped, 2008-03-28 13:46:45+04:00, gshchepa@stripped +10 -1
    Bug#27219: Aggregate functions in ORDER BY.
    The full_group_by_flag is added to the SELECT_LEX class.

  sql/sql_select.cc@stripped, 2008-03-28 13:46:46+04:00, gshchepa@stripped +5 -29
    Bug#27219: Aggregate functions in ORDER BY.
    Implementation of new check for mixing non aggregated fields and aggregation
    function in the ONLY_FULL_GROUP_BY mode.

diff -Nrup a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result
--- a/mysql-test/r/group_by.result	2008-01-11 22:00:24 +04:00
+++ b/mysql-test/r/group_by.result	2008-03-28 13:46:40 +04:00
@@ -1213,4 +1213,150 @@ FROM t1;
 ERROR 21000: Subquery returns more than 1 row
 DROP TABLE t1;
 SET @@sql_mode = @old_sql_mode;
+#
+# 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
diff -Nrup a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test
--- a/mysql-test/t/group_by.test	2008-01-11 22:00:24 +04:00
+++ b/mysql-test/t/group_by.test	2008-03-28 13:46:41 +04:00
@@ -893,4 +893,121 @@ FROM t1;
 DROP TABLE t1;
 SET @@sql_mode = @old_sql_mode;
 
+--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
diff -Nrup a/sql/item.cc b/sql/item.cc
--- a/sql/item.cc	2008-03-25 18:34:52 +04:00
+++ b/sql/item.cc	2008-03-28 13:46:42 +04:00
@@ -3930,9 +3930,9 @@ bool Item_field::fix_fields(THD *thd, It
       }
       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;
@@ -3944,9 +3944,9 @@ bool Item_field::fix_fields(THD *thd, It
       int ret;
       if ((ret= fix_outer_field(thd, &from_field, reference)) < 0)
         goto error;
-      else if (!ret)
-        return FALSE;
       outer_fixed= 1;
+      if (!ret)
+        goto mark_non_agg_field;
     }
 
     /*
@@ -4011,6 +4011,26 @@ bool Item_field::fix_fields(THD *thd, It
   {
     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;
 
diff -Nrup a/sql/item_subselect.cc b/sql/item_subselect.cc
--- a/sql/item_subselect.cc	2008-03-25 18:34:53 +04:00
+++ b/sql/item_subselect.cc	2008-03-28 13:46:43 +04:00
@@ -1476,6 +1476,23 @@ Item_in_subselect::select_in_like_transf
 
   transformed= 1;
   arena= thd->activate_stmt_arena_if_needed(&backup);
+
+  {
+    /*
+      IN/SOME/ALL/ANY subqueries aren't support LIMIT clause. Without it
+      ORDER BY clause becomes meaningless thus we drop it here.
+    */
+    SELECT_LEX_UNIT *unit= current->master_unit();
+    if (unit->fake_select_lex)
+      unit->fake_select_lex->order_list.empty();
+    SELECT_LEX *sl= unit->first_select();
+    for (; sl; sl= sl->next_select())
+    {
+      sl->order_list.empty();
+      if (sl->join)
+        sl->join->order= 0;
+    }
+  }
   /*
     Both transformers call fix_fields() only for Items created inside them,
     and all that items do not make permanent changes in current item arena
diff -Nrup a/sql/item_sum.cc b/sql/item_sum.cc
--- a/sql/item_sum.cc	2008-02-28 15:31:18 +04:00
+++ b/sql/item_sum.cc	2008-03-28 13:46:43 +04:00
@@ -66,6 +66,7 @@ bool Item_sum::init_sum_func_check(THD *
   aggr_sel= NULL;
   max_arg_level= -1;
   max_sum_func_level= -1;
+  outer_fields.empty();
   return FALSE;
 }
 
@@ -175,6 +176,7 @@ bool Item_sum::check_sum_func(THD *thd, 
                MYF(0));
     return TRUE;
   }
+
   if (in_sum_func)
   {
     /*
@@ -195,6 +197,68 @@ bool Item_sum::check_sum_func(THD *thd, 
       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;
diff -Nrup a/sql/item_sum.h b/sql/item_sum.h
--- a/sql/item_sum.h	2007-12-14 15:24:18 +04:00
+++ b/sql/item_sum.h	2008-03-28 13:46:44 +04:00
@@ -239,6 +239,13 @@ public:
   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;
diff -Nrup a/sql/mysql_priv.h b/sql/mysql_priv.h
--- a/sql/mysql_priv.h	2008-02-29 13:55:49 +04:00
+++ b/sql/mysql_priv.h	2008-03-28 13:46:44 +04:00
@@ -1045,6 +1045,13 @@ SQL_SELECT *make_select(TABLE *head, tab
 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
   of possibly aliased items.
diff -Nrup a/sql/sql_lex.cc b/sql/sql_lex.cc
--- a/sql/sql_lex.cc	2007-08-31 04:23:37 +05:00
+++ b/sql/sql_lex.cc	2008-03-28 13:46:45 +04:00
@@ -1253,6 +1253,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;
 }
 
 /*
@@ -1491,8 +1492,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);
 }
 
diff -Nrup a/sql/sql_lex.h b/sql/sql_lex.h
--- a/sql/sql_lex.h	2007-11-19 20:59:43 +04:00
+++ b/sql/sql_lex.h	2008-03-28 13:46:45 +04:00
@@ -611,7 +611,16 @@ public:
     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();
diff -Nrup a/sql/sql_select.cc b/sql/sql_select.cc
--- a/sql/sql_select.cc	2008-03-03 21:35:38 +04:00
+++ b/sql/sql_select.cc	2008-03-28 13:46:46 +04:00
@@ -568,37 +568,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 */
Thread
bk commit into 5.0 tree (gshchepa:1.2601) BUG#27219gshchepa28 Mar