Click here to view and discuss this page in DocCommentXchange. In the future, you will be sent there automatically.

SQL Anywhere 10.0.1 » SQL Anywhere Server - SQL Usage » Using Subqueries

Outer references Next Page

Subqueries and joins


The query optimizer automatically rewrites as joins many of the queries that make use of subqueries.

Example

Consider the request, "When did Mrs. Clarke and Suresh place their orders, and by which sales representatives?" It can be answered with the following query:

SELECT OrderDate, SalesRepresentative
FROM SalesOrders
WHERE CustomerID IN (
   SELECT ID
   FROM Customers
   WHERE Surname = 'Clarke' OR GivenName = 'Suresh' );
OrderDate SalesRepresentative
2001-01-05 1596
2000-01-27 667
2000-11-11 467
2001-02-04 195
... ...

The subquery yields a list of customer IDs that correspond to the two customers whose names are listed in the WHERE clause, and the main query finds the order dates and sales representatives corresponding to those two people's orders.

Replacing a subquery with a join

The same question can be answered using joins. Here is an alternative form of the query, using a two-table join:

SELECT OrderDate, SalesRepresentative
FROM SalesOrders, Customers
WHERE CustomerID=Customers.ID AND
  ( Surname = 'Clarke' OR GivenName = 'Suresh' );

This form of the query joins the SalesOrders table to the Customers table to find the orders for each customer, and then returns only those records for Suresh and Clarke.

Some joins cannot be written as subqueries

Both of these queries find the correct order dates and sales representatives, and neither is more right than the other. Many people will find the subquery form more natural, because the request doesn't ask for any information about customer IDs, and because it might seem odd to join the SalesOrders and Customers tables together to answer the question.

If, however, the request changes to include some information from the Customers table, the subquery form no longer works. For example, the request "When did Mrs. Clarke and Suresh place their orders, and by which representatives, and what are their full names?", it is necessary to include the Customers table in the main WHERE clause:

SELECT GivenName, Surname, OrderDate, SalesRepresentative
FROM SalesOrders, Customers
WHERE CustomerID=Customers.ID AND 
  ( Surname = 'Clarke' OR GivenName = 'Suresh' );
GivenName Surname OrderDate SalesRepresentative
Belinda Clarke 2001-01-05 1596
Belinda Clarke 2000-01-27 667
Belinda Clarke 2000-11-11 467
Belinda Clarke 2001-02-04 195
... ... ... ...
Some subqueries cannot be written as joins

Similarly, there are cases where a subquery will work but a join will not. For example:

SELECT Name, Description, Quantity
FROM Products
WHERE Quantity <  2 * (
   SELECT AVG( Quantity )
   FROM SalesOrderItems );
name Description Quantity
Tee Shirt Tank Top 28
Baseball Cap Wool cap 12
Visor Cloth Visor 36
... ... ...

In this case, the inner query is a summary query and the outer query is not, so there is no way to combine the two queries by a simple join.

For more information on joins, see Joins: Retrieving Data from Several Tables.