Skip Headers

Oracle9i SQL Reference
Release 2 (9.2)

Part Number A96540-02
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page Go to next page
View PDF

SELECT

Purpose

Use a SELECT statement or subquery to retrieve data from one or more tables, object tables, views, object views, or materialized views.


Note:

If the result (or part of the result) of a SELECT statement is equivalent to an existing materialized view, then Oracle may use the materialized view in place of one or more tables specified in the SELECT statement. This substitution is called query rewrite, and takes place only if cost optimization is enabled and the QUERY_REWRITE_ENABLED parameter is set to TRUE. To determine whether query write has occurred, use the EXPLAIN PLAN statement.


See Also:

Additional Topics

Prerequisites

For you to select data from a table or materialized view, the table or materialized view must be in your own schema or you must have the SELECT privilege on the table or materialized view.

For you to select rows from the base tables of a view,

The SELECT ANY TABLE system privilege also allows you to select data from any table or any materialized view or any view's base table.

To issue a flashback query (using the flashback_clause), either you must have FLASHBACK object privilege on the objects in the select list, or you must have FLASHBACK ANY TABLE system privilege.

Syntax

select::=

Text description of statements_1012.gif follows
Text description of select


(for_update_clause::=)

subquery::=

Text description of statements_1013.gif follows
Text description of subquery


(subquery_factoring_clause::=, select_list::=, table_reference::=, hierarchical_query_clause::=, group_by_clause::=, order_by_clause::=)

subquery_factoring_clause::=

Text description of statements_10a.gif follows
Text description of subquery_factoring_clause


select_list::=

Text description of statements_1031a.gif follows
Text description of select_list


table_reference::=

Text description of statements_1011.gif follows
Text description of table_reference


(query_table_expression::=, flashback_clause::=)

flashback_clause::=

Text description of statements_1033.gif follows
Text description of flashback_clause


query_table_expression::=

Text description of statements_1014.gif follows
Text description of query_table_expression


(subquery_restriction_clause::=, table_collection_expression::=)

sample_clause::=

Text description of statements_1015.gif follows
Text description of sample_clause


subquery_restriction_clause::=

Text description of statements_1016.gif follows
Text description of subquery_restriction_clause


table_collection_expression::=

Text description of statements_1017.gif follows
Text description of table_collection_expression


joined_table::=

Text description of statements_1032b.gif follows
Text description of joined_table


(table_reference::=)

join_type::=

Text description of statements_1010.gif follows
Text description of join_type


where_clause::=

Text description of where_clause.gif follows
Text description of where_clause


hierarchical_query_clause::=

Text description of statements_1018.gif follows
Text description of hierarchical_query_clause


group_by_clause::=

Text description of statements_1029.gif follows
Text description of group_by_clause


(rollup_cube_clause::=, grouping_sets_clause::=)

rollup_cube_clause::=

Text description of statements_1030a.gif follows
Text description of rollup_cube_clause


(grouping_expression_list::=)

grouping_sets_clause::=

Text description of statements_109.gif follows
Text description of grouping_sets_clause


(rollup_cube_clause::=, grouping_expression_list::=)

grouping_expression_list::=

Text description of statements_1031.gif follows
Text description of grouping_expression_list


expression_list::=

Text description of statements_1032.gif follows
Text description of expression_list


order_by_clause::=

Text description of statements_1020.gif follows
Text description of order_by_clause


for_update_clause::=

Text description of statements_1021.gif follows
Text description of for_update_clause


Semantics

subquery_factoring_clause

The subquery_factoring_clause (WITH query_name) lets you assign names to subquery blocks. You can then reference the subquery block multiple places in the query by specifying the query name. Oracle optimizes the query by treating the query name as either an inline view or as a temporary table.

You can specify this clause in any top-level SELECT statement and in most types of subqueries. The query name is visible to all subsequent subqueries (except the subquery that defines the query name itself) and to the main query.

Restrictions on Subquery Factoring

hint

Specify a comment that passes instructions to the optimizer on choosing an execution plan for the statement.

See Also:

"Hints" and Oracle9i Database Performance Tuning Guide and Reference for the syntax and description of hints

DISTINCT | UNIQUE

Specify DISTINCT or UNIQUE if you want Oracle to return only one copy of each set of duplicate rows selected (these two keywords are synonymous). Duplicate rows are those with matching values for each expression in the select list.

Restrictions on DISTINCT and UNIQUE Queries

ALL

Specify ALL if you want Oracle to return all rows selected, including all copies of duplicates. The default is ALL.

* (asterisk)

Specify the asterisk to select all columns from all tables, views, or materialized views listed in the FROM clause.


Note:

If you are selecting from a table (that is, you specify a table in the FROM clause rather than a view or a materialized view), then then columns that have been marked as UNUSED by the ALTER TABLE SET UNUSED statement are not selected.


See Also:

ALTER TABLE, "Simple Query Examples", and "Selecting from the DUAL Table: Example"

select_list

The select_list lets you specify the columns you want to retrieve from the database.

query_name

For query_name, specify a name already specified in the subquery_factoring_clause. You must have specified the subquery_factoring_clause in order to specify query_name in the select_list. If you specify query_name in the select_list, then you also must specify query_name in the query_table_expression (FROM clause).

table.* | view.* | materialized view.*

Specify the object name followed by a period and the asterisk to select all columns from the specified table, view, or materialized view. A query that selects rows from two or more tables, views, or materialized views is a join.

You can use the schema qualifier to select from a table, view, or materialized view in a schema other than your own. If you omit schema, then Oracle assumes the table, view, or materialized view is in your own schema.

See Also:

"Joins"

expr

Specify an expression representing the information you want to select. A column name in this list can be qualified with schema only if the table, view, or materialized view containing the column is qualified with schema in the FROM clause. If you specify a member method of an object type, then you must follow the method name with parentheses even if the method takes no arguments.

