select-statement

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+--------------------------------------------------+--------->
   |                      .-,-----------------------. |
   |                      V                         | |
   '-WITH--+-----------+----common-table-expression-+-'
           '-RECURSIVE-'
 
>--fullselect--+-----------------+--+--------------------+------>
               '-order-by-clause-'  '-fetch-first-clause-'
 
   .----------------------.
   V                      | (1) (2)
>----+------------------+-+------------------------------------><
     +-update-clause----+
     +-read-only-clause-+
     +-optimize-clause--+
     '-isolation-clause-'
 
Notes:
  1. The update-clause and read-only-clause cannot both be specified in the same select-statement.
  2. Each clause may be specified only once.

The select-statement is the form of a query that can be directly specified in a DECLARE CURSOR statement, prepared and then referenced in a DECLARE CURSOR statement, or directly specified in an SQLJ assignment clause. It can also be issued interactively causing a result table to be displayed at your work station. In any case, the table specified by a select-statement is the result of the fullselect.

RECURSIVE
Indicates that a common-table-expression is potentially recursive.

common-table-expression

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-table-identifier--+-----------------------+------------------>
                     |    .-,-----------.    |
                     |    V             |    |
                     '-(----column-name-+--)-'
 
>--AS--(--fullselect--+-----------------+--+--------------------+--)-->
                      '-order-by-clause-'  '-fetch-first-clause-'
 
>--+---------------+--+--------------+-------------------------><
   '-search-clause-'  '-cycle-clause-'
 
search-clause:
 
                                  .-,-----------.
                                  V             |
|--SEARCH--+-DEPTH FIRST---+--BY----column-name-+--SET--seq-column-name--|
           '-BREADTH FIRST-'
 
cycle-clause:
 
          .-,-----------.
          V             |
|--CYCLE----column-name-+--------------------------------------->
 
>--SET--cycle-column-name--TO--constant--DEFAULT--constant------>
 
>--+--------------------------+---------------------------------|
   '-USING--using-column-name-'
 

A common-table-expression permits defining a result table with a table-identifier that can be specified as a table name in any FROM clause of the fullselect that follows. The table-identifier must be unqualified. Multiple common table expressions can be specified following the single WITH keyword. Each common table expression specified can also be referenced by name in the FROM clause of subsequent common table expressions.

If a list of columns is specified, it must consist of as many names as there are columns in the result table of the fullselect. Each column-name must be unique and unqualified. If these column names are not specified, the names are derived from the select list of the subselect used to define the common table expression.

The table-identifier of a common table expression must be different from any other common table expression table-identifier in the same statement. A common table expression table-identifier can be specified as a table name in any FROM clause throughout the fullselect. A table-identifier of a common table expression overrides any existing table, view, or alias (in the catalog) with the same unqualified name.

If more than one common table expression is defined in the same statement, cyclic references between the common table expressions are not permitted. A cyclic reference occurs when two common table expressions dt1 and dt2 are created such that dt1 refers to dt2 and dt2 refers to dt1.

The table name of a common table expression can only be referenced in the select-statement, INSERT statement, or CREATE VIEW statement that defines it.

If a select-statement, INSERT statement, or CREATE VIEW statement refers to an unqualified table name, the following rules are applied to determine which table is actually being referenced:

A common-table-expression can be used:

If a fullselect of a common table expression contains a reference to itself in a FROM clause, the common table expression is a recursive table expression. Queries using recursion are useful in supporting applications such as bill of materials (BOM), reservation systems, and network planning.

The following restrictions apply to a recursive common-table-expression:

If a column name of the common-table-expression is referred to in the iterative fullselect, the attributes of the result columns are determined using the rules for result columns. For more information see Rules for result data types.

