ibm-information-center/dist/eclipse/plugins/i5OS.ic.db2_5.4.0.1/rbafzmstintsel.htm

861 lines
52 KiB
HTML
Raw Permalink Normal View History

2024-04-02 14:02:31 +00:00
<?xml version="1.0" encoding="utf-8"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN"
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
<html xmlns="http://www.w3.org/1999/xhtml" lang="en-US" xml:lang="en-us">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<meta name="dc.language" scheme="rfc1766" content="en-us" />
<!-- All rights reserved. Licensed Materials Property of IBM -->
<!-- US Government Users Restricted Rights -->
<!-- Use, duplication or disclosure restricted by -->
<!-- GSA ADP Schedule Contract with IBM Corp. -->
<meta name="dc.date" scheme="iso8601" content="2005-09-19" />
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="security" content="public" />
<meta name="Robots" content="index,follow"/>
<meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' />
<meta name="keywords" content="definition, common table expression,
select statement, recursive, query, of recursive common-table-expression,
SEARCH DEPTH FIRST clause, SEARCH BREADTH FIRST clause, CYCLE clause,
of select-statement, ORDER BY clause, AS clause, ASC clause, DESC clause,
in ORDER BY, ORDER OF clause, fetch-first-clause, FETCH FIRST clause,
UPDATE clause, FOR UPDATE OF clause, read-only-clause, FOR READ ONLY clause,
FOR FETCH ONLY clause, OPTIMIZE clause, WITH clause, isolation-clause,
USE AND KEEP EXCLUSIVE LOCKS, KEEP LOCKS" />
<title>select-statement</title>
<link rel="stylesheet" type="text/css" href="ibmidwb.css" />
<link rel="stylesheet" type="text/css" href="ic.css" />
</head>
<body>
<a id="Top_Of_Page" name="Top_Of_Page"></a><!-- Java sync-link -->
<script language = "Javascript" src = "../rzahg/synch.js" type="text/javascript"></script>
<a name="intsel"></a>
<h2 id="intsel"><a href="rbafzmst02.htm#ToC_700">select-statement</a></h2>
<a href="rbafzmstintsel.htm#synselstmt"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq971"></a>
<div class="fignone" id="wq971">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn232.htm"
border="0" /></span><a href="#skipsyn-231"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-+--------------------------------------------------+--------->
| .-,-----------------------. |
| V | |
'-WITH--+-----------+----<span class="italic">common-table-expression</span>-+-'
'-RECURSIVE-'
>--<span class="italic">fullselect</span>--+-----------------+--+--------------------+------>
'-<span class="italic">order-by-clause</span>-' '-<span class="italic">fetch-first-clause</span>-'
.----------------------.
V | (1) (2)
>----+------------------+-+------------------------------------>&lt;
+-<span class="italic">update-clause</span>----+
+-<span class="italic">read-only-clause</span>-+
+-<span class="italic">optimize-clause</span>--+
'-<span class="italic">isolation-clause</span>-'
</pre>
<a name="skipsyn-231" id="skipsyn-231"></a>
<a name="wq972"></a>
<div class="notelisttitle" id="wq972">Notes:</div>
<ol type="1">
<li>The update-clause and read-only-clause cannot both be specified in
the same select-statement.</li>
<li>Each clause may be specified only once.</li>
</ol></div>
<a name="synselstmt"></a>
<p id="synselstmt">The <span class="italic">select-statement</span> 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 <var class="pv">select-statement</var> is the result of the fullselect.</p>
<dl class="parml">
<dt class="bold">RECURSIVE</dt>
<dd>Indicates that a <var class="pv">common-table-expression</var> is potentially recursive.
</dd>
</dl>
<a name="comtexp"></a>
<h3 id="comtexp"><a href="rbafzmst02.htm#ToC_701">common-table-expression</a></h3><a id="idx1234" name="idx1234"></a><a id="idx1235" name="idx1235"></a>
<a href="rbafzmstintsel.htm#synselstmt_common"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq974"></a>
<div class="fignone" id="wq974">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn233.htm"
border="0" /></span><a href="#skipsyn-232"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-<span class="italic">table-identifier</span>--+-----------------------+------------------>
| .-,-----------. |
| V | |
'-(----<span class="italic">column-name</span>-+--)-'
>--AS--(--<span class="italic">fullselect</span>--+-----------------+--+--------------------+--)-->
'-<span class="italic">order-by-clause</span>-' '-<span class="italic">fetch-first-clause</span>-'
>--+---------------+--+--------------+------------------------->&lt;
'-<span class="italic">search-clause</span>-' '-<span class="italic">cycle-clause</span>-'
search-clause:
.-,-----------.
V |
|--SEARCH--+-DEPTH FIRST---+--BY----<span class="italic">column-name</span>-+--SET--<span class="italic">seq-column-name</span>--|
'-BREADTH FIRST-'
cycle-clause:
.-,-----------.
V |
|--CYCLE----<span class="italic">column-name</span>-+--------------------------------------->
>--SET--<span class="italic">cycle-column-name</span>--TO--<span class="italic">constant</span>--DEFAULT--<span class="italic">constant</span>------>
>--+--------------------------+---------------------------------|
'-USING--<span class="italic">using-column-name</span>-'
</pre>
<a name="skipsyn-232" id="skipsyn-232"></a></div>
<a name="synselstmt_common"></a>
<p id="synselstmt_common">A <var class="pv">common-table-expression</var> permits defining
a result table with a <var class="pv">table-identifier</var> that can be specified as a
table name in any FROM clause of the fullselect that follows. The <span class="italic">table-identifier</span> 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.</p>
<p>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 <var class="pv">column-name</var> 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.</p>
<p>The <var class="pv">table-identifier</var> of a common table expression must
be different from any other common table expression <var class="pv">table-identifier</var> in
the same statement. A common table expression <var class="pv">table-identifier</var> can
be specified as a table name in any FROM clause throughout the fullselect.
A <var class="pv">table-identifier</var> of a common table expression overrides any existing
table, view, or alias (in the catalog) with the same unqualified name.</p>
<p>If more than one common table expression is defined in the same statement,
cyclic references between the common table expressions are not permitted.
A <var class="pv">cyclic reference</var> occurs when two common table expressions <var class="pv">dt1</var> and <var class="pv">dt2</var> are created such that <var class="pv">dt1</var> refers to <var class="pv">dt2</var> and <var class="pv">dt2</var> refers to <var class="pv">dt1</var>.</p>
<p>The <var class="pv">table name</var> of a common table expression can only
be referenced in the <var class="pv">select-statement</var>, INSERT statement, or CREATE
VIEW statement that defines it.</p>
<p>If a <var class="pv">select-statement</var>, 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: </p>
<ul>
<li>If the unqualified name corresponds to one or more common table expression
names that are specified in the <var class="pv">select-statement</var>, the name identifies
the common table expression that is in the innermost scope.</li>
<li>If in a CREATE TRIGGER statement and the unqualified name corresponds
to a transition table name, the name identifies that transition table.</li>
<li>Otherwise, the name identifies a persistent table, a temporary table,
or a view that is present in the default schema.</li></ul>
<p>A <var class="pv">common-table-expression</var> can be used: </p>
<ul>
<li>In place of a view to avoid creating the view (when general use of the
view is not required and positioned updates or deletes are not used</li>
<li>When the desired result table is based on variables</li>
<li>When the same result table needs to be shared in a <var class="pv">fullselect</var></li></ul><a id="idx1236" name="idx1236"></a><a id="idx1237" name="idx1237"></a><a id="idx1238" name="idx1238"></a>
<p>If a <var class="pv">fullselect</var> of a common table expression contains
a reference to itself in a FROM clause, the common table expression is a <var class="pv">recursive table expression</var>. Queries using recursion are useful in supporting
applications such as bill of materials (BOM), reservation systems, and network
planning.</p>
<p>The following restrictions apply to a recursive <var class="pv">common-table-expression</var>:</p>
<ul>
<li>A list of <var class="pv">column-names</var> must be specified following
the <var class="pv">table-identifier</var>.</li>
<li>The UNION ALL set operator must be specified.</li>
<li>The first fullselect of the first union (the initialization fullselect)
must not include a reference to the <var class="pv">common-table-expression</var> itself
in any FROM clause.</li>
<li>Each fullselect that is part of the recursion cycle must not include any
aggregate functions, GROUP BY clauses, or HAVING clauses.</li>
<li>The FROM clauses of each fullselect can include at most one reference
to a <var class="pv">common-table-expression</var> that is part of a recursion cycle.</li>
<li>The table being defined in the <var class="pv">common-table-expression</var> cannot
be referenced in a subquery of a fullselect that defines the <var class="pv">common-table-expression</var>.</li>
<li>LEFT OUTER JOIN is not allowed if the <var class="pv">common-table-expression</var> is the right operand. A RIGHT OUTER JOIN is not allowed if the <var class="pv">common-table-expression</var> is the left operand.</li></ul>
<p>If a column name of the <var class="pv">common-table-expression</var> 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 <a href="rbafzmstopcomb.htm#opcomb">Rules for result data types</a>.</p>
<dl class="parml">
<dt class="bold">search-clause</dt>
<dd>The SEARCH clause in the definition of the recursive <var class="pv">common-table-expression</var> is used to specify the order in which the result rows are to be returned.
<dl class="parml">
<dt class="bold">SEARCH DEPTH FIRST<a id="idx1239" name="idx1239"></a></dt>
<dd>Each parent or containing item appears in the result before the items
that it contains.
</dd>
<dt class="bold">SEARCH BREADTH FIRST<a id="idx1240" name="idx1240"></a></dt>
<dd>Sibling items are grouped prior to subordinate items.
</dd>
<dt class="bold">BY <var class="pv">column-name</var>,...</dt>
<dd>Identifies the columns that associate the parent and child
relationship of the recursive query. Each <var class="pv">column-name</var> 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 <a href="rbafzmstch2col.htm#qcn1">Column name qualifiers to avoid ambiguity</a> for more information.
<p>The <var class="pv">column-name</var> must identify a column name of the recursive <var class="pv">common-table-expression</var>. The <var class="pv">column-name</var> must not be qualified.</p>
</dd>
<dt class="bold">SET <var class="pv">seq-column-name</var></dt>
<dd>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 <var class="pv">seq-column-name</var> is BIGINT.
<p>The <var class="pv">seq-column-name</var> may
only be referenced in the ORDER BY clause of the outer fullselect that references
the <var class="pv">common-table-expression</var>. The <var class="pv">seq-column-name</var> cannot
be referenced in the fullselect that defines the <var class="pv">common-table-expression</var>.</p>
<p>The <var class="pv">seq-column-name</var> must not be the same
as <var class="pv">using-column-name</var> or <var class="pv">cycle-column-name</var>.</p>
</dd>
</dl>
</dd>
<dt class="bold">cycle-clause</dt>
<dd>The CYCLE clause in the definition of the recursive <var class="pv">common-table-expression</var> is used to prevent an infinite loop in the recursive query when the
parent and child relationship of the data results in a loop.
<dl class="parml">
<dt class="bold">CYCLE <var class="pv">column-name</var>,...<a id="idx1241" name="idx1241"></a></dt>
<dd>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.
<p>Each <var class="pv">column-name</var> must identify a result
column of the common table expression. The same <var class="pv">column-name</var> must
not be specified more than once.</p>
</dd>
<dt class="bold">SET <var class="pv">cycle-column-name</var></dt>
<dd>Specifies the name of a result column that is set based on whether or
not a cycle has been detected in the recursive query:
<ul>
<li>If a duplicate row is encountered, indicating that a cycle has been detected
in the data, the <var class="pv">cycle-column-name</var> is set to the TO <var class="pv">constant</var>.</li>
<li>If a duplicate row is not encountered, indicating that a cycle has not
been detected in the data, the <var class="pv">cycle-column-name</var> is set to the DEFAULT <var class="pv">constant</var>.</li></ul>The data type of the <var class="pv">cycle-column-name</var> is CHAR(1).
<p>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 <var class="pv">cycle-column-name</var> 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.</p>
<p>The <var class="pv">cycle-column-name</var> must not be the same as <var class="pv">using-column-name</var> or <var class="pv">seq-column-name</var>.</p>
<p>The <var class="pv">cycle-column-name</var> can be referenced in the fullselect that defines the <var class="pv">common-table-expression</var>.</p>
</dd>
<dt class="bold">TO <var class="pv">constant</var></dt>
<dd>Specifies a CHAR(1) constant value to assign to the <var class="pv">cycle-column</var> if a cycle has been detected in the data. The TO <var class="pv">constant</var> must not be equal to the DEFAULT <var class="pv">constant</var>.
</dd>
<dt class="bold">DEFAULT <var class="pv">constant</var></dt>
<dd>Specifies a CHAR(1) constant value to assign to the <var class="pv">cycle-column</var> if a cycle has not been detected in the data. The DEFAULT <var class="pv">constant</var> must not be equal to the TO <var class="pv">constant</var>.
</dd>
<dt class="bold">USING <var class="pv">using-column-name</var></dt>
<dd>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.
<p>The <var class="pv">using-column-name</var> must not be the same as <var class="pv">cycle-column-name</var> or <var class="pv">seq-column-name</var>.</p>
</dd>
</dl>
</dd>
</dl>
<p>Recursive common table expressions are not allowed if the query
specifies:</p>
<ul>
<li>lateral correlation,</li>
<li>a sort sequence,</li>
<li>an operation that requires CCSID conversion,</li>
<li>a UTF-8 or UTF-16 argument in a CHARACTER_LENGTH, POSITION, or SUBSTRING
scalar function,</li>
<li>a distributed table,</li>
<li>a table with a read trigger, or</li>
<li>a logical file built over multiple physical file members.</li></ul>
<a name="wq975"></a>
<h4 id="wq975">Recursion example: bill of materials</h4>
<p>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:</p>
<pre class="xmp"> <span class="bold">CREATE TABLE</span> PARTLIST
<span class="bold">(</span> PART <span class="bold">VARCHAR(</span>8<span class="bold">),</span>
SUBPART <span class="bold">VARCHAR(</span>8<span class="bold">),</span>
QUANTITY <span class="bold">INTEGER )</span> </pre>
<p>To give query results for this example, assume that the PARTLIST table
is populated with the following values:</p>
<pre class="xmp">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
</pre>
<a name="singlelvlexp"></a>
<h5 id="singlelvlexp">Example 1: Single level explosion</h5>
<p>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.</p>
<pre class="xmp"> <span class="bold">WITH RPL (</span>PART, SUBPART, QUANTITY<span class="bold">) AS
( SELECT</span> ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY
<span class="bold">FROM</span> PARTLIST ROOT
<span class="bold">WHERE</span> ROOT.PART = '01'
<span class="bold">UNION ALL
SELECT</span> CHILD.PART, CHILD.SUBPART, CHILD.QUANTITY
<span class="bold">FROM</span> RPL PARENT, PARTLIST CHILD
<span class="bold">WHERE</span> PARENT.SUBPART = CHILD.PART
<span class="bold">)
SELECT DISTINCT</span> PART, SUBPART, QUANTITY
<span class="bold">FROM</span> RPL
<span class="bold">ORDER BY</span> PART, SUBPART, QUANTITY</pre>
<p>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.</p>
<p>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.</p>
<p>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.</p>
<p>The SELECT DISTINCT in the main fullselect of this query ensures the same
part/subpart is not listed more than once.</p>
<p>The result of the query is as follows:</p>
<pre class="xmp">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</pre>
<p>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.</p>
<a name="wq976"></a>
<h5 id="wq976">Example 2: Summarized explosion</h5>
<p>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'.</p>
<pre class="xmp"> <span class="bold">WITH RPL (</span>PART, SUBPART, QUANTITY<span class="bold">) AS
( SELECT</span> ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY
<span class="bold">FROM</span> PARTLIST ROOT
<span class="bold">WHERE</span> ROOT.PART = '01'
<span class="bold">UNION ALL
SELECT</span> PARENT.PART, CHILD.SUBPART, PARENT.QUANTITY<span class="bold">*</span>CHILD.QUANTITY
<span class="bold">FROM</span> RPL PARENT, PARTLIST CHILD
<span class="bold">WHERE</span> PARENT.SUBPART = CHILD.PART
<span class="bold">)
SELECT</span> PART, SUBPART, <span class="bold">SUM(</span>QUANTITY<span class="bold">) AS</span> "Total QTY Used"
<span class="bold">FROM</span> RPL
<span class="bold">GROUP BY</span> PART, SUBPART
<span class="bold">ORDER BY</span> PART, SUBPART</pre>
<p>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.</p>
<p>The result of the query is as follows:</p>
<pre class="xmp">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
</pre>
<p>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'.</p>
<a name="wq977"></a>
<h5 id="wq977">Example 3: Controlling depth</h5>
<p>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.</p>
<pre class="xmp"> <span class="bold">WITH RPL (</span> LEVEL, PART, SUBPART, QUANTITY<span class="bold">)
AS ( SELECT</span> 1, ROOT.PART, ROOT.SUBPART, ROOT.QUANTITY
<span class="bold">FROM</span> PARTLIST ROOT
<span class="bold">WHERE</span> ROOT.PART = '01'
<span class="bold">UNION ALL
SELECT</span> PARENT.LEVEL<span class="bold">+</span>1, CHILD.PART, CHILD.SUBPART, CHILD.QUANTITY
<span class="bold">FROM</span> RPL PARENT, PARTLIST CHILD
<span class="bold">WHERE</span> PARENT.SUBPART = CHILD.PART
<span class="bold">AND</span> PARENT.LEVEL &lt; 2
<span class="bold">)
SELECT</span> PART, LEVEL, SUBPART, QUANTITY
<span class="bold">FROM</span> RPL</pre>
<p>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.</p>
<p>The result of the query is:</p>
<pre class="xmp">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
</pre>
<a name="orderby"></a>
<h3 id="orderby"><a href="rbafzmst02.htm#ToC_706">order-by-clause</a></h3><a id="idx1242" name="idx1242"></a>
<a href="rbafzmstintsel.htm#synselstmt_order"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq978"></a>
<div class="fignone" id="wq978">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn234.htm"
border="0" /></span><a href="#skipsyn-233"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a> .-,------------------------------.
V .-<span>ASC</span>--. |
>>-ORDER BY----+-<span><span class="italic">sort-key</span></span>--+------+---------+-+---------------->&lt;
| '-<span>DESC</span>-' |
'-<span>ORDER OF</span>--<span><span class="italic">table-designator</span></span>-'
sort-key:
|--+-<span class="italic">column-name</span>---------+--------------------------------------|
+-<span class="italic">integer</span>-------------+
'-<span class="italic">sort-key-expression</span>-'
</pre>
<a name="skipsyn-233" id="skipsyn-233"></a></div>
<a name="synselstmt_order"></a>
<p id="synselstmt_order">The ORDER BY clause specifies an ordering of the
rows of the result table. If a single sort specification (one <var class="pv">sort-key</var> 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.</p>
<p>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.</p><a id="idx1243" name="idx1243"></a>
<p>A named column in the select list may be identified by a <var class="pv">sort-key</var> that
is a <var class="pv">integer</var> or a <var class="pv">column-name</var>. An unnamed column in the
select list may be identified by a <var class="pv">integer</var> or, in some cases by a <var class="pv">sort-key-expression</var> that matches the expression in the select list (see
details of <var class="pv">sort-key-expression</var>). <a href="rbafzmstsubselect.htm#nrcmj">Names of result columns</a> defines when
result columns are unnamed. If the fullselect includes a UNION operator, see <a href="rbafzmstmark.htm#mark">fullselect</a> for the rules on named columns in a fullselect.</p>
<p>Ordering is performed in accordance with the comparison rules described
in <a href="rbafzmstsqlelem.htm#sqlelem">Language elements</a>. 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 <var class="pv">sort-key</var> have
an arbitrary order. If the ORDER BY clause is not specified, the rows of the
result table have an arbitrary order.</p>
<a name="upcl"></a>
<p id="upcl">The number of <var class="pv">sort-keys</var> must not exceed 10000-<span class="italic">n</span> and the sum of their length attributes must not exceed 10000-<span class="italic">n</span> bytes (where <span class="italic">n</span> is the number of <var class="pv">sort-keys</var> specified that allow nulls).</p>
<p></p>
<dl class="parml">
<dt class="bold"><var class="pv">column-name</var></dt>
<dd>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 <a href="rbafzmstch2col.htm#qcn1">Column name qualifiers to avoid ambiguity</a> for
more information.
<p>If the fullselect includes a UNION, UNION ALL, EXCEPT,
or INTERSECT the column name cannot be qualified.</p>
<p>The <var class="pv">column-name</var> may also identify a column name of a table, view, or <span class="italic">nested-table-expression</span> 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 <var class="pv">column-name</var> is not a <var class="pv">grouping-expression</var>.</p>
</dd>
<dt class="bold"><var class="pv">integer</var></dt>
<dd>Must be greater than 0 and not greater than the number of columns in
the result table. The integer <span class="italic">n</span> identifies the <span class="italic">n</span>th column of the result table. The identified column
must not be a LOB or DATALINK column.
</dd>
<dt class="bold"><var class="pv">sort-key-expression</var></dt>
<dd>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 <var class="pv">sort-key</var>.
<p>The <span class="italic">sort-key-expression</span> cannot contain RRN, DATAPARTITIONNAME, DATAPARTITIONNUM, DBPARTITIONNAME,
DBPARTITIONNUM, and HASHED_VALUE scalar functions if the <span class="italic">fullselect</span> includes a UNION, UNION ALL, EXCEPT, or INTERSECT. The result
of the <var class="pv">sort-key-expression</var> must not be a LOB or DATALINK.</p>
<p>If the subselect is grouped, the <span class="italic">sort-key-expression</span> can
be an expression in the select list of the subselect or can include a <var class="pv">grouping-expression</var> from the GROUP BY clause of the subselect.</p>
</dd>
<dt class="bold">ASC <a id="idx1244" name="idx1244"></a></dt>
<dd>Uses the values of the column in ascending order. This is the default.
</dd>
<dt class="bold">DESC </dt><a id="idx1245" name="idx1245"></a>
<dd>Uses the values of the column in descending order.
</dd>
<dt class="bold">ORDER OF <var class="pv">table-designator</var></dt><a id="idx1246" name="idx1246"></a>
<dd>Specifies that the same ordering used in <var class="pv">table-designator</var> should
be applied to the result table of the subselect. There must be a table reference
matching <var class="pv">table-designator</var> in the FROM clause of the subselect that
specifies this clause and the table reference must identify a <var class="pv">nested-table-expression</var> or <var class="pv">common-table-expression</var>. The subselect (or fullselect) corresponding
to the specified <var class="pv">table-designator</var> 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 <var class="pv">nested-table-expression</var> or <var class="pv">common-table-expression</var> were included in the outer subselect (or fullselect), and these columns
were specified in place of the ORDER OF clause.
<p>ORDER OF is not
allowed if the query specifies:</p>
<ul>
<li>lateral correlation,</li>
<li>a sort sequence,</li>
<li>an operation that requires CCSID conversion,</li>
<li>a UTF-8 or UTF-16 argument in a CHARACTER_LENGTH, POSITION, or SUBSTRING
scalar function,</li>
<li>a distributed table,</li>
<li>a table with a read trigger, or</li>
<li>a logical file built over multiple physical file members.</li></ul>
</dd>
</dl>
<a name="fetchfirst"></a>
<h3 id="fetchfirst"><a href="rbafzmst02.htm#ToC_707">fetch-first-clause</a></h3><a id="idx1247" name="idx1247"></a><a id="idx1248" name="idx1248"></a>
<a href="rbafzmstintsel.htm#synselstmt_fetch"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq979"></a>
<div class="fignone" id="wq979">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn235.htm"
border="0" /></span><a href="#skipsyn-234"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a> .-1-------.
>>-FETCH FIRST--+---------+--+-ROW--+--ONLY-------------------->&lt;
'-<span class="italic">integer</span>-' '-ROWS-'
</pre>
<a name="skipsyn-234" id="skipsyn-234"></a></div>
<a name="synselstmt_fetch"></a>
<p id="synselstmt_fetch">The <span class="italic">fetch-first-clause</span> sets
a maximum number of rows that can be retrieved. It lets the database manager
know that only <var class="pv">integer</var> 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 <span class="italic">integer</span> rows
is handled the same way as normal end of data (SQLSTATE 02000). The value
of <span class="italic">integer</span> must be a positive integer (not zero).</p>
<p>Limiting the result table to the first <span class="italic">integer</span> rows
can improve performance. The database manager will cease processing the query
once it has determined the first <span class="italic">integer</span> rows.</p>
<p>If both the <span class="italic">order-by-clause</span> and <span class="italic">fetch-first-clause</span> are specified, the FETCH FIRST operation is always
performed on the ordered data. Specification of the <span class="italic">fetch-first-clause</span> in a <span class="italic">select-statement</span> makes the result table <span class="italic">read-only</span>. A <span class="italic">read-only</span> result
table must not be referred to in an UPDATE or DELETE statement. The <span class="italic">fetch-first-clause</span> cannot appear in a statement containing an UPDATE
clause.</p>
<a name="updateclause"></a>
<h3 id="updateclause"><a href="rbafzmst02.htm#ToC_708">update-clause</a></h3><a id="idx1249" name="idx1249"></a><a id="idx1250" name="idx1250"></a>
<a href="rbafzmstintsel.htm#synselstmt_update"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq980"></a>
<div class="fignone" id="wq980">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn236.htm"
border="0" /></span><a href="#skipsyn-235"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-FOR UPDATE--+---------------------+------------------------->&lt;
| .-,-----------. |
| V | |
'-OF----<span class="italic">column-name</span>-+-'
</pre>
<a name="skipsyn-235" id="skipsyn-235"></a></div>
<a name="synselstmt_update"></a>
<p id="synselstmt_update">The UPDATE clause identifies the columns
that can be updated in a subsequent positioned UPDATE statement. Each <span class="italic">column-name</span> 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.</p>
<p>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.</p>
<p>The FOR UPDATE OF clause must not be specified if the result table of the
fullselect is read-only (for more information see <a href="rbafzmsth2clcu.htm#h2dclcu">DECLARE CURSOR</a>)
or if the FOR READ ONLY clause is used.</p>
<p>Positioned UPDATE statements identifying the cursor associated with a <span class="italic">select-statement</span> can update all updatable columns, if
the select-statement does not contain one of the following: </p>
<ul>
<li>An UPDATE clause</li>
<li>A FOR READ ONLY clause</li>
<li>An ORDER BY clause</li></ul>
<p>When FOR UPDATE is used, FETCH operations referencing the cursor
acquire an exclusive row lock.</p>
<a name="readonly"></a>
<h3 id="readonly"><a href="rbafzmst02.htm#ToC_709">read-only-clause</a></h3><a id="idx1251" name="idx1251"></a><a id="idx1252" name="idx1252"></a><a id="idx1253" name="idx1253"></a>
<a href="rbafzmstintsel.htm#synselstmt_read"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq981"></a>
<div class="fignone" id="wq981">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn237.htm"
border="0" /></span><a href="#skipsyn-236"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-FOR READ ONLY----------------------------------------------->&lt;
</pre>
<a name="skipsyn-236" id="skipsyn-236"></a></div>
<a name="synselstmt_read"></a>
<p id="synselstmt_read">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.</p>
<p>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.</p>
<p>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.</p>
<p>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.</p>
<p>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 <var class="pv">isolation-clause</var>. This guarantees that the selected data can later be
updated or deleted without incurring a row lock conflict.</p>
<p><span class="bold">Syntax Alternatives:</span> FOR FETCH ONLY can be specified
in place of FOR READ ONLY.</p>
<a name="optimize"></a>
<h3 id="optimize"><a href="rbafzmst02.htm#ToC_710">optimize-clause</a></h3><a id="idx1254" name="idx1254"></a>
<a href="rbafzmstintsel.htm#synselstmt_opt"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq982"></a>
<div class="fignone" id="wq982">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn238.htm"
border="0" /></span><a href="#skipsyn-237"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-OPTIMIZE FOR--+-<span class="italic">integer</span>-+--+-ROW--+------------------------->&lt;
'-ALL-----' '-ROWS-'
</pre>
<a name="skipsyn-237" id="skipsyn-237"></a></div>
<a name="synselstmt_opt"></a>
<p id="synselstmt_opt">The <span class="italic">optimize-clause</span> tells the
database manager to assume that the program does not intend to retrieve more
than <var class="pv">integer</var> 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 <var class="pv">integer</var> rows can improve
performance. The database manager will optimize the query based on the specified
number of rows.</p>
<p>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 <var class="pv">integer</var> fetches.</p>
<p>The value of <span class="italic">integer</span> must be a positive integer
(not zero).</p>
<a name="isocl"></a>
<h3 id="isocl"><a href="rbafzmst02.htm#ToC_711">isolation-clause</a></h3>
<p><a id="idx1255" name="idx1255"></a><a id="idx1256" name="idx1256"></a></p>
<a href="rbafzmstintsel.htm#synselstmt_iso"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq983"></a>
<div class="fignone" id="wq983">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn239.htm"
border="0" /></span><a href="#skipsyn-238"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-WITH--+-NC------------------+------------------------------->&lt;
+-UR------------------+
+-CS--+------------+--+
| '-KEEP LOCKS-' |
+-<span>RS</span>--+-------------+-+
| '-<span><span class="italic">lock-clause</span></span>-' |
'-<span>RR</span>--+-------------+-'
'-<span><span class="italic">lock-clause</span></span>-'
lock-clause:
|--<span>USE AND KEEP EXCLUSIVE LOCKS</span>---------------------------------|
</pre>
<a name="skipsyn-238" id="skipsyn-238"></a></div>
<a name="synselstmt_iso"></a>
<p id="synselstmt_iso">The <span class="italic">isolation-clause</span> specifies
an isolation level at which the select statement is executed.</p>
<dl>
<dt class="bold">RR</dt>
<dd>Repeatable Read
<dl class="parml">
<dt class="bold">USE AND KEEP EXCLUSIVE LOCKS</dt><a id="idx1257" name="idx1257"></a>
<dd>Exclusive row locks are acquired and held until a COMMIT
or ROLLBACK statement is executed.
</dd>
</dl>
</dd>
<dt class="bold">RS</dt>
<dd>Read Stability
<dl class="parml">
<dt class="bold">USE AND KEEP EXCLUSIVE LOCKS</dt><a id="idx1258" name="idx1258"></a>
<dd>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 <span class="italic">isolation-clause</span> in the following
SQL statements:
<ul>
<li>DECLARE CURSOR,</li>
<li>FOR,</li>
<li>INSERT with a <span class="italic">select-statement</span>,</li>
<li>SELECT,</li>
<li>SELECT INTO, or</li>
<li>PREPARE in the ATTRIBUTES string.</li></ul>It is not allowed on updatable cursors.
</dd>
</dl>
</dd>
<dt class="bold">CS</dt>
<dd>Cursor Stability
<dl class="parml">
<dt class="bold">KEEP LOCKS</dt><a id="idx1259" name="idx1259"></a>
<dd>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.
</dd>
</dl>
</dd>
<dt class="bold">UR</dt>
<dd>Uncommitted Read
</dd>
<dt class="bold">NC</dt>
<dd>No Commit
</dd>
</dl>
<p>If <var class="pv">isolation-clause</var> is not specified, the default isolation is
used with the exception of a default isolation level of uncommitted read.
See <a href="rbafzmstisol.htm#isol">Isolation level</a> for a description of how the default is determined.</p>
<p><span class="bold">Exclusive locks:</span> 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.</p>
<p><span class="bold">Keyword Synonyms:</span> The following keywords are synonyms
supported for compatibility to prior releases. These keywords are non-standard
and should not be used:</p>
<ul>
<li>The keyword NONE can be used as a synonym for NC.</li>
<li>The keyword CHG can be used as a synonym for UR.</li>
<li>The keyword ALL can be used as a synonym for RS.</li></ul>
<a name="wq984"></a>
<h3 id="wq984"><a href="rbafzmst02.htm#ToC_712">Examples of a select-statement</a></h3>
<a name="wq985"></a>
<h4 id="wq985">Example 1</h4>
<p>Select all columns and rows from the EMPLOYEE table. </p>
<pre class="xmp"> <span class="bold">SELECT * FROM</span> EMPLOYEE</pre>
<a name="wq986"></a>
<h4 id="wq986">Example 2</h4>
<p>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. </p>
<pre class="xmp"> <span class="bold">SELECT</span> PROJNAME, PRSTDATE, PRENDATE
<span class="bold">FROM</span> PROJECT
<span class="bold">ORDER BY</span> PRENDATE <span class="bold">DESC</span></pre>
<a name="wq987"></a>
<h4 id="wq987">Example 3</h4>
<p>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. </p>
<pre class="xmp"> <span class="bold">SELECT</span> WORKDEPT, <span class="bold">AVG(</span>SALARY<span class="bold">)</span>
<span class="bold">FROM</span> EMPLOYEE
<span class="bold">GROUP BY</span> WORKDEPT
<span class="bold">ORDER BY</span> AVGSAL</pre>
<a name="wq988"></a>
<h4 id="wq988">Example 4</h4>
<p>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. </p>
<pre class="xmp"> EXEC SQL <span class="bold">DECLARE</span> UP_CUR <span class="bold">CURSOR FOR</span>
<span class="bold">SELECT</span> PROJNO, PRSTDATE, PRENDATE
<span class="bold">FROM</span> PROJECT
<span class="bold">FOR UPDATE OF</span> PRSTDATE, PRENDATE
<span class="bold">OPTIMIZE FOR</span> 2 <span class="bold">ROWS</span> ;</pre>
<a name="wq989"></a>
<h4 id="wq989">Example 5</h4><a id="idx1260" name="idx1260"></a>
<p>Select items from a table with an isolation level of Read Stability
(RS). </p>
<pre class="xmp"> <span class="bold">SELECT</span> NAME, SALARY
<span class="bold">FROM</span> PAYROLL
<span class="bold">WHERE</span> DEPT = 704
<span class="bold">WITH RS</span></pre>
<a name="wq990"></a>
<h4 id="wq990">Example 6</h4>
<p>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.</p>
<pre class="xmp"> <span class="bold">SELECT</span> V.SNO, <span class="bold">AVG(</span> V.CHARGES<span class="bold">)</span>
<span class="bold">FROM</span> CUST, <span class="bold">LATERAL (</span>
<span class="bold">SELECT</span> SNO, CHARGES, DATE
<span class="bold">FROM</span> MONTH1
<span class="bold">WHERE</span> DATE <span class="bold">BETWEEN</span> '01/01/2000' <span class="bold">AND</span> '01/31/2000'
<span class="bold">UNION ALL</span>
<span class="bold">SELECT</span> SNO, CHARGES, DATE
<span class="bold">FROM</span> MONTH2
<span class="bold">WHERE</span> DATE <span class="bold">BETWEEN</span> '02/01/2000' <span class="bold">AND</span> '02/29/2000'
<span class="bold">UNION ALL</span>
<span class="bold">SELECT</span> SNO, CHARGES, DATE
<span class="bold">FROM</span> MONTH3
<span class="bold">WHERE</span> DATE <span class="bold">BETWEEN</span> '03/01/2000' <span class="bold">AND</span> '03/31/2000'
<span class="bold">) AS </span> V <span class="bold">(</span>SNO, CHARGES, DATE<span class="bold">)</span>
<span class="bold">WHERE</span> CUST.SNO=V.SNO
<span class="bold">AND</span> CUST.STATE='CA'
<span class="bold">AND</span> DATE <span class="bold">IN (</span>'01/28/2000','02/25/2000','03/31/2000'<span class="bold">)</span>
<span class="bold">GROUP BY</span> V.SNO</pre>
<a name="wq991"></a>
<h4 id="wq991">Example 7</h4>
<p>This example names the expression SAL+BONUS+COMM as TOTAL_PAY:</p>
<pre class="xmp"> <span class="bold">SELECT</span> SALARY+BONUS+COMM <span class="bold">AS</span> TOTAL_PAY
<span class="bold">FROM</span> EMPLOYEE
<span class="bold">ORDER BY</span> TOTAL_PAY</pre>
<a name="wq992"></a>
<h4 id="wq992">Example 8</h4>
<p>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.</p>
<p>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.</p>
<pre class="xmp"> <span class="bold">WITH</span>
DINFO (DEPTNO, AVGSALARY, EMPCOUNT) <span class="bold">AS</span>
<span class="bold">(SELECT</span> OTHERS.WORKDEPT, <span class="bold">AVG(</span>OTHERS.SALARY<span class="bold">)</span>, <span class="bold">COUNT(*)</span>
<span class="bold">FROM</span> EMPLOYEE OTHERS
<span class="bold">GROUP BY</span> OTHERS.WORKDEPT<span class="bold">),</span>
DINFOMAX <span class="bold">AS</span>
<span class="bold">(SELECT MAX(</span>AVGSALARY<span class="bold">) AS</span> AVGMAX
<span class="bold">FROM</span> DINFO<span class="bold">)</span>
<span class="bold">SELECT</span> THIS_EMP.EMPNO, THIS_EMP.SALARY, DINFO.AVGSALARY, DINFO.EMPCOUNT,
DINFOMAX.AVGMAX
<span class="bold">FROM</span> EMPLOYEE THIS_EMP, DINFO, DINFOMAX
<span class="bold">WHERE</span> THIS_EMP.JOB = 'SALESREP'
<span class="bold">AND</span> THIS_EMP.WORKDEPT = DINFO.DEPTNO</pre>
<hr /><br />
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstmark.htm">Previous Page</a> | <a href="rbafzmststates.htm">Next Page</a> | <a href="rbafzmst02.htm#wq1">Contents</a> |
<a href="rbafzmstindex.htm#index">Index</a> ]
<a id="Bot_Of_Page" name="Bot_Of_Page"></a>
</body>
</html>