[Commits] b6daedac14b: MDEV-11563: GROUP_CONCAT(DISTINCT ...) may produce a non-distinct list

Varun varunraiko1803 at gmail.com
Thu Aug 10 01:44:08 EEST 2017


revision-id: b6daedac14b9038251a8c827403c8857d7088da9 (mariadb-5.5.56-66-gb6daedac14b)
parent(s): 0739179857699d68758ff2e56e9414735546ded6
author: Varun Gupta
committer: Varun Gupta
timestamp: 2017-08-10 04:10:48 +0530
message:

MDEV-11563: GROUP_CONCAT(DISTINCT ...) may produce a non-distinct list

 Backported from MYSQL
 Bug #25331425: DISTINCT CLAUSE DOES NOT WORK IN GROUP_CONCAT
    Issue:
    ------
    The problem occurs when:
    1) GROUP_CONCAT (DISTINCT ....) is used in the query.
    2) Data size greater than value of system variable:
    tmp_table_size.

    The result would contain values that are non-unique.

    Root cause:
    -----------
    An in-memory structure is used to filter out non-unique
    values. When the data size exceeds tmp_table_size, the
    overflow is written to disk as a separate file. The
    expectation here is that when all such files are merged,
    the full set of unique values can be obtained.

    But the Item_func_group_concat::add function is in a bit of
    hurry. Even as it is adding values to the tree, it wants to
    decide if a value is unique and write it to the result
    buffer. This works fine if the configured maximum size is
    greater than the size of the data. But since tmp_table_size
    is set to a low value, the size of the tree is smaller and
    hence requires the creation of multiple copies on disk.

    Item_func_group_concat currently has no mechanism to merge
    all the copies on disk and then generate the result. This
    results in duplicate values.

    Solution:
    ---------
    In case of the DISTINCT clause, don't write to the result
    buffer immediately. Do the merge and only then put the
    unique values in the result buffer. This has be done in
    Item_func_group_concat::val_str.

    Note regarding result file changes:
    -----------------------------------
    Earlier when a unique value was seen in
    Item_func_group_concat::add, it was dumped to the output.
    So result is in the order stored in SE. But with this fix,
    we wait until all the data is read and the final set of
    unique values are written to output buffer. So the data
    appears in the sorted order.

---
 mysql-test/r/func_gconcat.result | 62 +++++++++++++++++++++++++++-------------
 mysql-test/t/func_gconcat.test   | 23 +++++++++++++++
 sql/item_sum.cc                  | 27 ++++++++++-------
 sql/item_sum.h                   |  3 +-
 4 files changed, 83 insertions(+), 32 deletions(-)

diff --git a/mysql-test/r/func_gconcat.result b/mysql-test/r/func_gconcat.result
index 0bc31a5e85b..a343b35b628 100644
--- a/mysql-test/r/func_gconcat.result
+++ b/mysql-test/r/func_gconcat.result
@@ -364,8 +364,8 @@ bb,ccc,a,bb,ccc
 BB,CCC,A,BB,CCC
 select group_concat(distinct b) from t1 group by a;
 group_concat(distinct b)
-bb,ccc,a
-BB,CCC,A
+a,bb,ccc
+A,BB,CCC
 select group_concat(b order by b) from t1 group by a;
 group_concat(b order by b)
 a,bb,bb,ccc,ccc
@@ -384,11 +384,11 @@ Warning	1260	Row 2 was cut by GROUP_CONCAT()
 Warning	1260	Row 4 was cut by GROUP_CONCAT()
 select group_concat(distinct b) from t1 group by a;
 group_concat(distinct b)
-bb,c
-BB,C
+a,bb
+A,BB
 Warnings:
-Warning	1260	Row 2 was cut by GROUP_CONCAT()
-Warning	1260	Row 4 was cut by GROUP_CONCAT()
+Warning	1260	Row 3 was cut by GROUP_CONCAT()
+Warning	1260	Row 6 was cut by GROUP_CONCAT()
 select group_concat(b order by b) from t1 group by a;
 group_concat(b order by b)
 a,bb
@@ -414,8 +414,8 @@ bb,ccc,a,bb,ccc,1111111111111111111111111111111111111111111111111111111111111111
 BB,CCC,A,BB,CCC,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001
 select group_concat(distinct b) from t1 group by a;
 group_concat(distinct b)
