Skip to content

Commit 0c0a891

Browse files
author
Sreeharsha Ramanavarapu
committed
Bug #22655856: COLUMN NAME IN HAVING, WHICH IS CONTAINED
IN SELECT LIST '*', PRODUCES ERROR ISSUE: ------ The query EXISTS(SELECT *...) is transformed to EXISTS(SELECT 1 ...) before all the columns in the inner subquery have been resolved. Since mysql allows HAVING without GROUP BY, the columns in the HAVING clause will need to resolve to the SELECT list. Replacing * with 1 effectively eliminates this possibility. SOLUTION: --------- The transformation of EXISTS(SELECT *...) to EXISTS(SELECT 1 ...) will not applied if there is a HAVING clause in the inner subquery.
1 parent 73fe801 commit 0c0a891

File tree

3 files changed

+48
-2
lines changed

3 files changed

+48
-2
lines changed

mysql-test/r/having.result

Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -866,3 +866,23 @@ GROUP BY pk
866866
);
867867
ERROR 21000: Subquery returns more than 1 row
868868
DROP TABLE t1, t2;
869+
#
870+
# Bug #22655856: COLUMN NAME IN HAVING, WHICH IS CONTAINED IN SELECT
871+
# LIST '*', PRODUCES ERROR
872+
#
873+
CREATE TABLE t1(c1 INT) ENGINE=INNODB;
874+
CREATE TABLE t2(c2 INT) ENGINE=INNODB;
875+
EXPLAIN SELECT c1 FROM t1 WHERE EXISTS(SELECT * FROM t2 HAVING c2>0);
876+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
877+
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
878+
2 SUBQUERY t2 NULL ALL NULL NULL NULL NULL 1 100.00 NULL
879+
Warnings:
880+
Note 1003 /* select#1 */ select `test`.`t1`.`c1` AS `c1` from `test`.`t1` where 0
881+
SELECT c1 FROM t1 WHERE EXISTS(SELECT * FROM t2 HAVING c2>0);
882+
c1
883+
INSERT INTO t1 VALUES(1);
884+
INSERT INTO t2 VALUES(2);
885+
SELECT c1 FROM t1 WHERE EXISTS(SELECT * FROM t2 HAVING c2>0);
886+
c1
887+
1
888+
DROP TABLE t1, t2;

mysql-test/t/having.test

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -882,3 +882,21 @@ HAVING (2, 7) NOT IN
882882
);
883883

884884
DROP TABLE t1, t2;
885+
886+
--echo #
887+
--echo # Bug #22655856: COLUMN NAME IN HAVING, WHICH IS CONTAINED IN SELECT
888+
--echo # LIST '*', PRODUCES ERROR
889+
--echo #
890+
891+
CREATE TABLE t1(c1 INT) ENGINE=INNODB;
892+
CREATE TABLE t2(c2 INT) ENGINE=INNODB;
893+
894+
EXPLAIN SELECT c1 FROM t1 WHERE EXISTS(SELECT * FROM t2 HAVING c2>0);
895+
SELECT c1 FROM t1 WHERE EXISTS(SELECT * FROM t2 HAVING c2>0);
896+
897+
INSERT INTO t1 VALUES(1);
898+
INSERT INTO t2 VALUES(2);
899+
900+
SELECT c1 FROM t1 WHERE EXISTS(SELECT * FROM t2 HAVING c2>0);
901+
902+
DROP TABLE t1, t2;

sql/sql_resolver.cc

Lines changed: 10 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
/* Copyright (c) 2000, 2015, Oracle and/or its affiliates. All rights reserved.
1+
/* Copyright (c) 2000, 2016, Oracle and/or its affiliates. All rights reserved.
22
33
This program is free software; you can redistribute it and/or modify
44
it under the terms of the GNU General Public License as published by
@@ -1102,7 +1102,15 @@ bool SELECT_LEX::setup_wild(THD *thd)
11021102
const uint elem= fields_list.elements;
11031103
const bool any_privileges= item_field->any_privileges;
11041104
Item_subselect *subsel= master_unit()->item;
1105-
if (subsel && subsel->substype() == Item_subselect::EXISTS_SUBS)
1105+
1106+
/*
1107+
In case of EXISTS(SELECT * ... HAVING ...), don't use this
1108+
transformation. The columns in HAVING will need to resolve to the
1109+
select list. Replacing * with 1 effectively eliminates this
1110+
possibility.
1111+
*/
1112+
if (subsel && subsel->substype() == Item_subselect::EXISTS_SUBS &&
1113+
!having_cond())
11061114
{
11071115
/*
11081116
It is EXISTS(SELECT * ...) and we can replace * by any constant.

0 commit comments

Comments
 (0)