2.4 Conditions and Expressions

Now that you understand how conditions are grouped together and evaluated, it's time to take a look at the different elements that make up a condition. A condition is comprised of one or more expressions along with one or more operators. Examples of expressions include:

  • Numbers

  • Columns, such as s.supplier_id

  • Literals, such as `Acme Industries'

  • Functions, such as UPPER(`abcd')

  • Lists of simple expressions, such as (1, 2, 3)

  • Subqueries

Examples of operators include:

  • Arithmetic operators, such as +, -, *, and /

  • Comparison operators, such as =, <, >=, !=, LIKE, and IN

The following sections explore many of the common condition types that use different combinations of the preceeding expression and operator types.

2.4.1 Equality/Inequality Conditions

Most of the conditions found in a WHERE clause will be equality conditions used to join data sets together or to isolate specific values. You have already encountered these types of conditions numerous times in previous examples, including:

s.supplier_id = p.supplier_id



s.name = 'Acme Industries'



supplier_id = (SELECT supplier_id 

  FROM supplier 

  WHERE name = 'Acme Industries')

All three conditions are comprised of a column expression followed by a comparison operator (=) followed by another expression. The conditions differ in the type of expression on the right side of the comparison operator. The first example compares one column to another, the second example compares a column to a literal, and the third example compares a column to the value returned by a subquery.

You can also build conditions that use the inequality comparison operator (!=). In a previous example, the NOT operator was used to find information about parts supplied by every supplier other than Acme Industries and Tilton Enterprises. Using the != operator rather than using NOT makes the query easier to understand and removes the need for the OR operator:

SELECT p.part_nbr, p.name, p.supplier_id, p.status, p.inventory_qty,

  s.supplier_id, s.name

FROM part p, supplier s

WHERE s.supplier_id = p.supplier_id

  AND s.name != 'Acme Industries'

  AND s.name != 'Tilton Enterprises';

While this is an improvement over the previous version, the next section shows an even cleaner way to represent the same logic.

2.4.2 Membership Conditions

Along with determining whether two expressions are identical, it is often useful to determine whether one expression can be found within a set of expressions. Using the IN operator, you can build conditions that will evaluate to TRUE if a given expression exists in a set of expressions:

s.name IN ('Acme Industries', 'Tilton Enterprises')

You may also use the NOT IN operator to determine whether an expression does not exist in a set of expressions:

s.name NOT IN ('Acme Industries', 'Tilton Enterprises')

Most people prefer to use a single condition with IN or NOT IN instead of writing multiple conditions using = or !=, so, with that in mind, here's one last stab at the Acme/Tilton query:

SELECT p.part_nbr, p.name, p.supplier_id, p.status, p.inventory_qty,

  s.supplier_id, s.name

FROM part p, supplier s

WHERE s.supplier_id = p.supplier_id

  AND s.name NOT IN ('Acme Industries', 'Tilton Enterprises');

Along with prefabricated sets of expressions, subqueries may be employed to generate sets on the fly. If a subquery returns exactly one row, you may use a comparison operator; if a subquery returns more than one row, or if you're not sure whether the subquery might return more than one row, use the IN operator. The following example updates all orders that contain parts supplied by Eastern Importers:

UPDATE cust_order

SET sale_price = sale_price * 1.1

WHERE cancelled_dt IS NULL

  AND ship_dt IS NULL

  AND order_nbr IN

 (SELECT li.order_nbr

  FROM line_item li, part p, supplier s

  WHERE s.name = 'Eastern Importers'

    AND s.supplier_id = p.supplier_id

    AND p.part_nbr = li.part_nbr);

The subquery evaluates to a (potentially empty) set of order numbers. All orders whose order number exists in that set are then modified by the UPDATE statement.

2.4.3 Range Conditions

If you are dealing with dates or numeric data, you may be interested in whether a value falls within a specified range rather than whether it matches a specific value or exists in a finite set. For such cases, you may use the BETWEEN operator, as in:

DELETE FROM cust_order

WHERE order_dt BETWEEN '01-JUL-2001' AND '31-JUL-2001';

To determine whether a value lies outside a specific range, you can use the NOT BETWEEN operator:

SELECT order_nbr, cust_nbr, sale_price

FROM cust_order

WHERE sale_price NOT BETWEEN 1000 AND 10000;