-bb,ccc,a,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001
-BB,CCC,A,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001
+0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,a,bb,ccc
+0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,A,BB,CCC
 select group_concat(b order by b) from t1 group by a;
 group_concat(b order by b)
 0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,a,bb,bb,ccc,ccc
@@ -434,11 +434,11 @@ Warning	1260	Row 7 was cut by GROUP_CONCAT()
 Warning	1260	Row 14 was cut by GROUP_CONCAT()
 select group_concat(distinct b) from t1 group by a;
 group_concat(distinct b)
-bb,ccc,a,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000
-BB,CCC,A,1111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111112,00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000
+0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001,11111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111
+0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001,11111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111
 Warnings:
-Warning	1260	Row 5 was cut by GROUP_CONCAT()
-Warning	1260	Row 10 was cut by GROUP_CONCAT()
+Warning	1260	Row 2 was cut by GROUP_CONCAT()
+Warning	1260	Row 4 was cut by GROUP_CONCAT()
 select group_concat(b order by b) from t1 group by a;
 group_concat(b order by b)
 0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001,11111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111111
@@ -521,9 +521,9 @@ a	group_concat(b)
 NULL	3,4,2,1,2,7,3,3
 select a, group_concat(distinct b) from t1 group by a with rollup;
 a	group_concat(distinct b)
-1	3,4,2,1
-2	7,3
-NULL	3,4,2,1,7
+1	1,2,3,4
+2	3,7
+NULL	1,2,3,4,7
 select a, group_concat(b order by b) from t1 group by a with rollup;
 a	group_concat(b order by b)
 1	1,2,2,3,4
@@ -746,10 +746,10 @@ CREATE TABLE t1(a TEXT, b CHAR(20));
 INSERT INTO t1 VALUES ("one.1","one.1"),("two.2","two.2"),("one.3","one.3");
 SELECT GROUP_CONCAT(DISTINCT UCASE(a)) FROM t1;
 GROUP_CONCAT(DISTINCT UCASE(a))
-ONE.1,TWO.2,ONE.3
+ONE.1,ONE.3,TWO.2
 SELECT GROUP_CONCAT(DISTINCT UCASE(b)) FROM t1;
 GROUP_CONCAT(DISTINCT UCASE(b))
-ONE.1,TWO.2,ONE.3
+ONE.1,ONE.3,TWO.2
 DROP TABLE t1;
 CREATE TABLE t1( a VARCHAR( 10 ), b INT );
 INSERT INTO t1 VALUES ( repeat( 'a', 10 ), 1), 
@@ -848,7 +848,7 @@ create table t1(a bit(2) not null);
 insert into t1 values (1), (0), (0), (3), (1);
 select group_concat(distinct a) from t1;
 group_concat(distinct a)
-1,0,3
+0,1,3
 select group_concat(distinct a order by a) from t1;
 group_concat(distinct a order by a)
 0,1,3
@@ -861,13 +861,13 @@ insert into t1 values (1, 'a', 0), (0, 'b', 1), (0, 'c', 0), (3, 'd', 1),
 (1, 'e', 1), (3, 'f', 1), (0, 'g', 1);
 select group_concat(distinct a, c) from t1;
 group_concat(distinct a, c)
-10,01,00,31,11
+00,01,10,11,31
 select group_concat(distinct a, c order by a) from t1;
 group_concat(distinct a, c order by a)
 00,01,11,10,31
 select group_concat(distinct a, c) from t1;
 group_concat(distinct a, c)
-10,01,00,31,11
+00,01,10,11,31
 select group_concat(distinct a, c order by a, c) from t1;
 group_concat(distinct a, c order by a, c)
 00,01,10,11,31
@@ -1119,3 +1119,25 @@ GROUP_CONCAT(t1a.a ORDER BY 1, t1a.a=0)
 1,1
 2,2
 DROP TABLE t1;
