9.22. 子查詢

This section describes theSQL-compliant subquery expressions available inPostgreSQL. All of the expression forms documented in this section return Boolean (true/false) results.

9.22.1. EXISTS

EXISTS (
subquery
)

The argument ofEXISTSis an arbitrarySELECTstatement, orsubquery. The subquery is evaluated to determine whether it returns any rows. If it returns at least one row, the result ofEXISTSis“true”; if the subquery returns no rows, the result ofEXISTSis“false”.

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

The subquery will generally only be executed long enough to determine whether at least one row is returned, not all the way to completion. It is unwise to write a subquery that has side effects (such as calling sequence functions); whether the side effects occur might be unpredictable.

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 unimportant. A common coding convention is to write allEXISTStests in the formEXISTS(SELECT 1 WHERE ...). There are exceptions to this rule however, such as subqueries that useINTERSECT.

This simple example is like an inner join oncol2, but it produces at most one output row for eachtab1row, even if there are several matchingtab2rows:

SELECT col1
FROM tab1
WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);

9.22.2. IN

expression
 IN (
subquery
)

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 ofINis“true”if any equal subquery row is found. The result is“false”if no equal row is found (including the case where the subquery returns no rows).

Note that 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 theINconstruct will be null, not false. This is in accordance with SQL's normal rules for Boolean combinations of null values.

As withEXISTS, it's unwise to assume that the subquery will be evaluated completely.

row_constructor
 IN (
subquery
)

The left-hand side of this form ofINis a row constructor, as described inSection 4.2.13. The right-hand side is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand row. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result. The result ofINis“true”if any equal subquery row is found. The result is“false”if no equal row is found (including the case where the subquery returns no rows).

As usual, null values in the rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of that row comparison is unknown (null). If all the per-row results are either unequal or null, with at least one null, then the result ofINis null.

9.22.3. NOT IN

expression
 NOT IN (
subquery
)

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 ofNOT INis“true”if only unequal subquery rows are found (including the case where the subquery returns no rows). The result is“false”if any equal row is found.

Note that 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 theNOT INconstruct will be null, not true. This is in accordance with SQL's normal rules for Boolean combinations of null values.

As withEXISTS, it's unwise to assume that the subquery will be evaluated completely.

row_constructor
 NOT IN (
subquery
)

The left-hand side of this form ofNOT INis a row constructor, as described inSection 4.2.13. The right-hand side is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand row. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result. The result ofNOT INis“true”if only unequal subquery rows are found (including the case where the subquery returns no rows). The result is“false”if any equal row is found.

As usual, null values in the rows are combined per the normal rules of SQL Boolean expressions. Two rows are considered equal if all their corresponding members are non-null and equal; the rows are unequal if any corresponding members are non-null and unequal; otherwise the result of that row comparison is unknown (null). If all the per-row results are either unequal or null, with at least one null, then the result ofNOT INis null.

9.22.4. ANY/SOME

expression
operator
 ANY (
subquery
)

expression
operator
 SOME (
subquery
)

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 givenoperator, which must yield a Boolean result. The result ofANYis“true”if any true result is obtained. The result is“false”if no true result is found (including the case where the subquery returns no rows).

SOMEis a synonym forANY.INis equivalent to= ANY.

Note that if there are no successes and at least one right-hand row yields null for the operator's result, the result of theANYconstruct will be null, not false. This is in accordance with SQL's normal rules for Boolean combinations of null values.

As withEXISTS, it's unwise to assume that the subquery will be evaluated completely.

row_constructor
operator
 ANY (
subquery
)

row_constructor
operator
 SOME (
subquery
)

The left-hand side of this form ofANYis a row constructor, as described inSection 4.2.13. The right-hand side is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand row. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result, using the givenoperator. The result ofANYis“true”if the comparison returns true for any subquery row. The result is“false”if the comparison returns false for every subquery row (including the case where the subquery returns no rows). The result is NULL if the comparison does not return true for any row, and it returns NULL for at least one row.

SeeSection 9.23.5for details about the meaning of a row constructor comparison.

9.22.5. ALL

expression
operator
 ALL (
subquery
)

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 givenoperator, which must yield a Boolean result. The result ofALLis“true”if all rows yield true (including the case where the subquery returns no rows). The result is“false”if any false result is found. The result is NULL if the comparison does not return false for any row, and it returns NULL for at least one row.

NOT INis equivalent to<> ALL.

As withEXISTS, it's unwise to assume that the subquery will be evaluated completely.

row_constructor
operator
 ALL (
subquery
)

The left-hand side of this form ofALLis a row constructor, as described inSection 4.2.13. The right-hand side is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand row. The left-hand expressions are evaluated and compared row-wise to each row of the subquery result, using the givenoperator. The result ofALLis“true”if the comparison returns true for all subquery rows (including the case where the subquery returns no rows). The result is“false”if the comparison returns false for any subquery row. The result is NULL if the comparison does not return false for any subquery row, and it returns NULL for at least one row.

SeeSection 9.23.5for details about the meaning of a row constructor comparison.

9.22.6. Single-row Comparison

row_constructor
operator
 (
subquery
)

The left-hand side is a row constructor, as described inSection 4.2.13. The right-hand side is a parenthesized subquery, which must return exactly as many columns as there are expressions in the left-hand row. Furthermore, the subquery cannot return more than one row. (If it returns zero rows, the result is taken to be null.) The left-hand side is evaluated and compared row-wise to the single subquery result row.

SeeSection 9.23.5for details about the meaning of a row constructor comparison.

Last updated