mirror of
https://github.com/MariaDB/server.git
synced 2025-01-16 03:52:35 +01:00
Bug#48920: COUNT DISTINCT returns 1 for NULL values when in a
subquery in the select list When a dependent subquery with count(distinct <col>) was evaluated multiple times, the Distinct_Aggregator was reused. However, the Aggregator was not reset, so when the subquery was evaluated for the next record in the outer select, old dependent info was used. The fix is to clear() the existing aggregator in Item_sum::set_aggregator(). This ensures that the aggregator is reevaluated with the new dependent information. mysql-test/r/subselect3.result: Added test case for BUG#48920 mysql-test/t/subselect3.test: Added test case for BUG#48920 sql/item_sum.cc: If an aggregator exists when Item_sum::set_aggregator() is called (i.e., set_aggregator is called in a dependent subquery), the aggregator is reset so that the aggregator is reevaluated with the dependent information from the outer record being evaluated.
This commit is contained in:
parent
1445cdaec8
commit
305f2e7f8a
3 changed files with 104 additions and 0 deletions
|
@ -964,3 +964,53 @@ Variable_name Value
|
|||
Handler_read_rnd_next 18
|
||||
DROP TABLE t1,t2;
|
||||
End of 5.1 tests
|
||||
#
|
||||
# BUG#48920: COUNT DISTINCT returns 1 for NULL values when in a subquery
|
||||
# in the select list
|
||||
#
|
||||
|
||||
CREATE TABLE t1 (
|
||||
i int(11) DEFAULT NULL,
|
||||
v varchar(1) DEFAULT NULL
|
||||
);
|
||||
|
||||
INSERT INTO t1 VALUES (8,'v');
|
||||
INSERT INTO t1 VALUES (9,'r');
|
||||
INSERT INTO t1 VALUES (NULL,'y');
|
||||
|
||||
CREATE TABLE t2 (
|
||||
i int(11) DEFAULT NULL,
|
||||
v varchar(1) DEFAULT NULL,
|
||||
KEY i_key (i)
|
||||
);
|
||||
|
||||
INSERT INTO t2 VALUES (NULL,'r');
|
||||
INSERT INTO t2 VALUES (0,'c');
|
||||
INSERT INTO t2 VALUES (0,'o');
|
||||
INSERT INTO t2 VALUES (2,'v');
|
||||
INSERT INTO t2 VALUES (7,'c');
|
||||
|
||||
SELECT i, v, (SELECT COUNT(DISTINCT i)
|
||||
FROM t1
|
||||
WHERE v = t2.v) as subsel
|
||||
FROM t2;
|
||||
i v subsel
|
||||
NULL r 1
|
||||
0 c 0
|
||||
0 o 0
|
||||
2 v 1
|
||||
7 c 0
|
||||
|
||||
EXPLAIN EXTENDED
|
||||
SELECT i, v, (SELECT COUNT(DISTINCT i)
|
||||
FROM t1
|
||||
WHERE v = t2.v) as subsel
|
||||
FROM t2;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 PRIMARY t2 ALL NULL NULL NULL NULL 5 100.00
|
||||
2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 3 100.00 Using where
|
||||
Warnings:
|
||||
Note 1276 Field or reference 'test.t2.v' of SELECT #2 was resolved in SELECT #1
|
||||
Note 1003 select `test`.`t2`.`i` AS `i`,`test`.`t2`.`v` AS `v`,(select count(distinct `test`.`t1`.`i`) AS `COUNT(DISTINCT i)` from `test`.`t1` where (`test`.`t1`.`v` = `test`.`t2`.`v`)) AS `subsel` from `test`.`t2`
|
||||
DROP TABLE t1,t2;
|
||||
End of 5.6 tests
|
||||
|
|
|
@ -794,3 +794,50 @@ SHOW STATUS LIKE '%Handler_read_rnd_next';
|
|||
DROP TABLE t1,t2;
|
||||
|
||||
--echo End of 5.1 tests
|
||||
|
||||
--echo #
|
||||
--echo # BUG#48920: COUNT DISTINCT returns 1 for NULL values when in a subquery
|
||||
--echo # in the select list
|
||||
--echo #
|
||||
|
||||
--echo
|
||||
CREATE TABLE t1 (
|
||||
i int(11) DEFAULT NULL,
|
||||
v varchar(1) DEFAULT NULL
|
||||
);
|
||||
|
||||
--echo
|
||||
INSERT INTO t1 VALUES (8,'v');
|
||||
INSERT INTO t1 VALUES (9,'r');
|
||||
INSERT INTO t1 VALUES (NULL,'y');
|
||||
|
||||
--echo
|
||||
CREATE TABLE t2 (
|
||||
i int(11) DEFAULT NULL,
|
||||
v varchar(1) DEFAULT NULL,
|
||||
KEY i_key (i)
|
||||
);
|
||||
|
||||
--echo
|
||||
INSERT INTO t2 VALUES (NULL,'r');
|
||||
INSERT INTO t2 VALUES (0,'c');
|
||||
INSERT INTO t2 VALUES (0,'o');
|
||||
INSERT INTO t2 VALUES (2,'v');
|
||||
INSERT INTO t2 VALUES (7,'c');
|
||||
|
||||
--echo
|
||||
SELECT i, v, (SELECT COUNT(DISTINCT i)
|
||||
FROM t1
|
||||
WHERE v = t2.v) as subsel
|
||||
FROM t2;
|
||||
|
||||
--echo
|
||||
EXPLAIN EXTENDED
|
||||
SELECT i, v, (SELECT COUNT(DISTINCT i)
|
||||
FROM t1
|
||||
WHERE v = t2.v) as subsel
|
||||
FROM t2;
|
||||
|
||||
DROP TABLE t1,t2;
|
||||
|
||||
--echo End of 5.6 tests
|
||||
|
|
|
@ -578,7 +578,14 @@ int Item_sum::set_aggregator(Aggregator::Aggregator_type aggregator)
|
|||
{
|
||||
if (aggr)
|
||||
{
|
||||
/*
|
||||
Dependent subselects may be executed multiple times, making
|
||||
set_aggregator to be called multiple times. The aggregator type
|
||||
will be the same, but it needs to be reset so that it is
|
||||
reevaluated with the new dependent data.
|
||||
*/
|
||||
DBUG_ASSERT(aggregator == aggr->Aggrtype());
|
||||
aggr->clear();
|
||||
return FALSE;
|
||||
}
|
||||
switch (aggregator)
|
||||
|
|
Loading…
Reference in a new issue