See Also:

"Selecting Sequence Values: Examples"

c_alias

Specify a different name (alias) for the column expression. Oracle will use this alias in the column heading. The AS keyword is optional. The alias effectively renames the select list item for the duration of the query. The alias can be used in the order_by_clause, but not other clauses in the query.

See Also:
Restrictions on the Select List

FROM Clause

The FROM clause lets you specify the objects from which data is selected.

query_table_expression

Use the query_table_expression clause to identify a table, view, materialized view, or partition, or to specify a subquery that identifies the objects.

See Also:

"Using Subqueries: Examples"

ONLY

The ONLY clause applies only to views. Specify ONLY if the view in the FROM clause is a view belonging to a hierarchy and you do not want to include rows from any of its subviews.

flashback_clause

Use the flashback_clause to query past data from a table, view, or materialized view. If you specify SCN, then expr must evaluate to a number. If you specify TIMESTAMP, then expr must evaluate to a timestamp value. Oracle returns rows as they existed at the specified system change number or time.


Note:

This clause implements SQL-driven flashback, which lets you specify a different system change number or timestamp for each object in the select list. You can also implement session-level flashback using the DBMS_FLASHBACK package. For information on session-level flashback, please refer to Oracle9i Application Developer's Guide - Fundamentals and Oracle9i Supplied PL/SQL Packages and Types Reference.


Restrictions on Flashback Queries
PARTITION | SUBPARTITION

For PARTITION or SUBPARTITION, specify the name of the partition or subpartition within table from which you want to retrieve data.

For range- and list-partitioned data, as an alternative to this clause, you can specify a condition in the WHERE clause that restricts the retrieval to one or more partitions of table. Oracle will interpret the condition and fetch data from only those partitions. (It is not possible to formulate such a WHERE condition for hash-partitioned data.)

See Also:

"Selecting from a Partition: Example"

dblink

For dblink, specify the complete or partial name for a database link to a remote database where the table, view, or materialized view is located. This database need not be an Oracle database.

See Also:

If you omit dblink, then Oracle assumes that the table, view, or materialized view is on the local database.

Restrictions on Database Links
table | view | materialized view

For table, view, or materialized view, specify the name of a table, view, or materialized view from which data is selected.

sample_clause

The sample_clause lets you instruct Oracle to select from a random sample of rows from the table, rather than from the entire table.

See Also:

"Selecting a Sample: Examples"

BLOCK

BLOCK instructs Oracle to perform random block sampling instead of random row sampling.

See Also:

Oracle9i Database Concepts for a discussion of the difference

sample_percent

sample_percent is a number specifying the percentage of the total row or block count to be included in the sample. The value must be in the range .000001 to (but not including) 100.

Restrictions on Sampling During Queries
subquery_restriction_clause

The subquery_restriction_clause lets you restrict the subquery in one of the following ways:

WITH READ ONLY

Specify WITH READ ONLY to indicate that the table or view cannot be updated.

WITH CHECK OPTION

Specify WITH CHECK OPTION to indicate that Oracle prohibits any changes to the table or view that would produce rows that are not included in the subquery.

CONSTRAINT constraint

Specify the name of the CHECK OPTION constraint. If you omit this identifier, Oracle automatically assigns the constraint a name of the form SYS_Cn, where n is an integer that makes the constraint name unique within the database.

See Also:

"Using the WITH CHECK OPTION Clause: Example"

table_collection_expression

The table_collection_expression lets you inform Oracle that the value of collection_expression should be treated as a table for purposes of query and DML operations. The collection_expression can be a subquery, a column, a function, or a collection constructor. Regardless of its form, it must return a collection value (that is, a value whose type is nested table or varray). This process of extracting the elements of a collection is called collection unnesting.


Note:

In earlier releases of Oracle, when collection_expression was a subquery, table_collection_expression was expressed as "THE subquery". That usage is now deprecated.


The collection_expression can reference columns of tables defined to its left in the FROM clause. This is called left correlation. Left correlation can occur only in table_collection_expression. Other subqueries cannot contains references to columns defined outside the subquery.

The optional "(+)" lets you specify that table_collection_expression should return a row with all fields set to NULL if the collection is null or empty. The "(+)" is valid only if collection_expression uses left correlation. The result is similar to that of an outer join.


Note:

When you use the "(+)" syntax in the WHERE clause of a subquery in an UPDATE or DELETE operation, you must specify two tables in the FROM clause of the subquery. Oracle ignores the outer join syntax unless there is a join in the subquery itself.


See Also:
t_alias

Specify a correlation name (alias) for the table, view, materialized view, or subquery for evaluating the query. Correlation names are most often used in a correlated query. Other references to the table, view, or materialized view throughout the query must refer to this alias.


Note:

This alias is required if the query_table_expr_clause references any object type attributes or object type methods.


See Also:

"Using Correlated Subqueries: Examples"

joined_table

Use the joined_table syntax to identify tables that are part of a join from which to select data.

See Also:

"Joins" for more information on joins, "Using Join Queries: Examples", "Using Self Joins: Example", and "Using Outer Joins: Examples"

join_type

The join_type indicates the kind of join being performed:

JOIN

The JOIN keyword explicitly states that a join is being performed. You can use this syntax to replace the comma-delimited table expressions used in WHERE clause joins with FROM clause join syntax.

ON condition

Use the ON clause to specify a join condition. Doing so lets you specify join conditions separate from any search or filter conditions in the WHERE clause.

USING column

When you are specifying an equijoin of columns that have the same name in both tables, the USING column clause indicates the columns to be used. You can use this clause only if the join columns in both tables have the same name. Do not qualify the column name with a table name or table alias.

In an outer join with the USING clause, the query returns a single column which is a coalesce of the two matching columns in the join. The coalesce functions as follows:

COALESCE (a, b) = a if a NOT NULL, else b.

