Publishers of technology books, eBooks, and videos for creative people

Home > Articles

This chapter is from the book

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:

  1. Find all the biography titles less than $20.
  2. Find all the history titles (regardless of price).
  3. 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:

  1. Find all the biography and history titles.
  2. Of the titles found in step 1, keep the ones priced less than $20.
  3. 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

Peachpit Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from Peachpit and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about Peachpit products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites; develop new products and services; conduct educational research; and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email ask@peachpit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by Adobe Press. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.peachpit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020