Updated on 2025-10-23 GMT+08:00

Subquery Expressions

Subquery expressions include the following types:

EXISTS/NOT EXISTS

Figure 1 shows the syntax of an EXISTS/NOT EXISTS expression.

Figure 1 EXISTS/NOT EXISTS::=
  • The parameter of an EXISTS expression 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.
  • The subquery will generally only be executed long enough to determine whether at least one row is returned, not all the way to completion.
Example:
m_db=# CREATE SCHEMA tpcds;
m_db=# CREATE TABLE tpcds.store_returns
(
  sr_reason_sk     integer,
  sr_reason_id      character(16),
  sr_reason_desc    character(100),
  sr_customer_sk   integer
);
m_db=# CREATE TABLE tpcds.date_dim 
(
  d_dom            integer,
  d_reason_desc    character(100)
);
m_db=# INSERT INTO tpcds.store_returns VALUES(1, 'test_001', 'test_desc_001', 5), (12, 'test_002', 'test_desc_002', 8), (23, 'test_003', 'test_desc_003', 9), (14, 'test_004', 'test_desc_004', 10), (45, 'test_005', 'test_desc_005', 12), (55, 'test_006', 'test_desc_006', 1), (43, 'test_007', 'test_desc_007', 12);
m_db=# INSERT INTO tpcds.date_dim VALUES(1, 'test_dim_desc_001'), (6, 'test_dim_desc_002'), (9, 'test_dim_desc_003'), (19, 'test_dim_desc_004'), (12, 'test_dim_desc_005'), (23, 'test_dim_desc_006');

m_db=# SELECT sr_reason_sk,sr_customer_sk FROM tpcds.store_returns WHERE EXISTS (SELECT d_dom FROM tpcds.date_dim WHERE d_dom = store_returns.sr_reason_sk AND sr_customer_sk <10);
 sr_reason_sk | sr_customer_sk 
--------------+----------------
            1 |              5
           12 |              8
           23 |              9
(3 rows)

IN/NOT IN

Figure 2 shows the syntax of an IN/NOT IN expression.

Figure 2 IN/NOT IN::=
  • The right-hand side of IN/NOT IN is a parenthesized subquery, which returns exactly one column.
  • The expression on the left-hand side of IN/NOT IN is calculated and compared to each row of the subquery result.
  • The result of IN is true if any equal subquery row is found in the IN/NOT IN statement. The result is false if no equal row is found (including the case where the subquery returns no rows).
  • This is in accordance with SQL normal rules for Boolean combinations of null values. If the columns corresponding to two rows equal and are not empty, the two rows are equal to each other. If any columns corresponding to the two rows do not equal and are not empty, the two rows are not equal to each other. Otherwise, the result is NULL. If the result of each row does not equal and at least one row yields NULL, the result of IN will be NULL.
  • The IN operator of an array expression supports string types, binary types, and bit string types without truncating 0 characters.

Example:

m_db=# SELECT sr_reason_sk,sr_customer_sk  FROM tpcds.store_returns WHERE sr_customer_sk IN (SELECT d_dom FROM tpcds.date_dim WHERE d_dom < 10);
sr_reason_sk | sr_customer_sk 
--------------+----------------
           55 |              1
           23 |              9
(2 rows)

ANY/SOME

Figure 3 shows the syntax of an ANY/SOME expression.
Figure 3 any/some::=
  • The right-hand side of ANY/SOME is a parenthesized subquery, which returns exactly one column.
  • The expression on the left-hand side of ANY/SOME is evaluated and compared to each row of the subquery result using the given operator, which yields 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 case where the subquery returns no rows). SOME is a synonym of ANY. IN can be equivalently replaced with ANY.

Example:

m_db=# SELECT sr_reason_sk,sr_customer_sk  FROM tpcds.store_returns WHERE sr_customer_sk < ANY (SELECT d_dom FROM tpcds.date_dim WHERE d_dom < 10);
sr_reason_sk | sr_customer_sk 
--------------+----------------
            1 |              5
           12 |              8
           55 |              1
(3 rows)

ALL

Figure 4 shows the syntax of an ALL expression.

Figure 4 all::=
  • The right-hand side of ALL is a parenthesized subquery, which returns exactly one column.
  • The expression on the left-hand side of ALL is evaluated and compared to each row of the subquery result using the given operator, which yields a Boolean result. The result of ALL is true if all values are true (including the case where the subquery returns no rows). The result is false if any false result is found.

Example:

m_db=# SELECT sr_reason_sk,sr_customer_sk  FROM tpcds.store_returns WHERE sr_customer_sk < all(SELECT d_dom FROM tpcds.date_dim WHERE d_dom < 10);
 sr_reason_sk | sr_customer_sk 
--------------+----------------
(0 rows)

m_db=# DROP TABLE tpcds.store_returns;
m_db=# DROP TABLE tpcds.date_dim;
m_db=# DROP SCHEMA tpcds;