Therefore:

Restriction on Columns Used in Joins

You cannot specify a LOB column or a collection column in the USING column clause.

See Also:

"Using Outer Joins: Examples"

CROSS JOIN

The CROSS keyword indicates that a cross join is being performed. A cross join produces the cross-product of two relations and is essentially the same as the comma-delimited Oracle notation.

NATURAL JOIN

The NATURAL keyword indicates that a natural join is being performed. A natural join is based on all columns in the two tables that have the same name. It selects rows from the two tables that have equal values in the relevant columns. When specifying columns that are involved in the natural join, do not qualify the column name with a table name or table alias.


Note:

On occasion, the table pairings in natural or cross joins may be ambiguous. For example:

   a NATURAL LEFT JOIN b LEFT JOIN c ON b.c1 = c.c1

can be interpreted in either of the following ways:

   a NATURAL LEFT JOIN (b LEFT JOIN c ON b.c1 = c.c1) 
  (a NATURAL LEFT JOIN b) LEFT JOIN c ON b.c1 = c.c1

To avoid this ambiguity, you can use parentheses to specify the pairings of joined tables. In the absence of such parentheses, Oracle uses left associativity, pairing the tables from left to right.


Restriction on Natural Joins

You cannot specify a LOB column, columns of AnyType, AnyData, or AnyDataSet, or a collection column as part of a natural join.

where_clause

The WHERE condition lets you restrict the rows selected to those that satisfy one or more conditions. For condition, specify any valid SQL condition.

If you omit this clause, then Oracle returns all rows from the tables, views, or materialized views in the FROM clause.


Note:

If this clause refers to a DATE column of a partitioned table or index, then Oracle performs partition pruning only if (1) you created the table or index partitions by fully specifying the year using the TO_DATE function with a 4-digit format mask, and (2) you specify the date in the query's where_clause using the TO_DATE function and either a 2- or 4-digit format mask.


See Also:

hierarchical_query_clause

The hierarchical_query_clause lets you select rows in a hierarchical order.

SELECT statements that contain hierarchical queries can contain the LEVEL pseudocolumn in the select list. LEVEL returns the value 1 for a root node, 2 for a child node of a root node, 3 for a grandchild, and so on. The number of levels returned by a hierarchical query may be limited by available user memory.

If you specify this clause, do not specify either ORDER BY or GROUP BY, as they will destroy the hierarchical order of the CONNECT BY results. If you want to order rows of siblings of the same parent, use the ORDER SIBLINGS BY clause.

See Also:

"Hierarchical Queries" for a discussion of hierarchical queries and "Using the LEVEL Pseudocolumn: Examples"

START WITH Clause

Specify a condition that identifies the row(s) to be used as the root(s) of a hierarchical query. Oracle uses as root(s) all rows that satisfy this condition. If you omit this clause, then Oracle uses all rows in the table as root rows. The START WITH condition can contain a subquery, but it cannot contain a scalar subquery expression.

CONNECT BY Clause

Specify a condition that identifies the relationship between parent rows and child rows of the hierarchy. The connect_by_condition can be any condition as described in Chapter 5, "Conditions". However, it must use the PRIOR operator to refer to the parent row.

Restriction on the CONNECT BY Clause

The connect_by_condition cannot contain a regular subquery or a scalar subquery expression.

See Also:
Notes on Hierarchical Queries

If you specify a hierarchical query and also specify the ORDER BY clause, then the ORDER BY clause takes precedence over any ordering specified by the hierarchical query, unless you specify the SIBLINGS keyword in the ORDER BY clause.

The manner in which Oracle processes a WHERE clause (if any) in a hierarchical query depends on whether the WHERE clause contains a join:

group_by_clause

Specify the GROUP BY clause if you want Oracle to group the selected rows based on the value of expr(s) for each row and return a single row of summary information for each group. If this clause contains CUBE or ROLLUP extensions, then Oracle produces superaggregate groupings in addition to the regular groupings.

Expressions in the GROUP BY clause can contain any columns of the tables, views, or materialized views in the FROM clause, regardless of whether the columns appear in the select list.

The GROUP BY clause groups rows but does not guarantee the order of the result set. To order the groupings, use the ORDER BY clause.

See Also:
ROLLUP

The ROLLUP operation in the simple_grouping_clause groups the selected rows based on the values of the first n, n-1, n-2, ... 0 expressions in the GROUP BY specification, and returns a single row of summary for each group. You can use the ROLLUP operation to produce subtotal values by using it with the SUM function. When used with SUM, ROLLUP generates subtotals from the most detailed level to the grand total. Aggregate functions such as COUNT can be used to produce other kinds of superaggregates.

For example, given three expressions (n=3) in the ROLLUP clause of the simple_grouping_clause, the operation results in n+1 = 3+1 = 4 groupings.

Rows grouped on the values of the first 'n' expressions are called regular rows, and the others are called superaggregate rows.

See Also:

Oracle9i Data Warehousing Guide for information on using ROLLUP with materialized views

CUBE

The CUBE operation in the simple_grouping_clause groups the selected rows based on the values of all possible combinations of expressions in the specification, and returns a single row of summary information for each group. You can use the CUBE operation to produce cross-tabulation values.

For example, given three expressions (n=3) in the CUBE clause of the simple_grouping_clause, the operation results in 2n = 23 = 8 groupings. Rows grouped on the values of 'n' expressions are called regular rows, and the rest are called superaggregate rows.

See Also:
GROUPING SETS

GROUPING SETS are a further extension of the GROUP BY clause that let you specify multiple groupings of data. Doing so facilitates efficient aggregation by pruning the aggregates you do not need. You specify just the desired groups, and Oracle does not need to perform the full set of aggregations generated by CUBE or ROLLUP. Oracle computes all groupings specified in the GROUPING SETS clause and combines the results of individual groupings with a UNION ALL operation. The UNION ALL means that the result set can include duplicate rows.

