diff --git a/mysql-test/r/subselect3.result b/mysql-test/r/subselect3.result index 3a0576768b2..a51cef6833d 100644 --- a/mysql-test/r/subselect3.result +++ b/mysql-test/r/subselect3.result @@ -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 diff --git a/mysql-test/t/subselect3.test b/mysql-test/t/subselect3.test index fab0a462157..39c97941031 100644 --- a/mysql-test/t/subselect3.test +++ b/mysql-test/t/subselect3.test @@ -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 diff --git a/sql/item_sum.cc b/sql/item_sum.cc index c33088e0276..a61c5d59d67 100644 --- a/sql/item_sum.cc +++ b/sql/item_sum.cc @@ -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)