Although you usually use subqueries as search conditions in the WHERE clause, sometimes you can also use them in the HAVING clause of a query. When a subquery appears in the HAVING clause, like any expression in the HAVING clause, it is used as part of the row group selection.
Here is a request that lends itself naturally to a query with a subquery in the HAVING clause: "Which products' average in-stock quantity is more than double the average number of each item ordered per customer?"
SELECT Name, AVG( Quantity ) FROM Products GROUP BY Name HAVING AVG( Quantity ) > 2* ( SELECT AVG( Quantity ) FROM SalesOrderItems ); |
name | AVG( Products.Quantity ) |
---|---|
Baseball Cap | 62.000000 |
Shorts | 80.000000 |
Tee Shirt | 52.333333 |
The query executes as follows:
You can also use outer references in a HAVING clause, as shown in the following example, a slight variation on the one above.
This example finds the product ID numbers and line ID numbers of those products whose average ordered quantities is more than half the in-stock quantities of those products.
SELECT ProductID, LineID FROM SalesOrderItems GROUP BY ProductID, LineID HAVING 2* AVG( Quantity ) > ( SELECT Quantity FROM Products WHERE Products.ID = SalesOrderItems.ProductID ); |
ProductID | LineID |
---|---|
601 | 3 |
601 | 2 |
601 | 1 |
600 | 2 |
... | ... |
In this example, the subquery must produce the in-stock quantity of the product corresponding to the row group being tested by the HAVING clause. The subquery selects records for that particular product, using the outer reference SalesOrderItems.ProductID.
This query uses the comparison >, suggesting that the subquery must return exactly one value. In this case, it does. Since the ID field of the Products table is a primary key, there is only one record in the Products table corresponding to any particular product ID.
Send feedback about this page via email or DocCommentXchange | Copyright © 2008, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.0 |