Within the GROUP BY clause, you can combine expressions in various ways:

HAVING Clause

Use the HAVING clause to restrict the groups of returned rows to those groups for which the specified condition is TRUE. If you omit this clause, then Oracle returns summary rows for all groups.

Specify GROUP BY and HAVING after the where_clause and hierarchical_query_clause. If you specify both GROUP BY and HAVING, then they can appear in either order.

Restriction on the HAVING Clause

The HAVING condition cannot contain a scalar subquery expression.

See Also:

"Using the HAVING Condition: Example"

Restrictions on the GROUP BY Clause:

The expressions can be of any form except scalar subquery expressions.

Set Operators: UNION, UNION ALL, INTERSECT, MINUS

These set operators combine the rows returned by two SELECT statements into a single result. The number and datatypes of the columns selected by each component query must be the same, but the column lengths can be different. The names of the columns in the result set are the names of the expressions in the select list preceding the set operator.

If you combine more than two queries with set operators, then Oracle evaluates adjacent queries from left to right. You can use parentheses to specify a different order of evaluation.

See Also:

"The UNION [ALL], INTERSECT, MINUS Operators" for information on these operators

Restrictions on Set Operators

order_by_clause

Use the ORDER BY clause to order rows returned by the statement. Without an order_by_clause, no guarantee exists that the same query executed more than once will retrieve rows in the same order.

SIBLINGS

The SIBLINGS keyword is valid only if you also specify the hierarchical_query_clause (CONNECT BY). ORDER SIBLINGS BY preserves any ordering specified in the hierarchical query clause and then applies the order_by_clause to the siblings of the hierarchy.

expr

expr orders rows based on their value for expr. The expression is based on columns in the select list or columns in the tables, views, or materialized views in the FROM clause.

position

Specify position to order rows based on their value for the expression in this position of the select list; position must be an integer.

See Also:

"Sorting Query Results" for a discussion of ordering query results

You can specify multiple expressions in the order_by_clause. Oracle first sorts rows based on their values for the first expression. Rows with the same value for the first expression are then sorted based on their values for the second expression, and so on. Oracle sorts nulls following all others in ascending order and preceding all others in descending order.

ASC | DESC

Specify whether the ordering sequence is ascending or descending. ASC is the default.

NULLS FIRST | NULLS LAST

Specify whether returned rows containing null values should appear first or last in the ordering sequence.

NULLS LAST is the default for ascending order, and NULLS FIRST is the default for descending order.

Restrictions on the ORDER BY Clause

for_update_clause

The FOR UPDATE clause lets you lock the selected rows so that other users cannot lock or update the rows until you end your transaction. You can specify this clause only in a top-level SELECT statement (not in subqueries).


Note:

Prior to updating a LOB value, you must lock the row containing the LOB. One way to lock the row is with an embedded SELECT ... FOR UPDATE statement. You can do this using one of the programmatic languages or DBMS_LOB package. For more information on lock rows before writing to a LOB, see Oracle9i Application Developer's Guide - Large Objects (LOBs).


Nested table rows are not locked as a result of locking the parent table rows. If you want the nested table rows to be locked, then you must lock them explicitly.

Restrictions on the FOR UPDATE Clause
OF ... column

Use the OF ... column clause to lock the select rows only for a particular table or view in a join. The columns in the OF clause only indicate which table or view rows are locked. The specific columns that you specify are not significant. However, you must specify an actual column name, not a column alias. If you omit this clause, then Oracle locks the selected rows from all the tables in the query.

NOWAIT | WAIT

The NOWAIT and WAIT clauses let you tell Oracle how to proceed if the SELECT statement attempts to lock a row that is locked by another user.

NOWAIT

Specify NOWAIT to return control to you immediately if a lock exists.

WAIT

Specify WAIT to instruct Oracle to wait integer seconds for the row to become available, and then return control to you.

If you specify neither WAIT nor NOWAIT, then Oracle waits until the row is available and then returns the results of the SELECT statement.

Examples

Subquery Factoring: Example

The following statement creates the query names dept_costs and avg_cost for the initial query block containing a join, and then uses the query names in the body of the main query.

WITH 
   dept_costs AS (
      SELECT department_name, SUM(salary) dept_total
         FROM employees e, departments d
         WHERE e.department_id = d.department_id
      GROUP BY department_name),
   avg_cost AS (
      SELECT SUM(dept_total)/COUNT(*) avg
      FROM dept_costs)
SELECT * FROM dept_costs
   WHERE dept_total >
      (SELECT avg FROM avg_cost)
      ORDER BY department_name;

DEPARTMENT_NAME                DEPT_TOTAL
------------------------------ ----------
Sales                              313800
Shipping                           156400
Simple Query Examples

The following statement selects rows from the employees table with the department number of 30:

SELECT * 
   FROM employees 
   WHERE department_id = 30;

The following statement selects the name, job, salary and department number of all employees except purchase clerks from department number 30:

SELECT last_name, job_id, salary, department_id 
   FROM employees 
   WHERE NOT (job_id = 'PU_CLERK' AND department_id = 30); 

The following statement selects from subqueries in the FROM clause and gives departments' total employees and salaries as a decimal value of all the departments:

SELECT a.department_id "Department",
   a.num_emp/b.total_count "%_Employees",
   a.sal_sum/b.total_sal "%_Salary"
FROM
(SELECT department_id, COUNT(*) num_emp, SUM(salary) sal_sum
   FROM employees
   GROUP BY department_id) a,
(SELECT COUNT(*) total_count, SUM(salary) total_sal
   FROM employees) b;

Selecting from a Partition: Example

You can select rows from a single partition of a partitioned table by specifying the keyword PARTITION in the FROM clause. This SQL statement assigns an alias for and retrieves rows from the sales_q2_2000 partition of the sample table sh.sales:

