Examples
select genus, species from mammals
where family = 'Felidae'
order by genus;
select * from persons
where birthyear in (1880, 1881)
or birthyear between 1891 and 1898;
select name, street, borough, phone
from schools s
where exists (select * from pupils p where p.school = s.id)
order by borough, street;
select * from employees
where salary >= 10000 and position <> 'Manager';
select name from wrestlers
where region = 'Europe'
and weight > all (select weight from shot_putters
where region = 'Africa');
select id, name from players
where team_id = (select id from teams where name = 'Buffaloes');
select sum (population) from towns
where name like '%dam'
and province containing 'land';
select password from usertable
where username = current_user;
The following example shows what can happen if the search condition evaluates to NULL
.
Suppose you have a table listing children’s names and the number of marbles they possess.At a certain moment, the table contains this data:
CHILD | MARBLES |
---|---|
Anita |
23 |
Bob E. |
12 |
Chris |
<null> |
Deirdre |
1 |
Eve |
17 |
Fritz |
0 |
Gerry |
21 |
Hadassah |
<null> |
Isaac |
6 |
First, please notice the difference between NULL
and 0: Fritz is known to have no marbles at all, Chris’s and Hadassah’s marble counts are unknown.
Now, if you issue this SQL statement:
select list(child) from marbletable where marbles > 10;
you will get the names Anita, Bob E., Eve and Gerry.These children all have more than 10 marbles.
If you negate the expression:
select list(child) from marbletable where not marbles > 10
it’s the turn of Deirdre, Fritz and Isaac to fill the list.Chris and Hadassah are not included, because they aren’t known to have ten or fewer marbles.Should you change that last query to:
select list(child) from marbletable where marbles <= 10;
the result will still be the same, because the expression NULL <= 10
yields UNKNOWN
.This is not the same as TRUE
, so Chris and Hadassah are not listed.If you want them listed with the “poor” children, change the query to:
select list(child) from marbletable
where marbles <= 10 or marbles is null;
Now the search condition becomes true for Chris and Hadassah, because “marbles is null
” obviously returns TRUE
in their case.In fact, the search condition cannot be NULL
for anybody now.
Lastly, two examples of SELECT
queries with parameters in the search.It depends on the application how you should define query parameters and even if it is possible at all.Notice that queries like these cannot be executed immediately: they have to be prepared first.Once a parameterized query has been prepared, the user (or calling code) can supply values for the parameters and have it executed many times, entering new values before every call.How the values are entered and the execution started is up to the application.In a GUI environment, the user typically types the parameter values in one or more text boxes and then clicks an “Execute”, “Run” or “Refresh” button.
select name, address, phone frome stores
where city = ? and class = ?;
select * from pants
where model = :model and size = :size and color = :col;
The last query cannot be passed directly to the engine;the application must convert it to the other format first, mapping named parameters to positional parameters.