Summary: in this tutorial, you will learn how to use the Oracle ALL
operator to compare a value with a list or subquery.
Introduction to the Oracle ALL operator
The Oracle ALL
operator is used to compare a value to a list of values or result set returned by a subquery.
The following shows the syntax of the ALL
operator used with a list or a subquery:
operator ALL ( v1, v2, v3)
operator ALL ( subquery)
Code language: SQL (Structured Query Language) (sql)
In this syntax:
- The
ALL
operator must be preceded by an comparison operator such as =, != >,>=, <, <= and followed by a list or subquery. - The list or subquery must be surrounded by the parentheses.
When you use the ALL
operator to compare a value to a list, Oracle expands the initial condition to all elements of the list and uses the AND
operator to combine them as shown below:
SELECT
*
FROM
table_name
WHERE
c > ALL (
v1,
v2,
v3
);
-- transform the ALL operator
SELECT
*
FROM
table_name
WHERE
c > v1
AND c > v2
AND c > v3;
Code language: SQL (Structured Query Language) (sql)
If you use the ALL
operator to compare a value with a result set returned by a subquery, Oracle performs a two-step transformation as shown below:
SELECT product_name,
list_price
FROM products
WHERE list_price > ALL
( SELECT list_price
FROM products
WHERE category_id = 1 )
ORDER BY product_name;
-- 1st step: transformation that uses ANY
SELECT product_name,
list_price
FROM products p1
WHERE NOT( p1.list_price <= ANY
(SELECT list_price
FROM products p2
WHERE category_id = 1 ))
ORDER BY product_name;
-- 2nd step: transformation that eliminates ANY
SELECT product_name,
list_price
FROM products p1
WHERE NOT EXISTS
(SELECT p2.list_price
FROM products p2
WHERE p2.category_id = 1
AND p2.list_price >= p1.list_price )
ORDER BY product_name;
Code language: SQL (Structured Query Language) (sql)
If the subquery returns no rows, then the following condition evaluates to true:
operator ALL (subquery)
Code language: SQL (Structured Query Language) (sql)
This means that the query that uses the above condition in the WHERE
clause will return all rows in case the subquery returns no rows.
SELECT
*
FROM
table_name
WHERE
col operator ALL(subquery);
Code language: SQL (Structured Query Language) (sql)
Oracle ALL operator examples
The following example finds the average list price of products in each product category:
SELECT
ROUND( AVG( list_price ),2 ) avg_list_price
FROM
products
GROUP BY
category_id
ORDER BY
avg_list_price DESC;
Code language: SQL (Structured Query Language) (sql)
1) col > ALL (list)
The expression evaluates to true if the col
is greater than the biggest value in the list.
For example, the following query finds all products whose list prices are greater than the highest price of the average price list:
SELECT
product_name,
list_price
FROM
products
WHERE
list_price > ALL(
SELECT
AVG( list_price )
FROM
products
GROUP BY
category_id
)
ORDER BY
list_price ASC;
Code language: SQL (Structured Query Language) (sql)
2) col < ALL(list)
The expression evaluates to true if the col
is smaller than the smallest value in the list.
For example, the following query finds all products whose list prices are less than the lowest price in the average price list:
SELECT
product_name,
list_price
FROM
products
WHERE
list_price < ALL(
SELECT
AVG( list_price )
FROM
products
GROUP BY
category_id
)
ORDER BY
list_price DESC;
Code language: SQL (Structured Query Language) (sql)
3) col >= ALL(list)
The expression evaluates to true if the col
is greater than or equal to the biggest value in the list.
The following statement returns CPU products whose list price is greater than or equal to 2200:
SELECT
product_name,
list_price
FROM
products
WHERE
list_price >= ALL(
1000,
1500,
2200
)
AND category_id = 1
ORDER BY
list_price DESC;
Code language: SQL (Structured Query Language) (sql)
3) col <= ALL(list)
The expression evaluates to true if the col
is less than or equal to the smallest value in the list.
The following statement returns the CPU products whose list price is less than or equal to 977.99, which is the smallest value in the list.
SELECT
product_name,
list_price
FROM
products
WHERE
list_price <= ALL(
977.99,
1000,
2200
)
AND category_id = 1
ORDER BY
list_price DESC;
Code language: SQL (Structured Query Language) (sql)
5) col = ALL ( list)
The expression evaluates to true if the col
matches all values in the list.
6) col != ALL (list)
The expression evaluates to true if the col
does not match any values in the list.
In this tutorial, you have learned how to use the Oracle ALL
operator to compare a value with a list or subquery.