- Retrieving Columns with SELECT and FROM
- Creating Column Aliases with AS
- Eliminating Duplicate Rows with DISTINCT
- Sorting Rows with ORDER BY
- Filtering Rows with WHERE
- Combining and Negating Conditions with AND, OR, and NOT
- Matching Patterns with LIKE
- Range Filtering with BETWEEN
- List Filtering with IN
- Testing for Nulls with IS NULL
Combining and Negating Conditions with AND, OR, and NOT
You can specify multiple conditions in a single WHERE clause to, say, retrieve rows based on the values in multiple columns. You can use the AND and OR operators to combine two or more conditions into a compound condition. AND, OR, and a third operator, NOT, are logical operators. Logical operators, or Boolean operators, are operators designed to work with truth values: true, false, and unknown.
If you’ve programmed in other languages (or studied propositional logic), you’re familiar with the two-value logic (2VL) system. In two-value logic, the result of a logical expression is either true or false. 2VL assumes perfect knowledge, in which all propositions are known to be true or false. Databases model real data, however, and our knowledge of the world is imperfect—that’s why we use nulls to represent unknown values (see “Nulls” in Chapter 3).
2VL is insufficient to represent knowledge gaps, so SQL uses three-value logic (3VL). In three-value logic, the result of a logical expression is true, false, or unknown. If the result of a compound condition is false or unknown, the row is excluded from the result. (To retrieve rows with nulls, see “Testing for Nulls with IS NULL” later in this chapter.)
The AND operator
The AND operator’s important characteristics are:
- AND connects two conditions and returns true only if both conditions are true.
- Table 4.3 shows the possible outcomes when you combine two conditions with AND. The table’s left column shows the truth values of the first condition, the top row shows the truth values of the second condition, and each intersection shows the AND outcome. This type of table is called a truth table.
Table 4.3.
AND
True
False
Unknown
True
True
False
Unknown
False
False
False
False
Unknown
Unknown
False
Unknown
- Any number of conditions can be connected with ANDs. All the conditions must be true for the row to be included in the result.
- AND is commutative (independent of order): WHERE condition1 AND condition2 is equivalent to WHERE condition2 AND condition1.
- You can enclose one or both of the conditions in parentheses. Some compound conditions need parentheses to force the order in which conditions are evaluated.
See Listings 4.22 and 4.23, and Figures 4.22 and 4.23, for some AND examples.
Listing 4.22. List the biographies that sell for less than $20. See Figure 4.22 for the result.
SELECT title_name, type, price FROM titles WHERE type = 'biography' AND price < 20;
Figure 4.22 Result of Listing 4.22.
title_name type price ------------------------- ---------- ----- How About Never? biography 19.95 Spontaneous, Not Annoying biography 12.99
Listing 4.23. List the authors whose last names begin with one of the letters H through Z and who don’t live in California. See Figure 4.23 for the result.
SELECT au_fname, au_lname FROM authors WHERE au_lname >= 'H' AND au_lname <= 'Zz' AND state <> 'CA';
Figure 4.23 Result of Listing 4.23. Remember that the results of string comparisons depend on the DBMS’s collating sequence; see “Sorting Rows with ORDER BY” earlier in this chapter.
au_fname au_lname --------- ----------- Wendy Heydemark Christian Kells Paddy O'Furniture
The OR operator
The OR operator’s important characteristics are:
- OR connects two conditions and returns true if either condition is true or if both conditions are true.
Table 4.4 shows the OR truth table.
Table 4.4.
OR
True
False
Unknown
True
True
True
True
False
True
False
Unknown
Unknown
True
Unknown
Unknown
- Any number of conditions can be connected with ORs. OR will retrieve rows that match any condition or all the conditions.
- Like AND, OR is commutative; the order in which you list the conditions doesn’t matter.
- You can enclose one or both of the conditions in parentheses.
See Listings 4.24 and 4.25, and Figures 4.24 and 4.25, for some OR examples.
Listing 4.24. List the authors who live in New York State, Colorado, or San Francisco. See Figure 4.24 for the result.
SELECT au_fname, au_lname, city, state FROM authors WHERE (state = 'NY') OR (state = 'CO') OR (city = 'San Francisco');
Figure 4.24 Result of Listing 4.24.
au_fname au_lname city state --------- --------- --------------- ----- Sarah Buchman Bronx NY Wendy Heydemark Boulder CO Hallie Hull San Francisco CA Klee Hull San Francisco CA Christian Kells New York NY
Listing 4.25. List the publishers that are located in California or are not located in California. This example is contrived to show the effect of nulls in conditions; see Figure 4.25 for the result.
SELECT pub_id, pub_name, state, country FROM publishers WHERE (state = 'CA') OR (state <> 'CA');
Figure 4.25 Result of Listing 4.25. Publisher P03 is missing because its state is null.
pub_id pub_name state country ------ ----------------- ----- ------- P01 Abatis Publishers NY USA P02 Core Dump Books CA USA P04 Tenterhooks Press CA USA
Listing 4.25 shows the effect of nulls in conditions. You might expect the result, Figure 4.25, to display all the rows in the table publishers. But the row for publisher P03 (located in Germany) is missing because it contains a null in the column state. The null causes the result of both of the OR conditions to be unknown, so the row is excluded from the result. To test for nulls, see “Testing for Nulls with IS NULL” later in this chapter.
The NOT operator
The NOT operator’s important characteristics are:
- Unlike AND and OR, NOT doesn’t connect two conditions. Instead, it negates (reverses) a single condition.
Table 4.5 shows the NOT truth table.
Table 4.5.
CONDITION
NOT CONDITION
True
False
False
True
Unknown
Unknown
In comparisons, place NOT before the column name or expression
WHERE NOT state = 'CA' --Correct
and not before the operator (even though it sounds better when read):
WHERE state NOT = 'CA' --Illegal
NOT acts on one condition. To negate two or more conditions, repeat the NOT for each condition. To list titles that are not biographies and are not priced less than $20, for example, type
SELECT title_id, type, price FROM titles WHERE NOT type = 'biography' AND NOT price < 20; --Correct
and not
SELECT title_id, type, price FROM titles WHERE NOT type = 'biography' AND price < 20; --Wrong
The latter clause is legal but returns the wrong result. See the Tips in this section to learn ways to express equivalent NOT conditions.
In comparisons, using NOT often is a matter of style. The following two clauses are equivalent:
WHERE NOT state = 'CA'
and
WHERE state <> 'CA'
- You can enclose the condition in parentheses.
Listing 4.26. List the authors who don’t live in California. See Figure 4.26 for the result.
SELECT au_fname, au_lname, state FROM authors WHERE NOT (state = 'CA');
Figure 4.26 Result of Listing 4.26.
au_fname au_lname state --------- ----------- ----- Sarah Buchman NY Wendy Heydemark CO Christian Kells NY Paddy O'Furniture FL
Listing 4.27. List the titles whose price is not less than $20 and that have sold more than 15,000 copies. See Figure 4.27 for the result.
SELECT title_name, sales, price FROM titles WHERE NOT (price < 20) AND (sales > 15000);
Figure 4.27 Result of Listing 4.27.
title_name sales price ----------------------------- ------- ----- Ask Your System Administrator 25667 39.95 I Blame My Mother 1500200 23.95
Using AND, OR, and NOT together
You can combine the three logical operators in a compound condition. Your DBMS uses SQL’s precedence rules to determine which operators to evaluate first. Precedence is covered in “Determining the Order of Evaluation” in Chapter 5, but for now you need know only that when you use multiple logical operators in a compound condition, NOT is evaluated first, then AND, and finally OR. You can override this order with parentheses: Everything in parentheses is evaluated first. When parenthesized conditions are nested, the innermost condition is evaluated first. Under the default precedence rules, the condition x AND NOT y OR z is equivalent to (x AND (NOT y)) OR z. It’s wise to use parentheses, rather than rely on the default evaluation order, to make the evaluation order clear.
If I want to list history and biography titles priced less than $20, for example, Listing 4.28 won’t work. AND is evaluated before OR, so the query is evaluated as follows:
- Find all the biography titles less than $20.
- Find all the history titles (regardless of price).
- List both sets of titles in the result (Figure 4.28).
Listing 4.28. This query won’t work if I want to list history and biography titles less than $20, because AND has higher precedence than OR. See Figure 4.28 for the result.
SELECT title_id, type, price FROM titles WHERE type = 'history' OR type = 'biography' AND price < 20;
Figure 4.28 Result of Listing 4.28. This result contains two history titles priced more than $20, which is not what I wanted.
title_id type price -------- --------- ----- T01 history 21.99 T02 history 19.95 T06 biography 19.95 T12 biography 12.99 T13 history 29.99
To fix this query, I’ll add parentheses to force evaluation of OR first. Listing 4.29 is evaluated as follows:
- Find all the biography and history titles.
- Of the titles found in step 1, keep the ones priced less than $20.
- List the subset of titles in the result (Figure 4.29).
Listing 4.29. To fix Listing 4.28, I’ve added parentheses to force OR to be evaluated before AND. See Figure 4.29 for the result.
SELECT title_id, type, price FROM titles WHERE (type = 'history' OR type = 'biography') AND price < 20;
Figure 4.29 Result of Listing 4.29. Fixed.
title_id type price -------- --------- ----- T02 history 19.95 T06 biography 19.95 T12 biography 12.99