ibm-information-center/dist/eclipse/plugins/i5OS.ic.sqlp_5.4.0.1/rbafyexsub1.htm

186 lines
9.2 KiB
HTML

<?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 lang="en-us" xml:lang="en-us">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<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="DC.Type" content="reference" />
<meta name="DC.Title" content="Example: Correlated subquery in a WHERE clause" />
<meta name="abstract" content="Suppose that you want a list of all the employees whose education levels are higher than the average education levels in their respective departments. To get this information, SQL must search the CORPDATA.EMPLOYEE table." />
<meta name="description" content="Suppose that you want a list of all the employees whose education levels are higher than the average education levels in their respective departments. To get this information, SQL must search the CORPDATA.EMPLOYEE table." />
<meta name="DC.subject" content="correlation, subqueries, example WHERE clause, subquery, correlated, example WHERE clause, examples, correlated subquery, WHERE clause" />
<meta name="keywords" content="correlation, subqueries, example WHERE clause, subquery, correlated, example WHERE clause, examples, correlated subquery, WHERE clause" />
<meta name="DC.Relation" scheme="URI" content="rbafycorrs.htm" />
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="DC.Format" content="XHTML" />
<meta name="DC.Identifier" content="rbafyexsub1" />
<meta name="DC.Language" 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. -->
<link rel="stylesheet" type="text/css" href="./ibmdita.css" />
<link rel="stylesheet" type="text/css" href="./ic.css" />
<title>Example: Correlated subquery in a WHERE clause</title>
</head>
<body id="rbafyexsub1"><a name="rbafyexsub1"><!-- --></a>
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
<h1 class="topictitle1">Example: Correlated subquery in a WHERE clause</h1>
<div><p>Suppose that you want a list of all the employees whose education
levels are higher than the average education levels in their respective departments.
To get this information, SQL must search the CORPDATA.EMPLOYEE table.</p>
<div class="section"><p>For each employee in the table, SQL needs to compare the employee's
education level to the average education level for the employee's department.
In the subquery, you tell SQL to calculate the average education level for
the department number in the current row. For example: </p>
<pre> <strong>SELECT</strong> EMPNO, LASTNAME, WORKDEPT, EDLEVEL
<strong>FROM</strong> CORPDATA.EMPLOYEE X
<strong>WHERE</strong> EDLEVEL &gt;
(<strong>SELECT AVG</strong>(EDLEVEL)
<strong>FROM</strong> CORPDATA.EMPLOYEE
<strong>WHERE</strong> WORKDEPT = X.WORKDEPT)</pre>
</div>
<div class="section"><p>A correlated subquery looks like an uncorrelated one, except for
the presence of one or more correlated references. In the example, the single
correlated reference is the occurrence of X.WORKDEPT in the subselect's FROM
clause. Here, the qualifier <em>X</em> is the correlation name defined in the
FROM clause of the outer SELECT statement. In that clause, <em>X</em> is introduced
as the correlation name of the table CORPDATA.EMPLOYEE.</p>
</div>
<div class="section"><p>Now, consider what happens when the subquery is executed for a
given row of CORPDATA.EMPLOYEE. Before it is executed, the occurrence of X.WORKDEPT
is replaced with the value of the WORKDEPT column for that row. Suppose, for
example, that the row is for CHRISTINE I HAAS. Her work department is A00,
which is the value of WORKDEPT for this row. The subquery executed for this
row is:</p>
<pre> (<strong>SELECT AVG</strong>(EDLEVEL)
<strong>FROM</strong> CORPDATA.EMPLOYEE
<strong>WHERE</strong> WORKDEPT = 'A00')</pre>
</div>
<div class="section"><p>Thus, for the row considered, the subquery produces the average
education level of Christine's department. This is then compared in the outer
statement to Christine's own education level. For some other row for which
WORKDEPT has a different value, that value appears in the subquery in place
of A00. For example, for the row for MICHAEL L THOMPSON, this value is B01,
and the subquery for his row delivers the average education level for department
B01.</p>
</div>
<div class="section"><p>The result table produced by the query has the following values: </p>
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="hsides" border="1" rules="all"><caption>Table 1. Result set for previous query</caption><thead align="left"><tr><th valign="top" id="d0e93">EMPNO</th>
<th valign="top" id="d0e95">LASTNAME</th>
<th valign="top" id="d0e97">WORKDEPT</th>
<th valign="top" id="d0e99">EDLEVEL</th>
</tr>
</thead>
<tbody><tr><td valign="top" headers="d0e93 ">000010</td>
<td valign="top" headers="d0e95 ">HAAS</td>
<td valign="top" headers="d0e97 ">A00</td>
<td valign="top" headers="d0e99 ">18</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000030</td>
<td valign="top" headers="d0e95 ">KWAN</td>
<td valign="top" headers="d0e97 ">C01</td>
<td valign="top" headers="d0e99 ">20</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000070</td>
<td valign="top" headers="d0e95 ">PULASKI</td>
<td valign="top" headers="d0e97 ">D21</td>
<td valign="top" headers="d0e99 ">16</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000090</td>
<td valign="top" headers="d0e95 ">HENDERSON</td>
<td valign="top" headers="d0e97 ">E11</td>
<td valign="top" headers="d0e99 ">16</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000110</td>
<td valign="top" headers="d0e95 ">LUCCHESSI</td>
<td valign="top" headers="d0e97 ">A00</td>
<td valign="top" headers="d0e99 ">19</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000160</td>
<td valign="top" headers="d0e95 ">PIANKA</td>
<td valign="top" headers="d0e97 ">D11</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000180</td>
<td valign="top" headers="d0e95 ">SCOUTTEN</td>
<td valign="top" headers="d0e97 ">D11</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000210</td>
<td valign="top" headers="d0e95 ">JONES</td>
<td valign="top" headers="d0e97 ">D11</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000220</td>
<td valign="top" headers="d0e95 ">LUTZ</td>
<td valign="top" headers="d0e97 ">D11</td>
<td valign="top" headers="d0e99 ">18</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000240</td>
<td valign="top" headers="d0e95 ">MARINO</td>
<td valign="top" headers="d0e97 ">D21</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000260</td>
<td valign="top" headers="d0e95 ">JOHNSON</td>
<td valign="top" headers="d0e97 ">D21</td>
<td valign="top" headers="d0e99 ">16</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000280</td>
<td valign="top" headers="d0e95 ">SCHNEIDER</td>
<td valign="top" headers="d0e97 ">E11</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000320</td>
<td valign="top" headers="d0e95 ">MEHTA</td>
<td valign="top" headers="d0e97 ">E21</td>
<td valign="top" headers="d0e99 ">16</td>
</tr>
<tr><td valign="top" headers="d0e93 ">000340</td>
<td valign="top" headers="d0e95 ">GOUNOT</td>
<td valign="top" headers="d0e97 ">E21</td>
<td valign="top" headers="d0e99 ">16</td>
</tr>
<tr><td valign="top" headers="d0e93 ">200010</td>
<td valign="top" headers="d0e95 ">HEMMINGER</td>
<td valign="top" headers="d0e97 ">A00</td>
<td valign="top" headers="d0e99 ">18</td>
</tr>
<tr><td valign="top" headers="d0e93 ">200220</td>
<td valign="top" headers="d0e95 ">JOHN</td>
<td valign="top" headers="d0e97 ">D11</td>
<td valign="top" headers="d0e99 ">18</td>
</tr>
<tr><td valign="top" headers="d0e93 ">200240</td>
<td valign="top" headers="d0e95 ">MONTEVERDE</td>
<td valign="top" headers="d0e97 ">D21</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">200280</td>
<td valign="top" headers="d0e95 ">SCHWARTZ</td>
<td valign="top" headers="d0e97 ">E11</td>
<td valign="top" headers="d0e99 ">17</td>
</tr>
<tr><td valign="top" headers="d0e93 ">200340</td>
<td valign="top" headers="d0e95 ">ALONZO</td>
<td valign="top" headers="d0e97 ">E21</td>
<td valign="top" headers="d0e99 ">16</td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafycorrs.htm" title="You can write a subquery that SQL might need to re-evaluate as it examines each new row (WHERE clause) or group of rows (HAVING clause) in the outer-level SELECT. This is called a correlated subquery.">Correlated subqueries</a></div>
</div>
</div>
</body>
</html>