If a subquery returns any rows at all, EXISTS
is
subquery
TRUE
, and NOT EXISTS
is
subquery
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
Last example (using double negation) can be interpreted as follows:
Store 'si' is in all cities if and only if for this store we can not find a city cj such that 'si' does not exist.
so the second select statement SELECT * FROM cities WHERE NOT EXISTS is applied to detemine that.
best
EXISTS function provides a simple way to find intersection between tables (INTERSECT operator from relational model).
If we have table1 and table2, both having id and value columns, the intersection could be calculated like this:
SELECT * FROM table1 WHERE EXISTS(SELECT * FROM table2 WHERE table1.id=table2.id AND table1.value=table2.value)
EXISTS is supported from 4.1 on. Earlier versions of MySQL can try rewriting the query using a LEFT JOIN.
I'm coming from an MS SQL background (not my fault, honest) and would like to add that 'exists' does not operate as I expected it to in interactive mode.
I expect to be able to do something like:
if exists(select 1 from users where username=@username) then
do something;
end if;
but in interactive mode, this produces a syntax error. Oddly enough, though, this does work in a stored procedure.
Well...
You'll must build your own "IF EXISTS(..." with a set
of SQL statments.
It´s a challenge!
Cheers.
NOT EXISTS will always return false if table is empty.
For example:
CREATE TABLE states
(
state_id int auto_increment not null,
state_code char(2) not null,
state_name varchar(100) not null,
UNIQUE(state_code),
PRIMARY KEY(state_id)
);
mysql> select 100 from states where not exists (select 1 from states where state_id=1);
Empty set (0.00 sec)
I also come from an MSSQL background (also not my fault as I like to work), and found that this works in place of "IF EXISTS() THEN":
DECLARE v_user INTEGER DEFAULT (SELECT `user` FROM user_privacy WHERE `user` = p_user);
IF v_user IS NOT NULL THEN
-- do whatever
END IF;
I won't speak to the efficiency of that, but there it is. (I wouldn't store VARCHARs or TEXTs, etc. that way, for no reason).
It can also be written with the SELECT inline with the IF statement:
IF (SELECT `user` FROM user_privacy WHERE `user` = p_user) IS NOT NULL THEN
-- do whatever
END IF;
.. but I'm in the habit of sticking things like that into vars for re-use in longer SPs.
Add your own comment.