SELECT * FROM sales PARTITION (sales_q2_2000) s
   WHERE s.amount_sold > 10000;

The following example selects rows from the oe.orders table for orders earlier 
than a specified date: SELECT * FROM orders
   WHERE order_date < TO_DATE('2000-06-15', 'YYYY-MM-DD');
Selecting a Sample: Examples

The following query estimates the number of orders in the oe.orders table:

SELECT COUNT(*) * 100 FROM orders SAMPLE (1);

The following example creates a sampled subset of the sample table hr.employees table and then joins the resulting sampled table with departments. This operation circumvents the restriction that you cannot specify the sample_clause in join queries:

CREATE TABLE sample_emp AS 
   SELECT employee_id, department_id FROM employees SAMPLE(10);

SELECT e.employee_id FROM sample_emp e, departments d 
   WHERE e.department_id = d.department_id 
   AND d.department_name = 'Sales';
Using Flashback Queries: Example

The following statements show a current value from the sample table hr.employees and then changes the value:

SELECT salary FROM employees
   WHERE last_name = 'Chung';
   
    SALARY
----------
      3800

UPDATE employees SET salary = 4000
   WHERE last_name = 'Chung';
1 row updated.

SELECT salary FROM employees
   WHERE last_name = 'Chung';

    SALARY
----------
      4000

To learn what the value was before the update, you can use the following flashback query:

SELECT salary FROM employees
   AS OF TIMESTAMP (SYSTIMESTAMP - INTERVAL '1' DAY)
   WHERE last_name = 'Chung';
   
    SALARY
----------
      3800

To revert to the earlier value, use the flashback query as the subquery of another UPDATE statement:

UPDATE employees SET salary =      
   (SELECT salary FROM employees
   AS OF TIMESTAMP (SYSTIMESTAMP - INTERVAL '1' DAY)
   WHERE last_name = 'Chung')
   WHERE last_name = 'Chung';
1 row updated.

SELECT salary FROM employees
   WHERE last_name = 'Chung';
   
    SALARY
----------
      3800
Using the GROUP BY Clause: Examples

To return the minimum and maximum salaries for each department in the employees table, issue the following statement:

SELECT department_id, MIN(salary), MAX (salary)
     FROM employees
     GROUP BY department_id;

To return the minimum and maximum salaries for the clerks in each department, issue the following statement:

SELECT department_id, MIN(salary), MAX (salary)
     FROM employees
     WHERE job_id = 'PU_CLERK'
     GROUP BY department_id;
Using the GROUP BY CUBE Clause: Example

To return the number of employees and their average yearly salary across all possible combinations of department and job category, issue the following query on the sample tables hr.employees and hr.departments:

SELECT DECODE(GROUPING(department_name), 1, 'All Departments',
      department_name) AS department_name,
   DECODE(GROUPING(job_id), 1, 'All Jobs', job_id) AS job_id,
   COUNT(*) "Total Empl", AVG(salary) * 12 "Average Sal"
   FROM employees e, departments d
   WHERE d.department_id = e.department_id
   GROUP BY CUBE (department_name, job_id);

DEPARTMENT_NAME                JOB_ID     Total Empl Average Sal
------------------------------ ---------- ---------- -----------
Accounting                     AC_ACCOUNT          1       99600
Accounting                     AC_MGR              1      144000
Accounting                     All Jobs            2      121800
Administration                 AD_ASST             1       52800
.
.
.
All Departments                ST_MAN              5       87360
All Departments                All Jobs          107  77798.1308
Using the GROUPING SETS Clause: Example

The following example finds the sum of sales aggregated for three precisely specified groups:

Without the GROUPING SETS syntax, you would have to write less efficient queries with more complicated SQL. For example, you could run three separate queries and UNION them, or run a query with a CUBE(channel_desc, calendar_month_desc, country_id) operation and filter out 5 of the 8 groups it would generate.

SELECT channel_desc, calendar_month_desc, co.country_id,
      TO_CHAR(sum(amount_sold) , '9,999,999,999') SALES$
   FROM sales, customers, times, channels, countries co
   WHERE sales.time_id=times.time_id 
      AND sales.cust_id=customers.cust_id 
      AND sales.channel_id= channels.channel_id 
      AND customers.country_id = co.country_id
      AND channels.channel_desc IN ('Direct Sales', 'Internet') 
      AND times.calendar_month_desc IN ('2000-09', '2000-10')
      AND co.country_id IN ('UK', 'US')
  GROUP BY GROUPING SETS( 
      (channel_desc, calendar_month_desc, co.country_id), 
      (channel_desc, co.country_id), 
      ( calendar_month_desc, co.country_id) );

CHANNEL_DESC         CALENDAR CO SALES$
-------------------- -------- -- --------------
Direct Sales         2000-09  UK      1,378,126
Direct Sales         2000-10  UK      1,388,051
Direct Sales         2000-09  US      2,835,557
Direct Sales         2000-10  US      2,908,706
Internet             2000-09  UK        911,739
Internet             2000-10  UK        876,571
Internet             2000-09  US      1,732,240
Internet             2000-10  US      1,893,753
Direct Sales                  UK      2,766,177
Direct Sales                  US      5,744,263
Internet                      UK      1,788,310
Internet                      US      3,625,993
                     2000-09  UK      2,289,865
                     2000-09  US      4,567,797
                     2000-10  UK      2,264,622
                     2000-10  US      4,802,459
See Also:

the functions GROUP_ID, GROUPING, and GROUPING_ID for more information on those functions

Hierarchical Query Examples

The following query with a CONNECT BY clause defines a hierarchical relationship in which the employee_id value of the parent row is equal to the manager_id value of the child row:

SELECT last_name, employee_id, manager_id FROM employees
   CONNECT BY employee_id = manager_id;

