Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 39.3Mb
PDF (A4) - 39.3Mb
PDF (RPM) - 38.6Mb
HTML Download (TGZ) - 11.1Mb
HTML Download (Zip) - 11.1Mb
HTML Download (RPM) - 9.8Mb
Man Pages (TGZ) - 212.5Kb
Man Pages (Zip) - 321.6Kb
Info (Gzip) - 3.6Mb
Info (Zip) - 3.6Mb
Excerpts from this Manual

MySQL 5.7 Reference Manual  /  ...  /  Subqueries with EXISTS or NOT EXISTS

13.2.10.6 Subqueries with EXISTS or NOT EXISTS

If a subquery returns any rows at all, EXISTS subquery is TRUE, and NOT EXISTS subquery is FALSE. For example:

SELECT column1 FROM t1 WHERE EXISTS (SELECT * FROM t2);

Traditionally, an EXISTS subquery starts with SELECT *, but it could begin with SELECT 5 or SELECT column1 or anything at all. MySQL ignores the SELECT list in such a subquery, so it makes no difference.

For the preceding example, if t2 contains any rows, even rows with nothing but NULL values, the EXISTS condition is TRUE. This is actually an unlikely example because a [NOT] EXISTS subquery almost always contains correlations. Here are some more realistic examples:

  • What kind of store is present in one or more cities?

    SELECT DISTINCT store_type FROM stores
      WHERE EXISTS (SELECT * FROM cities_stores
                    WHERE cities_stores.store_type = stores.store_type);
  • What kind of store is present in no cities?

    SELECT DISTINCT store_type FROM stores
      WHERE NOT EXISTS (SELECT * FROM cities_stores
                        WHERE cities_stores.store_type = stores.store_type);
  • What kind of store is present in all cities?

    SELECT DISTINCT store_type FROM stores s1
      WHERE NOT EXISTS (
        SELECT * FROM cities WHERE NOT EXISTS (
          SELECT * FROM cities_stores
           WHERE cities_stores.city = cities.city
           AND cities_stores.store_type = stores.store_type));

The last example is a double-nested NOT EXISTS query. That is, it has a NOT EXISTS clause within a NOT EXISTS clause. Formally, it answers the question does a city exist with a store that is not in Stores? But it is easier to say that a nested NOT EXISTS answers the question is x TRUE for all y?


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
  Posted by mojgan kavehei on March 10, 2014
Hi,
I wonder if anyone tested the last example "What kind of store is present in all cities?"
it did not work for me, but instead i used this query in below ..

select count(stype), stype , city from cities_stores S group by S.stype having count(stype) = ( select count(distinct D.city) from cities_stores D )

any thought?

Thanks,
  Posted by sunghun kim on June 27, 2017
Do not use "exists subquery" with "loose index scan" in different column.
Because you do not have access to the entire index, there may be problems when "exists subquery" is performed based on another column than "group by".

example)
CREATE TABLE `g1` (
`seq` int(11) NOT NULL,
`key1` bigint(20) DEFAULT NULL,
PRIMARY KEY (`seq`),
KEY `idx1` (`key1`)
);
CREATE TABLE `g2` (
`seq` int(11) NOT NULL,
`key2` bigint(20) DEFAULT NULL,
PRIMARY KEY (`seq`),
KEY `idx1` (`key2`)
);

mysql> select * from g1;
+-----+------+
| seq | key1 |
+-----+------+
| 1 | 10 |
| 2 | 20 |
| 3 | 30 |
| 4 | 30 |
... (There are enough rows to do a "loose index scan")

mysql> select * from g2;
+-----+
| seq |
+-----+
| 1 |
| 2 |
| 3 |
| 4 |
+-----+

mysql> select key1 from g1 where exists (select 1 from g2 where g1.seq=g2.seq) group by g1.key1;
+------+
| key1 |
+------+
| 10 |
| 20 |
| 30 |
+------+

mysql> delete from g2 where seq = 3;
mysql> select key1 from g1 where exists (select 1 from g2 where g1.seq=g2.seq) group by g1.key1;
+------+
| key1 |
+------+
| 10 |
| 20 |
+------+

When using "loose index scan", only the seq = 3 which is located first among the items with key1 = 30. Therefore, even if seq = 4 exists in "exists subquery", it returns there is no item with key1 of 30.
+------+-----+
| key1 | seq |
+------+-----+
| 10 | 1 |
| 20 | 2 |
| 30 | 3 |
| 30 | 4 |
...
Sign Up Login You must be logged in to post a comment.