search-clause
The SEARCH clause in the definition of the recursive common-table-expression is used to specify the order in which the result rows are to be returned.
SEARCH DEPTH FIRST
Each parent or containing item appears in the result before the items that it contains.
SEARCH BREADTH FIRST
Sibling items are grouped prior to subordinate items.
BY column-name,...
Identifies the columns that associate the parent and child relationship of the recursive query. Each column-name must unambiguously identify a column of the parent. The column must not be a DATALINK column. The rules for unambiguous column references are the same as in the other clauses of the fullselect. See Column name qualifiers to avoid ambiguity for more information.

The column-name must identify a column name of the recursive common-table-expression. The column-name must not be qualified.

SET seq-column-name
Specifies the name of a result column that contains an ordinal number of the current row in the recursive query result. The data type of the seq-column-name is BIGINT.

The seq-column-name may only be referenced in the ORDER BY clause of the outer fullselect that references the common-table-expression. The seq-column-name cannot be referenced in the fullselect that defines the common-table-expression.

The seq-column-name must not be the same as using-column-name or cycle-column-name.

cycle-clause
The CYCLE clause in the definition of the recursive common-table-expression is used to prevent an infinite loop in the recursive query when the parent and child relationship of the data results in a loop.
CYCLE column-name,...
Specifies the list of columns that represent the parent/child join relationship values for the recursion. Any new row from the query is first checked for a duplicate value (per these column names) in the existing rows that lead to this row in the recursive query results to determine if there is a cycle.

Each column-name must identify a result column of the common table expression. The same column-name must not be specified more than once.

SET cycle-column-name
Specifies the name of a result column that is set based on whether or not a cycle has been detected in the recursive query:
  • If a duplicate row is encountered, indicating that a cycle has been detected in the data, the cycle-column-name is set to the TO constant.
  • If a duplicate row is not encountered, indicating that a cycle has not been detected in the data, the cycle-column-name is set to the DEFAULT constant.
The data type of the cycle-column-name is CHAR(1).

When cyclic data in the row is encountered, the duplicate row is not returned to the recursive query process for further recursion and that child branch of the query is stopped. By specifying the provided cycle-column-name is in the result set of the main fullselect, the existence of cyclic data can actually be determined and even corrected if that is desired.

The cycle-column-name must not be the same as using-column-name or seq-column-name.

The cycle-column-name can be referenced in the fullselect that defines the common-table-expression.

TO constant
Specifies a CHAR(1) constant value to assign to the cycle-column if a cycle has been detected in the data. The TO constant must not be equal to the DEFAULT constant.
DEFAULT constant
Specifies a CHAR(1) constant value to assign to the cycle-column if a cycle has not been detected in the data. The DEFAULT constant must not be equal to the TO constant.
USING using-column-name
Identifies the temporary results consisting of the columns from the CYCLE column list. The temporary result is used by the database manager to identify duplicate rows in the query result.

The using-column-name must not be the same as cycle-column-name or seq-column-name.

Recursive common table expressions are not allowed if the query specifies:

Recursion example: bill of materials

Bill of materials (BOM) applications are a common requirement in many business environments. To illustrate the capability of a recursive common table expression for BOM applications, consider a table of parts with associated subparts and the quantity of subparts required by the part. For this example, create the table as follows:

   CREATE TABLE  PARTLIST 
     ( PART     VARCHAR(8),
       SUBPART  VARCHAR(8),
       QUANTITY INTEGER ) 

To give query results for this example, assume that the PARTLIST table is populated with the following values:

PART     SUBPART  QUANTITY
-------- -------- -----------
   00       01        5
   00       05        3
   01       02        2
   01       03        3
   01       04        4
   01       06        3
   02       05        7
   02       06        6
   03       07        6
   04       08       10
   04       09       11
   05       10       10
   05       11       10
   06       12       10
   06       13       10
   07       14        8
   07       12        8
Example 1: Single level explosion