When using BETWEEN, make sure the first value is the lesser of the two values provided. While "BETWEEN 01-JUL-2001 AND 31-JUL-2001" and "BETWEEN 31-JUL-2001 AND 01-JUL-2001" might seem logically equivalent, specifying the higher value first guarantees that your condition will always evaluate to FALSE. Keep in mind that X BETWEEN Y AND Z is evaluated as X >= Y AND X <= Z.

Ranges may also be specified using the operators <, >, <=, and >=, although doing so requires writing two conditions rather than one. The previous query can also be expressed as:

SELECT order_nbr, cust_nbr, sale_price

FROM cust_order

WHERE sale_price < 1000 OR sale_price > 10000;

2.4.4 Matching Conditions

When dealing with character data, there are some situations where you are looking for an exact string match, and others where a partial match is sufficient. For the latter case, you can use the LIKE operator along with one or more pattern-matching characters, as in:

DELETE FROM part

WHERE part_nbr LIKE 'ABC%';

The pattern-matching character % matches strings of any length, so all of the following part numbers would be deleted: 'ABC', 'ABC-123', 'ABC9999999'. If you need finer control, you can use the underscore (_) pattern-matching character to match single characters, as in:

DELETE FROM part

WHERE part_nbr LIKE '_B_';

For this pattern, any part number composed of exactly three characters with a B in the middle would be deleted. Both pattern-matching characters may be utilized in numerous combinations to find the desired data. Additionally, the NOT LIKE operator may be employed to find strings that don't match a specified pattern. The following example deletes all parts whose name does not contain a Z in the third position followed later by the string "T1J":

DELETE FROM part

WHERE part_nbr NOT LIKE '_  _Z%T1J%';

Oracle provides a slew of built-in functions for handling character data that can be used to build matching conditions. For example, the condition part_nbr LIKE 'ABC%' could be rewritten using the SUBSTR function as SUBSTR(part_nbr, 1, 3) = 'ABC'. For definitions and examples for all of Oracle's built-in functions, see Oracle in a Nutshell (O'Reilly).

You may come across data that include the characters % and _ and need to include them in your patterns. For example, you might have a column called instructions in the cust_order table that may have a value such as:

Cancel order if more than 25% of parts are unavailable

If you want to find strings containing the % character, you will need to escape the % character within your pattern so that it isn't treated as a wildcard. To do so, you will need to use the ESCAPE clause to let Oracle know which character you have chosen as the escape character:

SELECT instructions

FROM cust_order

WHERE instructions LIKE '%\%%' ESCAPE '\';

This query would return all rows where the instructions column contains the % character anywhere in the string.

2.4.5 Regular Expressions

Beginning with the Oracle Database 10g release, you can use regular expressions within your conditions. Regular expressions allow for much more complex pattern matching without the need for multiple conditions. For example, if you wanted to find all customers whose name begins with W, ends in "ies" and does not include L anywhere in the string, you could use multiple conditions with the LIKE and NOT LIKE operators:

SELECT name

FROM customer

WHERE name LIKE 'W%ies'

  AND name NOT LIKE '%L%';



NAME

------------------------------

Worcester Technologies

Wallace Industries

You can achieve the same result more succinctly, in a single expression, with the new REGEXP_LIKE function:

SELECT name

FROM customer

WHERE REGEXP_LIKE(name, '^W([^L]*)ies$');



NAME

------------------------------

Worcester Technologies

Wallace Industries

If that second argument to REGEXP_LIKE looks like gibberish, fear not: we cover regular expressions in detail in Chapter 17.

2.4.6 Handling NULL

The NULL expression represents the absence of a value. If, when entering an order into the database, you are uncertain when the order will be shipped, it is better to leave the ship date undefined than to fabricate a value. Until the ship date has been determined, therefore, it is best to leave the ship_dt column NULL. NULL is also useful for cases where data is not applicable. For example, a cancelled order's shipping date is no longer applicable and should be set to NULL.

When working with NULL, the concept of equality does not apply; a column may be NULL, but it will never equal NULL. Therefore, you will need to use the special operator IS NULL when looking for NULL data, as in:

UPDATE cust_order

SET expected_ship_dt = SYSDATE + 1

WHERE ship_dt IS NULL;

In this example, all orders whose shipping date hasn't been specified will have their expected shipping date set to tomorrow.

You may also use the IS NOT NULL operator to locate non-NULL data:

