SELECT v11
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 more than one element is specified in theFROM
list, they are cross-joined together. (SeeFROM
clause, below.) - If the
WHERE
clause is specified, all rows that do not satisfy the condition are eliminated from the output. (SeeWHERE
clause, below.) - If the
GROUP BY
clause is specified, the output is divided into groups of rows that match on one or more values. If theHAVING
clause is present, it eliminates groups that do not satisfy the given condition. (SeeGROUP BY
clause andHAVING
clause below.) - Using the operators
UNION
,INTERSECT
, andMINUS
, the output of more than oneSELECT
statement can be combined 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, ifALL
is specified then duplicates are not eliminated. (SeeUNION
clause,INTERSECT
clause, andMINUS
clause below.) - The actual output rows are computed using the
SELECT
output expressions for each selected row. (SeeSELECT
list below.) - 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 the
ORDER BY
clause is specified, the returned rows are sorted in the specified order. IfORDER BY
is not given, the rows are returned in whatever order the system finds fastest to produce. (SeeORDER BY clause
below.) DISTINCT
eliminates duplicate rows from the result.ALL
(the default) will return all candidate rows, including duplicates. (SeeDISTINCT
clause below.)- The
FOR UPDATE
clause causes theSELECT
statement to lock the selected rows against concurrent updates. (SeeFOR UPDATE
clause below.)
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 selection of an execution plan. See Database Compatibility for Oracle Developers Guide 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. An alias is used for brevity or to eliminate ambiguity for self-joins (where the same table is scanned multiple times). When an alias is provided, it completely hides the actual 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. Note that the sub-SELECT
must be surrounded by parentheses, and an alias must be provided 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, a join condition must be specified, namely exactly one of NATURAL
, ON join_condition
, or USING (join_column [, ...] )
. See below for the meaning. For CROSS JOIN
, none of these clauses may appear.
A JOIN
clause combines two FROM
items. Use parentheses if necessary to determine the order of nesting. In the absence of 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 as you get from listing the two items at the top level of FROM
, but restricted by the join condition (if any). CROSS JOIN
is equivalent to INNER JOIN ON (TRUE)
, that is, no rows are removed by qualification. These join types are just a notational convenience, since they do nothing you couldn’t do with plain FROM
and WHERE
.
LEFT OUTER JOIN
returns all rows in the qualified Cartesian product (i.e., all combined rows that pass its join condition), plus 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. Note that 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 just a notational convenience, since you could convert it to a LEFT OUTER JOIN
by switching the left and right inputs.
FULL OUTER JOIN
returns all the joined rows, plus one row for each unmatched left-hand row (extended with nulls on the right), plus 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 which rows in a join 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 will be 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 multiple sources are specified, 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
The following 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 does not satisfy this condition will be 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
The following example joins the contents of the emp
and dept
tables, WHERE
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:
GROUP BY
will condense into a single row all selected rows that share the same values for the grouped expressions. expression
can be an input column name, or the name or ordinal number of an output column (SELECT
list item), or an arbitrary expression formed from input-column values. In case of ambiguity, a GROUP BY
name will be interpreted as an input-column name rather than an output column name.
ROLLUP
, CUBE
, and GROUPING SETS
are extensions to the GROUP BY
clause for supporting multidimensional analysis.
Aggregate functions, if any are used, are computed across all rows making up each group, producing a separate value for each group (whereas without GROUP BY
, an aggregate produces a single value computed across all the selected rows). When GROUP BY
is present, it is not valid for the SELECT
list expressions to refer to ungrouped columns except within aggregate functions, since there would be more than one possible value to return for an ungrouped column.
Example
The following example computes the sum of the sal
column in the emp
table, grouping the results by department number:
HAVING Clause
The optional HAVING
clause has the form:
where condition
is the same as specified for the WHERE
clause.
HAVING
eliminates group rows that do not satisfy the specified condition. HAVING
is different from WHERE; WHERE
filters individual rows before the application of GROUP BY
, while HAVING
filters group rows created by GROUP BY
. Each column referenced in condition must unambiguously reference a grouping column, unless the reference appears within an aggregate function.
Example
To sum the column, sal
of all employees, group the results by department number and show those group totals that are less than 10000:
SELECT List
The SELECT
list (between the key words SELECT
and FROM
) specifies expressions that form the output rows of the SELECT
statement. The expressions can (and usually do) refer to columns computed in the FROM
clause. Using the clause AS output_name
, another name can be specified for an output column. This name is primarily used to label the column for display. It can also be used to refer to the column’s value in ORDER BY
and GROUP BY
clauses, but not in the WHERE
or HAVING
clauses; there you must write out the expression instead.
Instead of an expression, * can be written in the output list as a shorthand for all the columns of the selected rows.
Example
The SELECT
list in the following example specifies that the result set should include the empno
column, the ename
column, the mgr
column and the hiredate
column:
UNION Clause
The UNION
clause has the form:
select_statement
is any SELECT
statement without an ORDER BY
or FOR UPDATE
clause. (ORDER BY
can be attached to a sub-expression if it is enclosed in parentheses. Without parentheses, these clauses will be taken to apply to the result of the UNION
, not to its right-hand input expression.)
The UNION
operator computes the set union of the rows returned by the involved SELECT
statements. A row is in the set union of two result sets if it appears in at least one of the result sets. The two SELECT
statements that represent the direct operands of the UNION
must produce the same number of columns, and corresponding columns must be of compatible data types.
The result of UNION
does not contain any duplicate rows unless the ALL
option is specified. ALL
prevents elimination of duplicates.
Multiple UNION
operators in the same SELECT
statement are evaluated left to right, unless otherwise indicated by parentheses.
Currently, FOR UPDATE
may not be specified either for a UNION
result or for any input of a UNION
.
INTERSECT Clause
The INTERSECT
clause has the form:
select_statement
is any SELECT
statement without an ORDER BY
or FOR UPDATE
clause.
The INTERSECT
operator computes the set intersection of the rows returned by the involved SELECT
statements. A row is in the intersection of two result sets if it appears in both result sets.
The result of INTERSECT
does not contain any duplicate rows.
Multiple INTERSECT
operators in the same SELECT
statement are evaluated left to right, unless parentheses dictate otherwise. INTERSECT
binds more tightly than UNION
. That is, A UNION B INTERSECT C
will be read as A UNION (B INTERSECT C)
.
MINUS Clause
The MINUS
clause has this general form:
select_statement
is any SELECT
statement without an ORDER BY
or FOR UPDATE
clause.
The MINUS
operator computes the set of rows that are in the result of the left SELECT
statement but not in the result of the right one.
The result of MINUS
does not contain any duplicate rows.
Multiple MINUS
operators in the same SELECT
statement are evaluated left to right, unless parentheses dictate otherwise. MINUS
binds at the same level as UNION
.
CONNECT BY Clause
The CONNECT BY
clause determines the parent-child relationship of rows when performing a hierarchical query. It has the general form:
parent_expr
is evaluated on a candidate parent row. If parent_expr = child_expr
results in TRUE
for a row returned by the FROM
clause, then this row is considered a child of the parent.
The following optional clauses may be specified in conjunction with the CONNECT BY
clause:
START WITH start_expression
The rows returned by the FROM
clause on which start_expression
evaluates to TRUE
become the root nodes of the hierarchy.
ORDER SIBLINGS BY expression [ ASC | DESC ] [, ...]
Sibling rows of the hierarchy are ordered by expression
in the result set.
Note
Advanced Server does not support the use of AND
(or other operators) in the CONNECT BY
clause.
ORDER BY Clause
The optional ORDER BY
clause has the form:
expression
can be the name or ordinal number of an output column (SELECT
list item), or it can be an arbitrary expression formed from input-column values.
The ORDER BY
clause causes the result rows to be sorted according to the specified expressions. If two rows are equal according to the leftmost expression, they are compared according to the next expression and so on. If they are equal according to all specified expressions, they are returned in an implementation-dependent order.
The ordinal number refers to the ordinal (left-to-right) position of the result column. This feature makes it possible to define an ordering on the basis of a column that does not have a unique name. This is never absolutely necessary because it is always possible to assign a name to a result column using the AS
clause.
It is also possible to use arbitrary expressions in the ORDER BY
clause, including columns that do not appear in the SELECT
result list. Thus the following statement is valid:
A limitation of this feature is that an ORDER BY
clause applying to the result of a UNION
, INTERSECT
, or MINUS
clause may only specify an output column name or number, not an expression.
If an ORDER BY
expression is a simple name that matches both a result column name and an input column name, ORDER BY
will interpret it as the result column name. This is the opposite of the choice that GROUP BY
will make in the same situation. This inconsistency is made to be compatible with the SQL standard.
Optionally one may add the key word ASC
(ascending) or DESC
(descending) after any expression in the ORDER BY
clause. If not specified, ASC
is assumed by default.
The null value sorts higher than any other value. In other words, with ascending sort order, null values sort at the end, and with descending sort order, null values sort at the beginning.
Character-string data is sorted according to the locale-specific collation order that was established when the database cluster was initialized.
Note
If SELECT DISTINCT
is specified or if a SELECT
statement includes the SELECT DISTINCT ...ORDER BY
clause then all the expressions in ORDER BY
must be present in the select list of the SELECT DISTINCT
query.
Examples
The following two examples are identical ways of sorting the individual results according to the contents of the second column (dname
):
The following example uses the SELECT DISTINCT ...ORDER BY
clause to fetch the job
and deptno
from table emp
:
DISTINCT Clause
If a SELECT
statement specifies DISTINCT
, all duplicate rows are removed from the result set (one row is kept from each group of duplicates). The ALL
keyword specifies the opposite: all rows are kept; that is the default.
FOR UPDATE Clause
The FOR UPDATE
clause takes the form:
FOR UPDATE
causes the rows retrieved by the SELECT
statement to be locked as though for update. This prevents a row from being modified or deleted by other transactions until the current transaction ends; any transaction that attempts to UPDATE
, DELETE
, or SELECT FOR UPDATE
a selected row will be blocked until the current transaction ends. If an UPDATE
, DELETE
, or SELECT FOR UPDATE
from another transaction has already locked a selected row or rows, SELECT FOR UPDATE
will wait for the first transaction to complete, and will then lock and return the updated row (or no row, if the row was deleted).
FOR UPDATE
cannot be used in contexts where returned rows cannot be clearly identified with individual table rows (for example, with aggregation).
Use FOR UPDATE
options to specify locking preferences:
- Include the
WAIT n
keywords to specify the number of seconds (or fractional seconds) that theSELECT
statement will wait for a row locked by another session. Use a decimal form to specify fractional seconds; for example,WAIT 1.5
instructs the server to wait one and a half seconds. Specify up to4
digits to the right of the decimal. - Include the
NOWAIT
keyword to report an error immediately if a row cannot be locked by the current session. - Include
SKIP LOCKED
to instruct the server to lock rows if possible, and skip rows that are already locked by another session.