The first example is called single level explosion. It answers the question, "What parts are needed to build the part identified by '01'?". The list will include the direct subparts, subparts of the subparts and so on. However, if a part is used multiple times, its subparts are only listed once.

   WITH RPL (PART, SUBPART, QUANTITY) AS
        (  SELECT ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY
              FROM PARTLIST ROOT
              WHERE ROOT.PART = '01'
          UNION ALL
           SELECT CHILD.PART, CHILD.SUBPART, CHILD.QUANTITY
              FROM RPL PARENT, PARTLIST CHILD
              WHERE PARENT.SUBPART = CHILD.PART
         )
   SELECT DISTINCT PART, SUBPART, QUANTITY
     FROM RPL
     ORDER BY PART, SUBPART, QUANTITY

The above query includes a common table expression, identified by the name RPL, that expresses the recursive part of this query. It illustrates the basic elements of a recursive common table expression.

The first operand (fullselect) of the UNION, referred to as the initialization fullselect, gets the direct children of part '01'. The FROM clause of this fullselect refers to the source table and will never refer to itself (RPL in this case). The result of this first fullselect goes into the common table expression RPL (Recursive PARTLIST). As in this example, the UNION must always be a UNION ALL.

The second operand (fullselect) of the UNION uses RPL to compute subparts of subparts by having the FROM clause refer to the common table expression RPL and the source table with a join of a part from the source table (child) to a subpart of the current result contained in RPL (parent). The result goes back to RPL again. The second operand of UNION is then used repeatedly until no more children exist.

The SELECT DISTINCT in the main fullselect of this query ensures the same part/subpart is not listed more than once.

The result of the query is as follows:

PART     SUBPART  QUANTITY
-------- -------- -----------
   01       02         2
   01       03         3
   01       04         4
   01       06         3
   02       05         7
   02       06         6
   03       07         6
   04       08        10
   04       09        11
   05       10        10
   05       11        10
   06       12        10
   06       13        10
   07       12         8
   07       14         8

Observe in the result that from part '01' we go to '02' which goes to '06' and so on. Further, notice that part '06' is reached twice, once through '01' directly and another time through '02'. In the output, however, its subcomponents are listed only once (this is the result of using a SELECT DISTINCT) as required.

Example 2: Summarized explosion

The second example is a summarized explosion. The question posed here is, what is the total quantity of each part required to build part '01'. The main difference from the single level explosion is the need to aggregate the quantities. The first example indicates the quantity of subparts required for the part whenever it is required. It does not indicate how many of the subparts are needed to build part '01'.

   WITH RPL (PART, SUBPART, QUANTITY) AS
        (  SELECT ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY
              FROM PARTLIST ROOT
              WHERE ROOT.PART = '01'
          UNION ALL
           SELECT PARENT.PART, CHILD.SUBPART, PARENT.QUANTITY*CHILD.QUANTITY
              FROM RPL PARENT, PARTLIST CHILD
              WHERE PARENT.SUBPART = CHILD.PART
         )
   SELECT PART, SUBPART, SUM(QUANTITY) AS "Total QTY Used"
     FROM RPL
     GROUP BY PART, SUBPART
     ORDER BY PART, SUBPART

In the above query, the select list of the second operand of the UNION in the recursive common table expression, identified by the name RPL, shows the aggregation of the quantity. To find out how much of a subpart is used, the quantity of the parent is multiplied by the quantity per parent of a child. If a part is used multiple times in different places, it requires another final aggregation. This is done by the grouping over the common table expression RPL and using the SUM aggregate function in the select list of the main fullselect.

The result of the query is as follows:

PART     SUBPART  Total Qty Used 
-------- -------- --------------
   01       02          2
   01       03          3
   01       04          4
   01       05         14
   01       06         15
   01       07         18
   01       08         40
   01       09         44
   01       10        140
   01       11        140
   01       12        294
   01       13        150
   01       14        144

Looking at the output, consider the line for subpart '06'. The total quantity used value of 15 is derived from a quantity of 3 directly for part '01' and a quantity of 6 for part '02' which is needed 2 times by part '01'.

Example 3: Controlling depth

The question may come to mind, what happens when there are more levels of parts in the table than you are interested in for your query? That is, how is a query written to answer the question, "What are the first two levels of parts needed to build the part identified by '01'?" For the sake of clarity in the example, the level is included in the result.

   WITH RPL ( LEVEL, PART, SUBPART, QUANTITY)
     AS ( SELECT 1, ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY
             FROM PARTLIST ROOT
             WHERE ROOT.PART = '01'
           UNION ALL
          SELECT PARENT.LEVEL+1, CHILD.PART, CHILD.SUBPART, CHILD.QUANTITY
             FROM RPL PARENT, PARTLIST CHILD
             WHERE PARENT.SUBPART = CHILD.PART
             AND PARENT.LEVEL < 2
         )
   SELECT PART, LEVEL, SUBPART, QUANTITY
     FROM RPL

This query is similar to example 1. The column LEVEL was introduced to count the levels from the original part. In the initialization fullselect, the value for the LEVEL column is initialized to 1. In the subsequent fullselect, the level from the parent is incremented by 1. Then to control the number of levels in the result, the second fullselect includes the condition that the parent level must be less than 2. This ensures that the second fullselect only processes children to the second level.

The result of the query is:

PART     LEVEL       SUBPART  QUANTITY
-------- ----------- -------- -----------
   01         1         02         2
   01         1         03         3
   01         1         04         4
   01         1         06         3
   02         2         05         7
   02         2         06         6
   03         2         07         6
   04         2         08        10
   04         2         09        11
   06         2         12        10
   06         2         13        10

order-by-clause

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram             .-,------------------------------.
             V             .-ASC--.           |
>>-ORDER BY----+-sort-key--+------+---------+-+----------------><
               |           '-DESC-'         |
               '-ORDER OF--table-designator-'
 
sort-key:
 
|--+-column-name---------+--------------------------------------|
   +-integer-------------+
   '-sort-key-expression-'
 

The ORDER BY clause specifies an ordering of the rows of the result table. If a single sort specification (one sort-key with associated ascending or descending ordering specification) is identified, the rows are ordered by the values of that specification. If more than one sort specification is identified, the rows are ordered by the values of the first identified sort specification, then by the values of the second identified sort specification, and so on.

If a sort sequence other than *HEX is in effect when the statement that contains the ORDER BY clause is executed and if the ORDER BY clause involves sort specifications that are SBCS data, mixed data, or Unicode data, the comparison for those sort specifications is done using weighted values. The weighted values are derived by applying the sort sequence to the values of the sort specifications.

A named column in the select list may be identified by a sort-key that is a integer or a column-name. An unnamed column in the select list may be identified by a integer or, in some cases by a sort-key-expression that matches the expression in the select list (see details of sort-key-expression). Names of result columns defines when result columns are unnamed. If the fullselect includes a UNION operator, see fullselect for the rules on named columns in a fullselect.

Ordering is performed in accordance with the comparison rules described in Language elements. The null value is higher than all other values. If your ordering specification does not determine a complete ordering, rows with duplicate values of the last identified sort-key have an arbitrary order. If the ORDER BY clause is not specified, the rows of the result table have an arbitrary order.

The number of sort-keys must not exceed 10000-n and the sum of their length attributes must not exceed 10000-n bytes (where n is the number of sort-keys specified that allow nulls).

column-name
Must unambiguously identify a column of the result table. The column must not be a LOB or DATALINK column. The rules for unambiguous column references are the same as in the other clauses of the fullselect. See Column name qualifiers to avoid ambiguity for more information.

If the fullselect includes a UNION, UNION ALL, EXCEPT, or INTERSECT the column name cannot be qualified.

The column-name may also identify a column name of a table, view, or nested-table-expression identified in the FROM clause if the query is a subselect. An error occurs if the subselect includes an aggregation in the select list and the column-name is not a grouping-expression.

integer
Must be greater than 0 and not greater than the number of columns in the result table. The integer n identifies the nth column of the result table. The identified column must not be a LOB or DATALINK column.
sort-key-expression
An expression that is not simply a column name or an unsigned integer constant. The query to which ordering is applied must be a subselect to use this form of sort-key.

The sort-key-expression cannot contain RRN, DATAPARTITIONNAME, DATAPARTITIONNUM, DBPARTITIONNAME, DBPARTITIONNUM, and HASHED_VALUE scalar functions if the fullselect includes a UNION, UNION ALL, EXCEPT, or INTERSECT. The result of the sort-key-expression must not be a LOB or DATALINK.

If the subselect is grouped, the sort-key-expression can be an expression in the select list of the subselect or can include a grouping-expression from the GROUP BY clause of the subselect.

ASC
Uses the values of the column in ascending order. This is the default.
DESC
Uses the values of the column in descending order.
ORDER OF table-designator
Specifies that the same ordering used in table-designator should be applied to the result table of the subselect. There must be a table reference matching table-designator in the FROM clause of the subselect that specifies this clause and the table reference must identify a nested-table-expression or common-table-expression. The subselect (or fullselect) corresponding to the specified table-designator must include an ORDER BY clause. The ordering that is applied is the same as if the columns of the ORDER BY clause in the nested-table-expression or common-table-expression were included in the outer subselect (or fullselect), and these columns were specified in place of the ORDER OF clause.

ORDER OF is not allowed if the query specifies:

fetch-first-clause

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                .-1-------.
>>-FETCH FIRST--+---------+--+-ROW--+--ONLY--------------------><
                '-integer-'  '-ROWS-'
 

The fetch-first-clause sets a maximum number of rows that can be retrieved. It lets the database manager know that only integer rows should be made available to be retrieved, regardless of how many rows there might be in the result table when this clause is not specified. An attempt to fetch beyond integer rows is handled the same way as normal end of data (SQLSTATE 02000). The value of integer must be a positive integer (not zero).

Limiting the result table to the first integer rows can improve performance. The database manager will cease processing the query once it has determined the first integer rows.

If both the order-by-clause and fetch-first-clause are specified, the FETCH FIRST operation is always performed on the ordered data. Specification of the fetch-first-clause in a select-statement makes the result table read-only. A read-only result table must not be referred to in an UPDATE or DELETE statement. The fetch-first-clause cannot appear in a statement containing an UPDATE clause.

update-clause

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-FOR UPDATE--+---------------------+-------------------------><
               |     .-,-----------. |
               |     V             | |
               '-OF----column-name-+-'
 

The UPDATE clause identifies the columns that can be updated in a subsequent positioned UPDATE statement. Each column-name must be unqualified and must identify a column of the table or view identified in the first FROM clause of the fullselect. A column that is used directly or indirectly in the ORDER BY clause must not be specified. The clause must not be specified if the result table of the fullselect is read-only.

If the UPDATE clause is specified without column names, all updatable columns of the table or view identified in the first FROM clause of the fullselect are included.

The FOR UPDATE OF clause must not be specified if the result table of the fullselect is read-only (for more information see DECLARE CURSOR) or if the FOR READ ONLY clause is used.

Positioned UPDATE statements identifying the cursor associated with a select-statement can update all updatable columns, if the select-statement does not contain one of the following:

When FOR UPDATE is used, FETCH operations referencing the cursor acquire an exclusive row lock.

read-only-clause

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-FOR READ ONLY-----------------------------------------------><
 

The FOR READ ONLY or FOR FETCH ONLY clause indicates that the result table is read-only and therefore the cursor cannot be used for Positioned UPDATE and DELETE statements.

Some result tables are read-only by nature. (For example, a table based on a read-only view). FOR READ ONLY can still be specified for such tables, but the specification has no effect.

For result tables in which updates and deletes are allowed, specifying FOR READ ONLY can possibly improve the performance of FETCH operations by allowing the database manager to do blocking and avoid exclusive locks. For example, in programs that contain dynamic SQL statements without the FOR READ ONLY or ORDER BY clause, the database manager might open cursors as if the UPDATE clause was specified.

A read-only result table must not be referred to in an UPDATE or DELETE statement, whether it is read-only by nature or specified as FOR READ ONLY.

To guarantee that selected data is not locked by any other job, you can specify the optional syntax of USE AND KEEP EXCLUSIVE LOCKS on the isolation-clause. This guarantees that the selected data can later be updated or deleted without incurring a row lock conflict.

Syntax Alternatives: FOR FETCH ONLY can be specified in place of FOR READ ONLY.

optimize-clause

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-OPTIMIZE FOR--+-integer-+--+-ROW--+-------------------------><
                 '-ALL-----'  '-ROWS-'
 

The optimize-clause tells the database manager to assume that the program does not intend to retrieve more than integer rows from the result table. Without this clause, or with the keyword ALL, the database manager assumes that all rows of the result table are to be retrieved. Optimizing for integer rows can improve performance. The database manager will optimize the query based on the specified number of rows.

The clause does not change the result table or the order in which the rows are fetched. Any number of rows can be fetched, but performance can possibly degrade after integer fetches.

The value of integer must be a positive integer (not zero).

isolation-clause

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-WITH--+-NC------------------+-------------------------------><
         +-UR------------------+
         +-CS--+------------+--+
         |     '-KEEP LOCKS-'  |
         +-RS--+-------------+-+
         |     '-lock-clause-' |
         '-RR--+-------------+-'
               '-lock-clause-'
 
lock-clause:
 
|--USE AND KEEP EXCLUSIVE LOCKS---------------------------------|
 

The isolation-clause specifies an isolation level at which the select statement is executed.

RR
Repeatable Read
USE AND KEEP EXCLUSIVE LOCKS
Exclusive row locks are acquired and held until a COMMIT or ROLLBACK statement is executed.
RS
Read Stability
USE AND KEEP EXCLUSIVE LOCKS
Exclusive row locks are acquired and held until a COMMIT or ROLLBACK statement is executed. The USE AND KEEP EXCLUSIVE LOCKS clause is only allowed in the isolation-clause in the following SQL statements:
  • DECLARE CURSOR,
  • FOR,
  • INSERT with a select-statement,
  • SELECT,
  • SELECT INTO, or
  • PREPARE in the ATTRIBUTES string.
It is not allowed on updatable cursors.
CS
Cursor Stability
KEEP LOCKS
The KEEP LOCKS clause specifies that any read locks acquired will be held for a longer duration. Normally, read locks are released when the next row is read. If the isolation clause is associated with a cursor, the locks will be held until the cursor is closed or until a COMMIT or ROLLBACK statement is executed. Otherwise, the locks will be held until the completion of the SQL statement.
UR
Uncommitted Read
NC
No Commit

If isolation-clause is not specified, the default isolation is used with the exception of a default isolation level of uncommitted read. See Isolation level for a description of how the default is determined.

Exclusive locks: The USE AND KEEP EXCLUSIVE LOCKS clause should be used with caution. If it is specified, the exclusive row locks that are acquired on rows will prevent concurrent access to those rows by other users running COMMIT(*CS), COMMIT(*RS), and COMMIT(*RR) till the end of the unit of work. Concurrent access by users running COMMIT(*NC) or COMMIT(*UR) is not prevented.

Keyword Synonyms: The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:

Examples of a select-statement

Example 1

Select all columns and rows from the EMPLOYEE table.

   SELECT * FROM EMPLOYEE

Example 2

Select the project name (PROJNAME), start date (PRSTDATE), and end date (PRENDATE) from the PROJECT table. Order the result table by the end date with the most recent dates appearing first.

   SELECT PROJNAME, PRSTDATE, PRENDATE
     FROM PROJECT
     ORDER BY PRENDATE DESC

Example 3

Select the department number (WORKDEPT) and average departmental salary (SALARY) for all departments in the EMPLOYEE table. Arrange the result table in ascending order by average departmental salary.

   SELECT WORKDEPT, AVG(SALARY)
     FROM EMPLOYEE
     GROUP BY WORKDEPT
     ORDER BY AVGSAL

Example 4

Declare a cursor named UP_CUR, to be used in a C program, that updates the start date (PRSTDATE) and the end date (PRENDATE) columns in the PROJECT table. The program must receive both of these values together with the project number (PROJNO) value for each row. The declaration specifies that the access path for the query be optimized for the retrieval of a maximum of 2 rows. Even so, the program can retrieve more than 2 rows from the result table. However, when more than 2 rows are retrieved, performance could possibly degrade.

   EXEC SQL  DECLARE UP_CUR CURSOR FOR
               SELECT PROJNO, PRSTDATE, PRENDATE
                 FROM PROJECT
                 FOR UPDATE OF PRSTDATE, PRENDATE
                 OPTIMIZE FOR 2 ROWS ;

Example 5

Select items from a table with an isolation level of Read Stability (RS).

   SELECT NAME, SALARY 
     FROM PAYROLL 
     WHERE DEPT = 704
     WITH RS

Example 6

Find the average charges for each subscriber (SNO) in the state of California during the last Friday of each month in the first quarter of 2000. Group the result according to SNO. Each MONTHnn table has columns for SNO, CHARGES, and DATE. The CUST table has columns for SNO and STATE.

   SELECT V.SNO, AVG( V.CHARGES)
     FROM CUST, LATERAL (
       SELECT SNO, CHARGES, DATE
       FROM MONTH1
       WHERE DATE BETWEEN '01/01/2000' AND '01/31/2000'
           UNION ALL
       SELECT SNO, CHARGES, DATE
       FROM MONTH2
       WHERE DATE BETWEEN '02/01/2000' AND '02/29/2000'
           UNION ALL
       SELECT SNO, CHARGES, DATE
       FROM MONTH3
       WHERE DATE BETWEEN '03/01/2000' AND '03/31/2000'
       ) AS  V (SNO, CHARGES, DATE)
     WHERE CUST.SNO=V.SNO
     AND CUST.STATE='CA'
     AND DATE IN ('01/28/2000','02/25/2000','03/31/2000')
     GROUP BY V.SNO

Example 7

This example names the expression SAL+BONUS+COMM as TOTAL_PAY:

   SELECT SALARY+BONUS+COMM AS TOTAL_PAY
     FROM EMPLOYEE
     ORDER BY TOTAL_PAY

Example 8

Determine the employee number and salary of sales representatives along with the average salary and head count of their departments. Also, list the average salary of the department with the highest average salary.

Using a common table expression for this case saves the overhead of creating the DINFO view as a regular view. Because of the context of the rest of the fullselect, only the rows for the department of the sales representatives need to be considered by the view.

   WITH 
      DINFO (DEPTNO, AVGSALARY, EMPCOUNT) AS
        (SELECT OTHERS.WORKDEPT, AVG(OTHERS.SALARY), COUNT(*)
           FROM EMPLOYEE OTHERS
           GROUP BY OTHERS.WORKDEPT),
      DINFOMAX AS
        (SELECT MAX(AVGSALARY) AS AVGMAX
           FROM DINFO)
   SELECT THIS_EMP.EMPNO, THIS_EMP.SALARY, DINFO.AVGSALARY, DINFO.EMPCOUNT, 
                              DINFOMAX.AVGMAX
     FROM EMPLOYEE THIS_EMP, DINFO, DINFOMAX
     WHERE THIS_EMP.JOB = 'SALESREP'
     AND THIS_EMP.WORKDEPT = DINFO.DEPTNO


[ Top of Page | Previous Page | Next Page | Contents | Index ]