+#
+#MDEV-11563: GROUP_CONCAT(DISTINCT ...) may produce a non-distinct list
+#
+create table t1 (
+a VARCHAR(1000),
+b int
+);
+insert into t1 values
+( 0 , 1 ),
+( 1 , 2 ),
+( 2 , 3 ),
+( 3 , 4 ),
+( 4 , 5 ),
+( 5 , 6 ),
+( 0 , 11 ),
+( 5 , 16 );
+set @@tmp_table_size=1024;
+select group_concat(distinct a) from t1;
+group_concat(distinct a)
+0,1,2,3,4,5
+set local tmp_table_size=default;
+drop table t1;
diff --git a/mysql-test/t/func_gconcat.test b/mysql-test/t/func_gconcat.test
index 5550eebf1a3..4ee50364871 100644
--- a/mysql-test/t/func_gconcat.test
+++ b/mysql-test/t/func_gconcat.test
@@ -832,3 +832,26 @@ PREPARE stmt FROM "SELECT GROUP_CONCAT(t1a.a ORDER BY 1, t1a.a=0) FROM t1 AS t1a
 EXECUTE stmt;
 EXECUTE stmt;
 DROP TABLE t1;
+
+
+--echo #
+--echo #MDEV-11563: GROUP_CONCAT(DISTINCT ...) may produce a non-distinct list
+--echo #
+
+create table t1 (
+a VARCHAR(1000),
+b int
+);
+insert into t1 values
+( 0 , 1 ),
+( 1 , 2 ),
+( 2 , 3 ),
+( 3 , 4 ),
+( 4 , 5 ),
+( 5 , 6 ),
+( 0 , 11 ),
+( 5 , 16 );
+set @@tmp_table_size=1024;
+select group_concat(distinct a) from t1;
+set local tmp_table_size=default;
+drop table t1;
diff --git a/sql/item_sum.cc b/sql/item_sum.cc
index 9a2e2e6cd4c..330d5fc6a8d 100644
--- a/sql/item_sum.cc
+++ b/sql/item_sum.cc
@@ -3083,8 +3083,8 @@ int dump_leaf_key(void* key_arg, element_count count __attribute__((unused)),
   Item **arg= item->args, **arg_end= item->args + item->arg_count_field;
   uint old_length= result->length();
 
-  if (item->no_appended)
-    item->no_appended= FALSE;
+  if (!item->m_result_finalized)
+    item->m_result_finalized= true;
   else
     result->append(*item->separator);
 
@@ -3342,7 +3342,7 @@ void Item_func_group_concat::clear()
   result.copy();
   null_value= TRUE;
   warning_for_row= FALSE;
-  no_appended= TRUE;
+  m_result_finalized= false;
   if (tree)
     reset_tree(tree);
   if (unique_filter)
@@ -3396,12 +3396,10 @@ bool Item_func_group_concat::add()
       return 1;
   }
   /*
-    If the row is not a duplicate (el->count == 1)
-    we can dump the row here in case of GROUP_CONCAT(DISTINCT...)
-    instead of doing tree traverse later.
+    In case of GROUP_CONCAT with DISTINCT or ORDER BY (or both) don't dump the
+    row to the output buffer here. That will be done in val_str.
   */
-  if (row_eligible && !warning_for_row &&
-      (!tree || (el->count == 1 && distinct && !arg_count_order)))
+  if (row_eligible && !warning_for_row && (!tree && !distinct))
     dump_leaf_key(table->record[0] + table->s->null_bytes, 1, this);
 
   return 0;
@@ -3623,9 +3621,16 @@ String* Item_func_group_concat::val_str(String* str)
   DBUG_ASSERT(fixed == 1);
   if (null_value)
     return 0;
-  if (no_appended && tree)
-    /* Tree is used for sorting as in ORDER BY */
-    tree_walk(tree, &dump_leaf_key, this, left_root_right);
+
+  if (!m_result_finalized) // Result yet to be written.
+  {
+    if (tree != NULL) // order by
+      tree_walk(tree, &dump_leaf_key, this, left_root_right);
+    else if (distinct) // distinct (and no order by).
+      unique_filter->walk(table, &dump_leaf_key, this);
+    else
+      DBUG_ASSERT(false); // Can't happen
+  }
   return &result;
 }
 
diff --git a/sql/item_sum.h b/sql/item_sum.h
index dcc3e494f82..7aa9dd98bd5 100644
--- a/sql/item_sum.h
+++ b/sql/item_sum.h
@@ -1417,7 +1417,8 @@ class Item_func_group_concat : public Item_sum
   bool warning_for_row;
   bool always_null;
   bool force_copy_fields;
-  bool no_appended;
+  /** True if result has been written to output buffer. */
+  bool m_result_finalized;
   /*
     Following is 0 normal object and pointer to original one for copy
     (to correctly free resources)


More information about the commits mailing list