In the following CONNECT BY clause, the PRIOR operator applies only to the employee_id value. To evaluate this condition, Oracle evaluates employee_id values for the parent row and manager_id, salary, and commission_pct values for the child row:

SELECT last_name, employee_id, manager_id FROM employees
   CONNECT BY PRIOR employee_id = manager_id
   AND salary > commission_pct; 

To qualify as a child row, a row must have a manager_id value equal to the employee_id value of the parent row and it must have a salary value greater than its commission_pct value.

Using the HAVING Condition: Example

To return the minimum and maximum salaries for the employees in each department whose lowest salary is less than $5,000, issue the next statement:

SELECT department_id, MIN(salary), MAX (salary)
   FROM employees
   GROUP BY department_id
   HAVING MIN(salary) < 5000;

DEPARTMENT_ID MIN(SALARY) MAX(SALARY)
------------- ----------- -----------
           10        4400        4400
           30        2500       11000
           50        2100        8200
           60        4200        9000
Using the ORDER BY Clause: Examples

To select all salesmen's records from employees, and order the results by commission in descending order, issue the following statement:

SELECT * 
   FROM employees
   WHERE job_id = 'PU_CLERK' 
   ORDER BY commission_pct DESC; 

To select information from employees ordered first by ascending department number and then by descending salary, issue the following statement:

SELECT last_name, department_id, salary
   FROM employees
   ORDER BY department_id ASC, salary DESC; 

To select the same information as the previous SELECT and use the positional ORDER BY notation, issue the following statement:

SELECT last_name, department_id, salary 
   FROM employees 
   ORDER BY 2 ASC, 3 DESC; 
Using the FOR UPDATE Clause: Examples

The following statement locks rows in the employees table with purchasing clerks located in Oxford (location_id 2500) and locks rows in the departments table with departments in Oxford that have purchasing clerks:

SELECT e.employee_id, e.salary, e.commission_pct
   FROM employees e, departments d
   WHERE job_id = 'SA_REP'
   AND e.department_id = d.department_id
   AND location_id = 2500
   FOR UPDATE;

The following statement locks only those rows in the employees table with purchasing clerks located in Oxford (location_id 2500). No rows are locked in the departments table:

SELECT e.employee_id, e.salary, e.commission_pct
   FROM employees e, departments d
   WHERE job_id = 'SA_REP'
   AND e.department_id = d.department_id
   AND location_id = 2500
   FOR UPDATE OF e.salary;
Using the WITH CHECK OPTION Clause: Example

The following statement is legal even though the third value inserted violates the condition of the subquery where_clause:

INSERT INTO (SELECT department_id, department_name, location_id
   FROM departments WHERE location_id < 2000)
   VALUES (9999, 'Entertainment', 2500);

However, the following statement is illegal because it contains the WITH CHECK OPTION clause:

INSERT INTO (SELECT department_id, department_name, location_id
   FROM departments WHERE location_id < 2000 WITH CHECK OPTION)
   VALUES (9999, 'Entertainment', 2500);
     *
ERROR at line 2:
ORA-01402: view WITH CHECK OPTION where-clause violation
Using Join Queries: Examples

The following examples show various ways of joining tables in a query. In the first example, an equijoin returns the name and job of each employee and the number and name of the department in which the employee works:

SELECT last_name, job_id, departments.department_id, department_name
   FROM employees, departments
   WHERE employees.department_id = departments.department_id;

LAST_NAME           JOB_ID     DEPARTMENT_ID DEPARTMENT_NAME
------------------- ---------- ------------- ----------------------
...
Sciarra             FI_ACCOUNT           100 Finance
Urman               FI_ACCOUNT           100 Finance
Popp                FI_ACCOUNT           100 Finance
...

You must use a join to return this data because employee names and jobs are stored in a different table than department names. Oracle combines rows of the two tables according to this join condition:

employees.department_id = departments.department_id 

The following equijoin returns the name, job, department number, and department name of all sales managers:

SELECT last_name, job_id, departments.department_id, department_name
   FROM employees, departments
   WHERE employees.department_id = departments.department_id
   AND job_id = 'SA_MAN';

LAST_NAME           JOB_ID     DEPARTMENT_ID DEPARTMENT_NAME
------------------- ---------- ------------- -----------------------
Russell             SA_MAN                80 Sales
Partners            SA_MAN                80 Sales
Errazuriz           SA_MAN                80 Sales
Cambrault           SA_MAN                80 Sales
Zlotkey             SA_MAN                80 Sales

This query is identical to the preceding example, except that it uses an additional where_clause condition to return only rows with a job value of 'SA_MAN'.

Using Subqueries: Examples

To determine who works in the same department as employee 'Lorentz', issue the following statement:

SELECT last_name, department_id FROM employees
   WHERE department_id =
     (SELECT department_id FROM employees
      WHERE last_name = 'Lorentz'); 

To give all employees in the employees table a 10% raise if they have changed jobs (that is, if they appear in the job_history table), issue the following statement:

UPDATE employees 
    SET salary = salary * 1.1
    WHERE employee_id IN (SELECT employee_id FROM job_history);

To create a second version of the departments table new_departments, with only three of the columns of the original table, issue the following statement:

CREATE TABLE new_departments 
   (department_id, department_name, location_id)
   AS SELECT department_id, department_name, location_id 
   FROM departments; 
Using Self Joins: Example

The following query uses a self join to return the name of each employee along with the name of the employee's manager. (A WHERE clause is added to shorten the output.)

SELECT e1.last_name||' works for '||e2.last_name 
   "Employees and Their Managers"
   FROM employees e1, employees e2 
   WHERE e1.manager_id = e2.employee_id
      AND e1.last_name LIKE 'R%';

Employees and Their Managers   
-------------------------------
Rajs works for Mourgos
Raphaely works for King
Rogers works for Kaufling
Russell works for King

The join condition for this query uses the aliases e1 and e2 for the sample table employees:

e1.manager_id = e2.employee_id
Using Outer Joins: Examples

The following example uses a left outer join to return the names of all departments in the sample schema hr, even if no employees have been assigned to the departments:

SELECT d.department_id, e.last_name
   FROM departments d LEFT OUTER JOIN employees e
   ON d.department_id = e.department_id
   ORDER BY d.department_id;

DEPARTMENT_ID LAST_NAME
------------- -------------------------
           10 Whalen
           20 Hartstein
           20 Fay
           30 Raphaely
...
          250
          260
          270

Users familiar with the traditional Oracle outer joins syntax will recognize the same query in this form:

SELECT d.department_id, e.last_name
   FROM departments d, employees e
   WHERE d.department_id = e.department_id(+)
   ORDER BY d.department_id;

Oracle Corporation strongly recommends that you use the more flexible Oracle9i FROM clause join syntax shown in the former example.

The left outer join returns all departments, including those without any employees. The same statement with a right outer join returns all employees, including those not yet assigned to a department:


Note:

The employee Zeuss was added to the employees table for these examples, and is not part of the sample data.


SELECT d.department_id, e.last_name
   FROM departments d RIGHT OUTER JOIN employees e
   ON d.department_id = e.department_id
   ORDER BY d.department_id;

DEPARTMENT_ID LAST_NAME
------------- -------------------------
...
          110 Higgins
          110 Gietz
              Grant
              Zeuss

It is not clear from this result whether employees Grant and Zeuss have department_id NULL, or whether their department_id is not in the departments table. To determine this requires a full outer join:

SELECT d.department_id as d_dept_id, e.department_id as e_dept_id,
      e.last_name
   FROM departments d FULL OUTER JOIN employees e
   ON d.department_id = e.department_id
   ORDER BY d.department_id;

 D_DEPT_ID  E_DEPT_ID LAST_NAME
---------- ---------- -------------------------
  ...
       110        110 Gietz
       110        110 Higgins
  ...
       260
       270
                  999 Zeuss
                      Grant

Because the column names in this example are the same in both tables in the join, you can also use the common column feature (the USING clause) of the join syntax, which coalesces the two matching columns department_id. The output is the same as for the preceding example:

SELECT department_id AS d_e_dept_id, e.last_name
   FROM departments d FULL OUTER JOIN employees e
   USING (department_id)
   ORDER BY department_id;

D_E_DEPT_ID LAST_NAME
----------- -------------------------
  ...
        110 Higgins
        110 Gietz
  ...
        260
        270
            Grant
            Zeuss
Table Collections: Examples

You can perform DML operations on nested tables only if they are defined as columns of a table. Therefore, when the query_table_expr_clause of an INSERT, DELETE, or UPDATE statement is a table_collection_expression, the collection expression must be a subquery that uses the TABLE function to select the table's nested table column. The examples that follow are based on the following scenario:

Suppose the database contains a table hr_info with columns department_id, location, and manager_id, and a column of nested table type people which has last_name, department_id, and salary columns for all the employees of each respective manager:

CREATE TYPE people_typ AS OBJECT (
   last_name      VARCHAR2(25),
   department_id  NUMBER(4),
   salary         NUMBER(8,2));
/
CREATE TYPE people_tab_typ AS TABLE OF people_typ;
/
CREATE TABLE hr_info (
   department_id   NUMBER(4),
   location_id     NUMBER(4),
   manager_id      NUMBER(6),
   people          people_tab_typ)
   NESTED TABLE people STORE AS people_stor_tab;

INSERT INTO hr_info VALUES (280, 1800, 999, people_tab_typ());

The following example inserts into the people nested table column of hr_info table's department numbered 280:

INSERT INTO TABLE(SELECT h.people FROM hr_info h
   WHERE h.department_id = 280)
   VALUES ('Smith', 280, 1750);

The next example updates Department 280's people nested table:

UPDATE TABLE(SELECT h.people FROM hr_info h
   WHERE h.department_id = 280) p
   SET p.salary = p.salary + 100;

The next example deletes from Department 280's people nested table:

DELETE TABLE(SELECT h.people FROM hr_info h
   WHERE h.department_id = 280) p
   WHERE p.salary > 1700;
Collection Unnesting: Examples

To select data from a nested table column you again use the TABLE function to treat the nested table as columns of a table. This process is called "collection unnesting.

You could get all the rows from hr_info (created in the preceding example) and all 
the rows from the people nested table column of hr_info using the following 
statement: 

SELECT t1.department_id, t2.* FROM hr_info t1, TABLE(t1.people) t2
   WHERE t2.department_id = t1.department_id;

Now suppose that people is not a nested table column of hr_info, but is instead a separate table with columns last_name, department_id, address, hiredate, and salary. You can extract the same rows as in the preceding example with this statement:

SELECT t1.department_id, t2.* 
   FROM hr_info t1, TABLE(CAST(MULTISET(
      SELECT t3.last_name, t3.department_id, t3.salary 
         FROM people t3
      WHERE t3.department_id = t1.department_id)
      AS people_tab_typ)) t2;

Finally, suppose that people is neither a nested table column of table hr_info nor a table itself. Instead, you have created a function people_func that extracts from various sources the name, department, and salary of all employees. You can get the same information as in the preceding examples with the following query:

SELECT t1.department_id, t2.* FROM hr_info t1, TABLE(CAST
   (people_func( ... ) AS people_tab_typ)) t2;
See Also:

Oracle9i Application Developer's Guide - Fundamentals for more examples of collection unnesting.

Using the LEVEL Pseudocolumn: Examples

The following statement returns all employees in hierarchical order. The root row is defined to be the employee whose job is 'AD_VP'. The child rows of a parent row are defined to be those who have the employee number of the parent row as their manager number.

SELECT LPAD(' ',2*(LEVEL-1)) || last_name org_chart, 
        employee_id, manager_id, job_id
    FROM employees
    START WITH job_id = 'AD_VP' 
    CONNECT BY PRIOR employee_id = manager_id; 

ORG_CHART          EMPLOYEE_ID MANAGER_ID JOB_ID
------------------ ----------- ---------- ----------
Kochhar                    101        100 AD_VP
  Greenberg                108        101 FI_MGR
    Faviet                 109        108 FI_ACCOUNT
    Chen                   110        108 FI_ACCOUNT
    Sciarra                111        108 FI_ACCOUNT
    Urman                  112        108 FI_ACCOUNT
    Popp                   113        108 FI_ACCOUNT
  Whalen                   200        101 AD_ASST
  Mavris                   203        101 HR_REP
  Baer                     204        101 PR_REP
  Higgins                  205        101 AC_MGR
    Gietz                  206        205 AC_ACCOUNT
De Haan                    102        100 AD_VP
  Hunold                   103        102 IT_PROG
    Ernst                  104        103 IT_PROG
    Austin                 105        103 IT_PROG
    Pataballa              106        103 IT_PROG
    Lorentz                107        103 IT_PROG

The following statement is similar to the previous one, except that it does not select employees with the job 'FI_MAN'.

SELECT LPAD(' ',2*(LEVEL-1)) || last_name org_chart, 
        employee_id, manager_id, job_id
    FROM employees
    WHERE job_id != 'FI_MGR'
    START WITH job_id = 'AD_VP' 
    CONNECT BY PRIOR employee_id = manager_id; 

ORG_CHART          EMPLOYEE_ID MANAGER_ID JOB_ID
------------------ ----------- ---------- ----------
Kochhar                    101        100 AD_VP
    Faviet                 109        108 FI_ACCOUNT
    Chen                   110        108 FI_ACCOUNT
    Sciarra                111        108 FI_ACCOUNT
    Urman                  112        108 FI_ACCOUNT
    Popp                   113        108 FI_ACCOUNT
  Whalen                   200        101 AD_ASST
  Mavris                   203        101 HR_REP
  Baer                     204        101 PR_REP
  Higgins                  205        101 AC_MGR
    Gietz                  206        205 AC_ACCOUNT
De Haan                    102        100 AD_VP
  Hunold                   103        102 IT_PROG
    Ernst                  104        103 IT_PROG
    Austin                 105        103 IT_PROG
    Pataballa              106        103 IT_PROG
    Lorentz                107        103 IT_PROG


Oracle does not return the manager greenberg, although it does return employees who are managed by greenberg.

The following statement is similar to the first one, except that it uses the LEVEL pseudocolumn to select only the first two levels of the management hierarchy:

SELECT LPAD(' ',2*(LEVEL-1)) || last_name org_chart, 
employee_id, manager_id, job_id 
    FROM employees
    START WITH job_id = 'AD_PRES' 
    CONNECT BY PRIOR employee_id = manager_id AND LEVEL <= 2; 

ORG_CHART          EMPLOYEE_ID MANAGER_ID JOB_ID
------------------ ----------- ---------- ----------
King                       100            AD_PRES
  Kochhar                  101        100 AD_VP
  De Haan                  102        100 AD_VP
  Raphaely                 114        100 PU_MAN
  Weiss                    120        100 ST_MAN
  Fripp                    121        100 ST_MAN
  Kaufling                 122        100 ST_MAN
  Vollman                  123        100 ST_MAN
  Mourgos                  124        100 ST_MAN
  Russell                  145        100 SA_MAN
  Partners                 146        100 SA_MAN
  Errazuriz                147        100 SA_MAN
  Cambrault                148        100 SA_MAN
  Zlotkey                  149        100 SA_MAN
  Hartstein                201        100 MK_MAN
Using Distributed Queries: Example

This example shows a query that joins the departments table on the local database with the employees table on the remote database:

SELECT last_name, department_name 
   FROM employees@remote, departments
   WHERE employees.department_id = departments.department_id; 
Using Correlated Subqueries: Examples

The following examples show the general syntax of a correlated subquery:

SELECT select_list 
    FROM table1 t_alias1 
    WHERE expr operator 
        (SELECT column_list 
            FROM table2 t_alias2 
            WHERE t_alias1.column 
               operator t_alias2.column); 

UPDATE table1 t_alias1 
    SET column = 
        (SELECT expr 
            FROM table2 t_alias2 
            WHERE t_alias1.column = t_alias2.column); 

DELETE FROM table1 t_alias1 
    WHERE column operator 
        (SELECT expr 
            FROM table2 t_alias2 
            WHERE t_alias1.column = t_alias2.column); 

The following statement returns data about employees whose salaries exceed their department average. The following statement assigns an alias to employees, the table containing the salary information, and then uses the alias in a correlated subquery:

SELECT department_id, last_name, salary 
   FROM employees x 
   WHERE salary > (SELECT AVG(salary) 
      FROM employees 
      WHERE x.department_id = department_id) 
   ORDER BY department_id; 

For each row of the employees table, the parent query uses the correlated subquery to compute the average salary for members of the same department. The correlated subquery performs the following steps for each row of the employees table:

  1. The department_id of the row is determined.
  2. The department_id is then used to evaluate the parent query.
  3. If that row's salary is greater than the average salary for that row's department, then the row is returned.

The subquery is evaluated once for each row of the employees table.

Selecting from the DUAL Table: Example

The following statement returns the current date:

SELECT SYSDATE FROM DUAL; 

You could select SYSDATE from the employees table, but Oracle would return 14 rows of the same SYSDATE, one for every row of the employees table. Selecting from DUAL is more convenient.

Selecting Sequence Values: Examples

The following statement increments the employees_seq sequence and returns the new value:

SELECT employees_seq.nextval 
    FROM dual; 

The following statement selects the current value of employees_seq:

SELECT employees_seq.currval 
    FROM dual;