Subquery expressions v16

SQL-compliant subquery expressions are available in EDB Postgres Advanced Server. All of these expression forms return Boolean (TRUE/FALSE) results.

EXISTS

The argument of EXISTS is an arbitrary SELECT statement or subquery. The subquery is evaluated to determine whether it returns any rows. If it returns at least one row, the result of EXISTS is TRUE. If the subquery returns no rows, the result of EXISTS is FALSE.

EXISTS(subquery)

The subquery can refer to variables from the surrounding query that act as constants during any one evaluation of the subquery.

The subquery is generally executed only far enough to determine whether at least one row is returned, not all the way to completion. We recommend that you don't write a subquery that has any side effects (such as calling sequence functions). Whether the side effects occur might be difficult to predict.

Since the result depends only on whether any rows are returned and not on the contents of those rows, the output list of the subquery is normally uninteresting. A common coding convention is to write all EXISTS tests in the form EXISTS(SELECT 1 WHERE ...). There are exceptions to this rule, however, such as subqueries that use INTERSECT.

This simple example is like an inner join on deptno, but it produces at most one output row for each dept row, even though there are multiple matching emp rows:

SELECT dname FROM dept WHERE EXISTS (SELECT 1 FROM emp WHERE emp.deptno =
dept.deptno);
Output
   dname
------------
 ACCOUNTING
 RESEARCH
 SALES
(3 rows)

IN

The right-hand side is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result. The result of IN is TRUE if any equal subquery row is found. The result is FALSE if no equal row is found (including the special case where the subquery returns no rows).

expression IN (subquery)

If the left-hand expression yields NULL, or if there are no equal right-hand values and at least one right-hand row yields NULL, the result of the IN construct is NULL, not FALSE. This is in accordance with SQL’s normal rules for Boolean combinations of null values.

As with EXISTS, you can't assume that the subquery will evaluate completely.

NOT IN

The right-hand side is a parenthesized subquery that must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result. The result of NOT IN is TRUE if only unequal subquery rows are found (including the special case where the subquery returns no rows). The result is FALSE if any equal row is found.

expression NOT IN (subquery)

If the left-hand expression yields NULL, or if there are no equal right-hand values and at least one right-hand row yields NULL, the result of the NOT IN construct is NULL, not TRUE. This is in accordance with SQL’s normal rules for Boolean combinations of null values.

As with EXISTS, you can't assume that the subquery will evaluate completely.

ANY/SOME

The right-hand side is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result using the given operator, which must yield a Boolean result. The result of ANY is TRUE if any true result is obtained. The result is FALSE if no true result is found (including the special case where the subquery returns no rows).

expression operator ANY (subquery)
expression operator SOME (subquery)

SOME is a synonym for ANY. IN is equivalent to = ANY.

If there are no successes and at least one right-hand row yields NULL for the operator’s result, the result of the ANY construct is NULL, not FALSE. This is in accordance with SQL’s normal rules for Boolean combinations of null values.

As with EXISTS, you can't assume that the subquery will evaluate completely.

ALL

The right-hand side is a parenthesized subquery, which must return exactly one column. The left-hand expression is evaluated and compared to each row of the subquery result using the given operator, which must yield a Boolean result. The result of ALL is TRUE if all rows yield true (including the special case where the subquery returns no rows). The result is FALSE if any false result is found. The result is NULL if the comparison doesn't return FALSE for any row and it returns NULL for at least one row.

expression operator ALL (subquery)

NOT IN is equivalent to <> ALL. As with EXISTS, you can't assume that the subquery will evaluate completely.