To obtain the opposite of a particular condition, you have to place the keyword NOT before the relevant expression. If you want to negate a compound expression, you have to place it in parentheses.
SELECT name, state
FROM hotel.city
WHERE NOT (state = 'CA' OR state = 'DC' OR state =
'IL' OR state = 'NY')
Selecting the cities/places that are not in the states of CA, DC, IL, or NY
Result
NAME |
STATE |
Silver Spring |
MD |
Daytona Beach |
FL |
Deerfield Beach |
FL |
Clearwater |
FL |
Cincinnati |
OH |
Detroit |
MI |
New Orleans |
LA |
Dallas |
TX |
Portland |
OR |
See also:
Search Condition (search_condition)
When the BETWEEN, IN, LIKE, and NULL predicates are used, you can place NOT before the predicate or immediately before the relevant keyword (BETWEEN, IN, LIKE, NULL).
SELECT name, state
FROM hotel.city
WHERE NOT (state BETWEEN 'CA' AND 'NY')
or
SELECT
name, state
FROM hotel.city
WHERE state NOT BETWEEN 'CA' AND
'NY'
Selecting the cities/places that are not in the states of CA, DC, FL, IL, LA, MD, MI, or NY
Result
NAME |
STATE |
Cincinnati |
OH |
Dallas |
TX |
Portland |
OR |
See also:
BETWEEN Predicate (between_predicate)
SELECT name, state
FROM hotel.city
WHERE NOT (state IN ('CA', 'DC', 'IL', 'NY'))
or
SELECT
name, state
FROM hotel.city
WHERE state NOT IN ('CA', 'DC', 'IL', 'NY')
Selecting the cities/places that are not in the states of CA, DC, IL, or NY
Result
NAME |
STATE |
Silver Spring |
MD |
Daytona Beach |
FL |
Deerfield Beach |
FL |
Clearwater |
FL |
Cincinnati |
OH |
Detroit |
MI |
New Orleans |
LA |
Dallas |
TX |
Portland |
OR |
See also:
SELECT firstname, name
FROM hotel.customer
WHERE NOT (firstname LIKE '%e%')
or
SELECT
firstname, name
FROM hotel.customer
WHERE firstname NOT LIKE '%e%'
Selecting the customers whose first names do not contain “e”
Result
FIRSTNAME |
NAME |
Mary |
Griffith |
Martin |
Randolph |
Sally |
Smith |
Rita |
Doe |
Frank |
Miller |
Susan |
Baker |
Antony |
Jenkins |
See also:
LIKE Predicate (like_predicate)
SELECT firstname, name
FROM hotel.customer
WHERE NOT (firstname IS NULL)
or
SELECT
firstname, name
FROM hotel.customer
WHERE firstname IS NOT NULL
Selecting the customers with a first name, that is, customers who are not companies
Result
FIRSTNAME |
NAME |
Jenny |
Porter |
Peter |
Brown |
Rose |
Brian |
Mary |
Griffith |
Martin |
Randolph |
Sally |
Smith |
Mike |
Jackson |
Rita |
Doe |
George |
Howe |
Frank |
Miller |
Susan |
Baker |
Joseph |
Peters |
Antony |
Jenkins |
See also:
NULL Predicate (null_predicate)
See also: