SELECT v16
Name
SELECT
— Retrieve rows from a table or view.
Synopsis
Where from_item
can be one of:
Description
SELECT
retrieves rows from one or more tables. The general processing of SELECT
is as follows:
- All elements in the
FROM
list are computed. (Each element in theFROM
list is a real or virtual table.) If you specify more than one element in theFROM
list, they are cross joined. SeeFROM
clause. - If you specify the
WHERE
clause, all rows that don't satisfy the condition are eliminated from the output. SeeWHERE
clause. - If you specify the
GROUP BY
clause, the output is divided into groups of rows that match one or more values. TheHAVING
clause eliminates groups that don't satisfy the given condition. SeeGROUP BY
clause andHAVING
clause. - Using the operators
UNION
,INTERSECT
, andMINUS
, you can combine the output of more than oneSELECT
statement to form a single result set. TheUNION
operator returns all rows that are in one or both of the result sets. TheINTERSECT
operator returns all rows that are strictly in both result sets. TheMINUS
operator returns the rows that are in the first result set but not in the second. In all three cases, duplicate rows are eliminated. In the case of theUNION
operator, if you specifyALL
, then duplicates aren't eliminated. SeeUNION
clause,INTERSECT
clause, andMINUS
clause. - The actual output rows are computed using the
SELECT
output expressions for each selected row. SeeSELECT
list. - The
CONNECT BY
clause is used to select data that has a hierarchical relationship. Such data has a parent-child relationship between rows. SeeCONNECT BY
clause. - If you specify the
ORDER BY
clause, the returned rows are sorted in the specified order. Otherwise, the rows are returned in the order the system finds fastest to produce. SeeORDER BY
clause. DISTINCT | UNIQUE
eliminates duplicate rows from the result.ALL
(the default) returns all candidate rows, including duplicates. SeeDISTINCT | UNIQUE
clause.- The
FOR UPDATE
clause causes theSELECT
statement to lock the selected rows against concurrent updates. SeeFOR UPDATE
clause.
You must have SELECT
privilege on a table to read its values. The use of FOR UPDATE
requires UPDATE
privilege as well.
Parameters
optimizer_hint
Comment-embedded hints to the optimizer for selecting an execution plan. See Optimizer hints for information about optimizer hints.
FROM clause
The FROM
clause specifies one or more source tables for a SELECT
statement. The syntax is:
Where source
can be one of following elements:
table_name[@dblink ]
The name (optionally schema-qualified) of an existing table or view. dblink
is a database link name identifying a remote database. See the CREATE DATABASE LINK
command for information on database links.
alias
A substitute name for the FROM
item containing the alias. Use an alias for brevity or to eliminate ambiguity for self-joins where the same table is scanned multiple times. Providing an alias completely hides the name of the table or function. For example, given FROM foo AS f
, the remainder of the SELECT
must refer to this FROM
item as f
, not foo
.
select
A sub-SELECT
can appear in the FROM
clause. This acts as though its output were created as a temporary table for the duration of this single SELECT
command. Surround the sub-SELECT
with parentheses, and provide an alias for it.
join_type
One of the following:
[ INNER ] JOIN
LEFT [ OUTER ] JOIN
RIGHT [ OUTER ] JOIN
FULL [ OUTER ] JOIN
CROSS JOIN
For the INNER
and OUTER
join types, you must specify a join condition, namely one of NATURAL
, ON join_condition
, or USING (join_column [, ...] )
. For CROSS JOIN
, you can't use any of these clauses.
A JOIN
clause combines two FROM
items. Use parentheses to determine the order of nesting. Without parentheses, JOINs
nest left-to-right. In any case JOIN
binds more tightly than the commas separating FROM
items.
CROSS JOIN
and INNER JOIN
produce a simple Cartesian product, the same result that you get from listing the two items at the top level of FROM
but restricted by any join condition. CROSS JOIN
is equivalent to INNER JOIN ON (TRUE)
, that is, no rows are removed by qualification. These join types are a notational convenience, since you can accomplish the same thing using FROM
and WHERE
.
LEFT OUTER JOIN
returns all rows in the qualified Cartesian product, that is, all combined rows that pass its join condition. It also returns one copy of each row in the left-hand table for which there was no right-hand row that passed the join condition. This left-hand row is extended to the full width of the joined table by inserting null values for the right-hand columns. Only the JOIN
clause’s own condition is considered while deciding which rows have matches. Outer conditions are applied afterwards.
Conversely, RIGHT OUTER JOIN
returns all the joined rows plus one row for each unmatched right-hand row extended with nulls on the left. This is a notational convenience, since you can convert it to a LEFT OUTER JOIN
by switching the left and right inputs.
FULL OUTER JOIN
returns all the joined rows, one row for each unmatched left-hand row extended with nulls on the right, and one row for each unmatched right-hand row extended with nulls on the left.
ON join_condition
join_condition
is an expression resulting in a value of type BOOLEAN
(similar to a WHERE
clause) that specifies the rows in a join that are considered to match.
USING (join_column [, ...] )
A clause of the form USING (a, b, ... )
is shorthand for ON left_table.a = right_table.a AND left_table.b = right_table.b ....
Also, USING
implies that only one of each pair of equivalent columns is included in the join output, not both.
NATURAL
NATURAL
is shorthand for a USING
list that mentions all columns in the two tables that have the same names.
If you specify multiple sources, the result is the Cartesian product (cross join) of all the sources. Usually qualification conditions are added to restrict the returned rows to a small subset of the Cartesian product.
Example
This example selects all of the entries from the dept
table:
WHERE clause
The optional WHERE
clause has the form:
where condition
is any expression that evaluates to a result of type BOOLEAN
. Any row that doesn't satisfy this condition is eliminated from the output. A row satisfies the condition if it returns TRUE
when the actual row values are substituted for any variable references.
Example
This example joins the contents of the emp
and dept
tables. The value of the deptno
column in the emp
table is equal to the value of the deptno
column in the deptno
table.
GROUP BY clause
The optional GROUP BY
clause has the form: