olap.result, olap.test:
Added test cases for bug #7894. sql_select.cc: Fixed bug #7894: GROUP BY queries with ROLLUP returned wrong results for expressions containing group by columns. The fix ensured correct results by replacement of all occurrences of group by fields in non-aggregate expressions for corresponding ref objects and preventing creation of fields in temporary tables for expression containing group by fields. sql/sql_select.cc: Fixed bug #7894: GROUP BY queries with ROLLUP returned wrong results for expressions containing group by columns. The fix ensured correct results by replacement of all occurrences of group by fields in non-aggregate expressions for corresponding ref objects and preventing creation of fields in temporary tables for expression containing group by fields. mysql-test/t/olap.test: Added test cases for bug #7894. mysql-test/r/olap.result: Added test cases for bug #7894.
This commit is contained in:
parent
755d2018ad
commit
5a54820003
@ -248,7 +248,7 @@ concat(':',product,':') sum(profit) avg(profit)
|
||||
:Computer: 6900 1380.0000
|
||||
:Phone: 10 10.0000
|
||||
:TV: 600 120.0000
|
||||
:TV: 7785 519.0000
|
||||
NULL 7785 519.0000
|
||||
select product, country_id , year, sum(profit) from t1 group by product, country_id, year with cube;
|
||||
ERROR 42000: This version of MySQL doesn't yet support 'CUBE'
|
||||
explain select product, country_id , year, sum(profit) from t1 group by product, country_id, year with cube;
|
||||
@ -438,3 +438,69 @@ a SUM(a) SUM(a)+1 CONCAT(SUM(a),'x') SUM(a)+SUM(a) SUM(a)
|
||||
5 5 6 5x 10 5
|
||||
NULL 8 9 8x 16 8
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (a int(11));
|
||||
INSERT INTO t1 VALUES (1),(2);
|
||||
SELECT a, a+1, SUM(a) FROM t1 GROUP BY a WITH ROLLUP;
|
||||
a a+1 SUM(a)
|
||||
1 2 1
|
||||
2 3 2
|
||||
NULL NULL 3
|
||||
SELECT a+1 FROM t1 GROUP BY a WITH ROLLUP;
|
||||
a+1
|
||||
2
|
||||
3
|
||||
NULL
|
||||
SELECT a+SUM(a) FROM t1 GROUP BY a WITH ROLLUP;
|
||||
a+SUM(a)
|
||||
2
|
||||
4
|
||||
NULL
|
||||
SELECT a, a+1 as b FROM t1 GROUP BY a WITH ROLLUP HAVING b > 2;
|
||||
a b
|
||||
2 3
|
||||
SELECT a, a+1 as b FROM t1 GROUP BY a WITH ROLLUP HAVING a IS NULL;
|
||||
a b
|
||||
NULL NULL
|
||||
SELECT a, a+1 as b FROM t1 GROUP BY a WITH ROLLUP HAVING b IS NULL;
|
||||
a b
|
||||
NULL NULL
|
||||
SELECT IFNULL(a, 'TEST') FROM t1 GROUP BY a WITH ROLLUP;
|
||||
IFNULL(a, 'TEST')
|
||||
1
|
||||
2
|
||||
TEST
|
||||
CREATE TABLE t2 (a int, b int);
|
||||
INSERT INTO t2 VALUES
|
||||
(1,4),
|
||||
(2,2), (2,2),
|
||||
(4,1), (4,1), (4,1), (4,1),
|
||||
(2,1), (2,1);
|
||||
SELECT a,b,SUM(b) FROM t2 GROUP BY a,b WITH ROLLUP;
|
||||
a b SUM(b)
|
||||
1 4 4
|
||||
1 NULL 4
|
||||
2 1 2
|
||||
2 2 4
|
||||
2 NULL 6
|
||||
4 1 4
|
||||
4 NULL 4
|
||||
NULL NULL 14
|
||||
SELECT a,b,SUM(b), a+b as c FROM t2
|
||||
GROUP BY a,b WITH ROLLUP HAVING c IS NULL;
|
||||
a b SUM(b) c
|
||||
1 NULL 4 NULL
|
||||
2 NULL 6 NULL
|
||||
4 NULL 4 NULL
|
||||
NULL NULL 14 NULL
|
||||
SELECT IFNULL(a, 'TEST'), COALESCE(b, 'TEST') FROM t2
|
||||
GROUP BY a, b WITH ROLLUP;
|
||||
IFNULL(a, 'TEST') COALESCE(b, 'TEST')
|
||||
1 4
|
||||
1 TEST
|
||||
2 1
|
||||
2 2
|
||||
2 TEST
|
||||
4 1
|
||||
4 TEST
|
||||
TEST TEST
|
||||
DROP TABLE t1,t2;
|
||||
|
@ -208,3 +208,33 @@ SELECT a, SUM(a), SUM(a)+1, CONCAT(SUM(a),'x'), SUM(a)+SUM(a), SUM(a)
|
||||
|
||||
DROP TABLE t1;
|
||||
|
||||
#
|
||||
# Tests for bug #7894: ROLLUP over expressions on group by attributes
|
||||
#
|
||||
|
||||
CREATE TABLE t1 (a int(11));
|
||||
INSERT INTO t1 VALUES (1),(2);
|
||||
|
||||
SELECT a, a+1, SUM(a) FROM t1 GROUP BY a WITH ROLLUP;
|
||||
SELECT a+1 FROM t1 GROUP BY a WITH ROLLUP;
|
||||
SELECT a+SUM(a) FROM t1 GROUP BY a WITH ROLLUP;
|
||||
SELECT a, a+1 as b FROM t1 GROUP BY a WITH ROLLUP HAVING b > 2;
|
||||
SELECT a, a+1 as b FROM t1 GROUP BY a WITH ROLLUP HAVING a IS NULL;
|
||||
SELECT a, a+1 as b FROM t1 GROUP BY a WITH ROLLUP HAVING b IS NULL;
|
||||
SELECT IFNULL(a, 'TEST') FROM t1 GROUP BY a WITH ROLLUP;
|
||||
|
||||
CREATE TABLE t2 (a int, b int);
|
||||
INSERT INTO t2 VALUES
|
||||
(1,4),
|
||||
(2,2), (2,2),
|
||||
(4,1), (4,1), (4,1), (4,1),
|
||||
(2,1), (2,1);
|
||||
|
||||
SELECT a,b,SUM(b) FROM t2 GROUP BY a,b WITH ROLLUP;
|
||||
SELECT a,b,SUM(b), a+b as c FROM t2
|
||||
GROUP BY a,b WITH ROLLUP HAVING c IS NULL;
|
||||
SELECT IFNULL(a, 'TEST'), COALESCE(b, 'TEST') FROM t2
|
||||
GROUP BY a, b WITH ROLLUP;
|
||||
|
||||
DROP TABLE t1,t2;
|
||||
|
||||
|
@ -9164,6 +9164,79 @@ void free_underlaid_joins(THD *thd, SELECT_LEX *select)
|
||||
ROLLUP handling
|
||||
****************************************************************************/
|
||||
|
||||
/*
|
||||
Replace occurences of group by fields in an expression by ref items
|
||||
|
||||
SYNOPSIS
|
||||
change_group_ref()
|
||||
thd reference to the context
|
||||
expr expression to make replacement
|
||||
group_list list of references to group by items
|
||||
changed out: returns 1 if item contains a replaced field item
|
||||
|
||||
DESCRIPTION
|
||||
The function replaces occurrences of group by fields in expr
|
||||
by ref objects for these fields unless they are under aggregate
|
||||
functions.
|
||||
|
||||
IMPLEMENTATION
|
||||
The function recursively traverses the tree of the expr expression,
|
||||
looks for occurrences of the group by fields that are not under
|
||||
aggregate functions and replaces them for the corresponding ref items.
|
||||
|
||||
NOTES
|
||||
This substitution is needed GROUP BY queries with ROLLUP if
|
||||
SELECT list contains expressions over group by attributes.
|
||||
|
||||
EXAMPLES
|
||||
SELECT a+1 FROM t1 GROUP BY a WITH ROLLUP
|
||||
SELECT SUM(a)+a FROM t1 GROUP BY a WITH ROLLUP
|
||||
|
||||
RETURN
|
||||
0 if ok
|
||||
1 on error
|
||||
*/
|
||||
|
||||
static bool change_group_ref(THD *thd, Item *expr, ORDER *group_list,
|
||||
bool *changed)
|
||||
{
|
||||
if (expr->type() != Item::FUNC_ITEM)
|
||||
return 0;
|
||||
Item_func *func_item= (Item_func *) expr;
|
||||
if (func_item->arg_count)
|
||||
{
|
||||
Item **arg,**arg_end;
|
||||
for (arg= func_item->arguments(),
|
||||
arg_end= func_item->arguments()+func_item->arg_count;
|
||||
arg != arg_end; arg++)
|
||||
{
|
||||
Item *item= *arg;
|
||||
if (item->type() == Item::FIELD_ITEM || item->type() == Item::REF_ITEM)
|
||||
{
|
||||
ORDER *group_tmp;
|
||||
for (group_tmp= group_list; group_tmp; group_tmp= group_tmp->next)
|
||||
{
|
||||
if (item->eq(*group_tmp->item,0))
|
||||
{
|
||||
Item *new_item;
|
||||
if(!(new_item= new Item_ref(group_tmp->item, 0, item->name)))
|
||||
return 1; // fatal_error is set
|
||||
thd->change_item_tree(arg, new_item);
|
||||
*changed= TRUE;
|
||||
}
|
||||
}
|
||||
}
|
||||
else if (item->type() == Item::FUNC_ITEM)
|
||||
{
|
||||
if (change_group_ref(thd, item, group_list, changed))
|
||||
return 1;
|
||||
}
|
||||
}
|
||||
}
|
||||
return 0;
|
||||
}
|
||||
|
||||
|
||||
/* Allocate memory needed for other rollup functions */
|
||||
|
||||
bool JOIN::rollup_init()
|
||||
@ -9208,19 +9281,31 @@ bool JOIN::rollup_init()
|
||||
for (j=0 ; j < fields_list.elements ; j++)
|
||||
rollup.fields[i].push_back(rollup.null_items[i]);
|
||||
}
|
||||
List_iterator_fast<Item> it(fields_list);
|
||||
List_iterator_fast<Item> it(all_fields);
|
||||
Item *item;
|
||||
while ((item= it++))
|
||||
{
|
||||
ORDER *group_tmp;
|
||||
for (group_tmp= group_list; group_tmp; group_tmp= group_tmp->next)
|
||||
{
|
||||
if (*group_tmp->item == item)
|
||||
if (item->eq(*group_tmp->item,0))
|
||||
item->maybe_null= 1;
|
||||
}
|
||||
if (item->type() == Item::FUNC_ITEM)
|
||||
{
|
||||
bool changed= 0;
|
||||
if (change_group_ref(thd, item, group_list, &changed))
|
||||
return 1;
|
||||
/*
|
||||
We have to prevent creation of a field in a temporary table for
|
||||
an expression that contains GROUP BY attributes.
|
||||
Marking the expression item as 'with_sum_func' will ensure this.
|
||||
*/
|
||||
if (changed)
|
||||
item->with_sum_func= 1;
|
||||
}
|
||||
}
|
||||
return 0;
|
||||
|
||||
}
|
||||
|
||||
|
||||
@ -9318,14 +9403,14 @@ bool JOIN::rollup_make_fields(List<Item> &fields_arg, List<Item> &sel_fields,
|
||||
*(*func)= (Item_sum*) item;
|
||||
(*func)++;
|
||||
}
|
||||
else if (real_fields)
|
||||
else
|
||||
{
|
||||
/* Check if this is something that is part of this group by */
|
||||
ORDER *group_tmp;
|
||||
for (group_tmp= start_group, i= pos ;
|
||||
group_tmp ; group_tmp= group_tmp->next, i++)
|
||||
{
|
||||
if (*group_tmp->item == item)
|
||||
if (item->eq(*group_tmp->item,0))
|
||||
{
|
||||
/*
|
||||
This is an element that is used by the GROUP BY and should be
|
||||
|
Loading…
x
Reference in New Issue
Block a user