UPDATE cust_order

SET expected_ship_dt = NULL

WHERE ship_dt IS NOT NULL;

This example sets the expected shipping date to NULL for all orders that have already shipped. Notice that the SET clause uses the equality operator (=) with NULL, whereas the WHERE clause uses the IS NOT NULL operator. The equality operator is used to set a column to NULL, whereas the IS NOT NULL operator is used to evaluate whether a column is NULL. A great many mistakes might have been avoided had the designers of SQL chosen a special operator to be utilized when setting a column to NULL (i.e., SET expected_ship_dt TO NULL), but this is not the case. To make matters worse, Oracle doesn't complain if you mistakenly use the equality operator when evaluating for NULL. The following query will parse and execute but will never return rows:

SELECT order_nbr, cust_nbr, sale_price, order_dt

FROM cust_order

WHERE ship_dt = NULL;

Hopefully, you would quickly recognize that the previous query never returns data and replace the equality operator with IS NULL. However, there is a more subtle mistake involving NULL that is harder to spot. Say you are looking for all employees who are not managed by Marion Blake, whose employee ID is 7698. Your first instinct may be to run the following query:

SELECT fname, lname, manager_emp_id

FROM employee

WHERE manager_emp_id != 7698;



FNAME                LNAME                MANAGER_EMP_ID

-------------------- -------------------- --------------

JOHN                 SMITH                          7902

TERRY                JONES                          7839

MARION               BLAKE                          7839

CAROL                CLARK                          7839

DONALD               SCOTT                          7566

DIANE                ADAMS                          7788

JENNIFER             FORD                           7566

BARBARA              MILLER                         7782

While this query returns rows, it leaves out those employees who are top-level managers and, thus, are not managed by anyone. Since NULL is neither equal nor not equal to 7698, this set of employees is absent from the result set. To ensure that all employees are considered, you will need to explicitly handle NULL, as in:

SELECT fname, lname, manager_emp_id

FROM employee

WHERE manager_emp_id IS NULL OR manager_emp_id != 7698;



FNAME                LNAME                MANAGER_EMP_ID

-------------------- -------------------- --------------

JOHN                 SMITH                          7902

TERRY                JONES                          7839

MARION               BLAKE                          7839

CAROL                CLARK                          7839

DONALD               SCOTT                          7566

FRANCIS              KING

DIANE                ADAMS                          7788

JENNIFER             FORD                           7566

BARBARA              MILLER                         7782

Including two conditions for every nullable column in your WHERE clause can get a bit tiresome. Instead, you can use Oracle's built-in function NVL, which substitutes a specified value for columns that are NULL, as in:

SELECT fname, lname, manager_emp_id

FROM employee

WHERE NVL(manager_emp_id, -999) != 7698;



FNAME                LNAME                MANAGER_EMP_ID

-------------------- -------------------- --------------

JOHN                 SMITH                          7902

TERRY                JONES                          7839

MARION               BLAKE                          7839

CAROL                CLARK                          7839

DONALD               SCOTT                          7566

FRANCIS              KING

DIANE                ADAMS                          7788

JENNIFER             FORD                           7566

BARBARA              MILLER                         7782

In this example, the value -999 is substituted for all NULL values, which, since -999 is never equal to 7698, guarantees that all rows whose manager_emp_id column is NULL will be included in the result set. Thus, all employees whose manager_emp_id column is NULL or is not NULL and has a value other than 7698 will be retrieved by the query.

2.4.7 Placement of Join Conditions

Throughout this chapter, all examples that join multiple tables have had their join conditions included in the WHERE clause along with various filter conditions. Beginning with the Oracle9i release, you have the option of using the ANSI join syntax, which specifies that all join conditions be included in the FROM clause, as illustrated by the following:

SELECT p.part_nbr, p.name, p.supplier_id, p.status, p.inventory_qty,

  s.supplier_id, s.name

FROM part p INNER JOIN supplier s

ON s.supplier_id = p.supplier_id

WHERE s.name NOT IN ('Acme Industries', 'Tilton Enterprises');

As you can see, the join condition s.supplier_id = p.supplier_id has been moved to the ON subclause, and the FROM clause specifies that the part and supplier tables be joined via an inner join. This syntax may look a bit strange at first, but it greatly improves the readability and maintainability of your queries. Therefore, for the remainder of this book, all examples will employ the ANSI join syntax.