- What Is a Set, Anyway?
- Operations on Sets
- Intersection
- Difference
- Union
- SQL Set Operations
- Summary
SQL Set Operations
Now that you have a basic understanding of set operations, let’s look briefly at how they’re implemented in SQL.
Classic Set Operations versus SQL
As noted earlier, not many commercial database systems yet support set intersection (INTERSECT) or set difference (EXCEPT) directly. The current SQL Standard, however, clearly defines how these operations should be implemented. We think that these set operations are important enough to at least warrant an overview of the syntax.
As promised, we’ll show you alternative ways to solve an intersection or difference problem in later chapters using JOINs. Because most database systems do support UNION, Chapter 10 is devoted to its use. The remainder of this chapter gives you an overview of all three operations.
Finding Common Values: INTERSECT
Let’s say you’re trying to solve the following seemingly simple problem:
- “Show me the orders that contain both a bike and a helmet.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of bike and helmet product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 10, 11, 25, 26) |
That seems to do the trick at first, but the answer includes orders that contain either a bike or a helmet, and you really want to find ones that contain both a bike and a helmet! If you visualize orders with bicycles and orders with helmets as two distinct sets, it’s easier to understand the problem. Figure 7-6 shows one possible relationship between the two sets of orders using a set diagram.
Figure 7-6 One possible relationship between two sets of orders
Actually, there’s no way to predict in advance what the relationship between two sets of data might be. In Figure 7-6, some orders have a bicycle in the list of products ordered, but no helmet. Some have a helmet, but no bicycle. The overlapping area, or intersection, of the two sets is where you’ll find orders that have both a bicycle and a helmet. Figure 7-7 shows another case where all orders that contain a helmet also contain a bicycle, but some orders that contain a bicycle do not contain a helmet.
Figure 7-7 All orders for a helmet also contain an order for a bicycle.
Seeing “both” in your request suggests you’re probably going to have to break the solution into separate sets of data and then link the two sets in some way. (Your request also needs to be broken into two parts.)
- “Show me the orders that contain a bike.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of bike product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) |
- “Show me the orders that contain a helmet.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of helmet product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) |
Now you’re ready to get the final solution by using—you guessed it—an intersection of the two sets. Figure 7-8 shows the SQL syntax diagram that handles this problem. (Note that you can use INTERSECT more than once to combine multiple SELECT statements.)
Figure 7-8 Linking two SELECT statements with INTERSECT
You can now take the two parts of your request and link them with an INTERSECT operator to get the correct answer:
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) INTERSECT SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) |
The sad news is that not many commercial implementations of SQL yet support the INTERSECT operator. But all is not lost! Remember that the primary key of a table uniquely identifies each row. (You don’t have to match on all the fields in a row—just the primary key—to find unique rows that intersect.) We’ll show you an alternative method (JOIN) in Chapter 8 that can solve this type of problem in another way. The good news is that virtually all commercial implementations of SQL do support JOIN.
Finding Missing Values: EXCEPT (DIFFERENCE)
Okay, let’s go back to the bicycles and helmets problem again. Let’s say you’re trying to solve this seemingly simple request as follows:
- “Show me the orders that contain a bike but not a helmet.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of bike product numbers and product number is not in the list of helmet product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) AND ProductNumber NOT IN (10, 25, 26) |
Unfortunately, the answer shows you orders that contain only a bike! The problem is that the first IN clause finds detail rows containing a bicycle, but the second IN clause simply eliminates helmet rows. If you visualize orders with bicycles and orders with helmets as two distinct sets, you’ll find this easier to understand. Figure 7-9 shows one possible relationship between the two sets of orders.
Figure 7-9 Orders for a bicycle that do not also contain a helmet
Seeing “except” or “but not” in your request suggests you’re probably going to have to break the solution into separate sets of data and then link the two sets in some way. (Your request also needs to be broken into two parts.)
- “Show me the orders that contain a bike.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of bike product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) |
- “Show me the orders that contain a helmet.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of helmet product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) |
Now you’re ready to get the final solution by using—you guessed it—a difference of the two sets. SQL uses the EXCEPT keyword to denote a difference operation. Figure 7-10 shows you the SQL syntax diagram that handles this problem.
Figure 7-10 Linking two SELECT statements with EXCEPT
You can now take the two parts of your request and link them with an EXCEPT operator to get the correct answer:
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) EXCEPT SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) |
Remember from our earlier discussion about the difference operation that the sequence of the sets matters. In this case, you’re asking for bikes “except” helmets. If you want to find out the opposite case—orders for helmets that do not include bikes—you can turn it around as follows:
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) EXCEPT SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) |
The sad news is that not many commercial implementations of SQL yet support the EXCEPT operator. Hang on to your helmet! Remember that the primary key of a table uniquely identifies each row. (You don’t have to match on all the fields in a row—just the primary key—to find unique rows that are different.) We’ll show you an alternative method (OUTER JOIN) in Chapter 9 that can solve this type of problem in another way. The good news is that nearly all commercial implementations of SQL do support OUTER JOIN.
Combining Sets: UNION
One more problem about bicycles and helmets, then we’ll pedal on to the next chapter. Let’s say you’re trying to solve this request, which looks simple enough on the surface:
- “Show me the orders that contain either a bike or a helmet.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of bike and helmet product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 10, 11, 25, 26) |
Actually, that works just fine! So why use a UNION to solve this problem? The truth is, you probably would not. However, if we make the problem more complicated, a UNION would be useful:
- “List the customers who ordered a bicycle together with the vendors who provide bicycles.”
Unfortunately, answering this request involves creating a couple of queries using JOIN operations, then using UNION to get the final result. Because we haven’t shown you how to do a JOIN yet, we’ll save solving this problem for Chapter 10. Gives you something to look forward to, doesn’t it?
Let’s get back to the “bicycles or helmets” problem and solve it with a UNION. If you visualize orders with bicycles and orders with helmets as two distinct sets, then you’ll find it easier to understand the problem. Figure 7-11 shows you one possible relationship between the two sets of orders.
Figure 7-11 Orders for bicycles or helmets
Seeing “either,” “or,” or “together” in your request suggests that you’ll need to break the solution into separate sets of data and then link the two sets with a UNION. This particular request can be broken into two parts:
- “Show me the orders that contain a bike.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of bike product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) |
- “Show me the orders that contain a helmet.”
Translation |
Select the distinct order numbers from the order details table where the product number is in the list of helmet product numbers |
Clean Up |
Select |
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) |
Now you’re ready to get the final solution by using—you guessed it—a union of the two sets. Figure 7-12 shows the SQL syntax diagram that handles this problem.
Figure 7-12 Linking two SELECT statements with UNION
You can now take the two parts of your request and link them with a UNION operator to get the correct answer:
SQL |
SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (1, 2, 6, 11) UNION SELECT DISTINCT OrderNumber FROM Order_Details WHERE ProductNumber IN (10, 25, 26) |
The good news is that nearly all commercial implementations of SQL support the UNION operator. As is perhaps obvious from the examples, a UNION might be doing it the hard way when you want to get an “either-or” result from a single table. UNION is most useful for compiling a list from several similarly structured but different tables. We’ll explore UNION in much more detail in Chapter 10.