132 lines
7.6 KiB
HTML
132 lines
7.6 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="Directed join with DB2 Multisystem" />
|
|
<meta name="abstract" content="In the directed join, the partitioning keys of at least one of the files are used as the join fields." />
|
|
<meta name="description" content="In the directed join, the partitioning keys of at least one of the files are used as the join fields." />
|
|
<meta name="DC.subject" content="query, directed join, join, directed, example, directed join query" />
|
|
<meta name="keywords" content="query, directed join, join, directed, example, directed join query" />
|
|
<meta name="DC.Relation" scheme="URI" content="joins.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="directed" />
|
|
<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>Directed join with DB2 Multisystem</title>
|
|
</head>
|
|
<body id="directed"><a name="directed"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Directed join with DB2<sup>®</sup> Multisystem</h1>
|
|
<div><p>In the directed join, the partitioning keys of at least one of
|
|
the files are used as the join fields.</p>
|
|
<div class="section"><p>The join fields do not match the partitioning
|
|
keys of the other files. Records of one file are directed to or sent to the
|
|
nodes of the second file based on the hashing of the join field values using
|
|
the partition map and node group of the second file. As soon as the records
|
|
have been moved to the nodes of the second file through a temporary distributed
|
|
file, a collocated join is used to join the data. This method is valid only
|
|
for equijoin queries where all fields of the partitioning key are join fields
|
|
for at least one of the files.</p>
|
|
<p>In the following query, join field (WORKDEPT)
|
|
is the partitioning key for file EMPLOYEE; however, join field (ADMRDEPT)
|
|
is not the partitioning key for DEPARTMENT. If the join was attempted without
|
|
moving the data, result records would be missing because record 2 of DEPARTMENT
|
|
should be joined to records 1 and 2 of EMPLOYEE and these records are stored
|
|
on different nodes. </p>
|
|
<p>SQL statement:</p>
|
|
<pre> SELECT DEPTNAME, FIRSTNME, LASTNAME
|
|
FROM DEPARTMENT, EMPLOYEE
|
|
WHERE ADMRDEPT = WORKDEPT AND JOB = 'Manager'</pre>
|
|
<p>OPNQRYF
|
|
command:</p>
|
|
<pre> OPNQRYF FILE((DEPARTMENT) (EMPLOYEE))
|
|
FORMAT(JOINFMT)
|
|
QRYSLT('JOB *EQ 'Manager')
|
|
JFLD((ADMRDEPT WORKDEPT *EQ))</pre>
|
|
<p>The
|
|
records of DEPARTMENT that are needed to run the query are read, and the data
|
|
in ADMRDEPT is hashed using the partitioning map and the node group of EMPLOYEE.
|
|
A temporary file is created and looks like this:</p>
|
|
|
|
<table cellpadding="4" cellspacing="0" border="1" class="tableborder"><tr><td>
|
|
<table cellpadding="4" cellspacing="0" summary="" border="0"><caption>Table 1. A
|
|
temporary table</caption><thead align="left"><tr><th align="center" valign="bottom" width="25%" id="d0e76">Old node</th>
|
|
<th align="center" valign="bottom" width="25%" id="d0e78">New node</th>
|
|
<th align="left" valign="bottom" width="25%" id="d0e80">DEPTNAME</th>
|
|
<th align="center" valign="bottom" width="25%" id="d0e82">ADMRDEPT (New partitioning key)</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td align="center" valign="top" width="25%" headers="d0e76 ">SYSA</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e78 ">SYSA</td>
|
|
<td align="left" valign="top" width="25%" headers="d0e80 ">Support services</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e82 ">A00</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="25%" headers="d0e76 ">SYSB</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e78 ">SYSA</td>
|
|
<td align="left" valign="top" width="25%" headers="d0e80 ">Planning</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e82 ">A00</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="25%" headers="d0e76 ">SYSC</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e78 ">SYSC</td>
|
|
<td align="left" valign="top" width="25%" headers="d0e80 ">Accounting</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e82 ">B00</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="25%" headers="d0e76 ">SYSA</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e78 ">SYSC</td>
|
|
<td align="left" valign="top" width="25%" headers="d0e80 ">Programming</td>
|
|
<td align="center" valign="top" width="25%" headers="d0e82 ">B00</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</td></tr></table>
|
|
<p>This temporary table is joined to EMPLOYEE. The join works because
|
|
ADMRDEPT is partition compatible with WORKDEPT.</p>
|
|
|
|
<table cellpadding="4" cellspacing="0" border="1" class="tableborder"><tr><td>
|
|
<table cellpadding="4" cellspacing="0" summary="" border="0"><caption>Table 2. EMPLOYEE
|
|
joined table</caption><thead align="left"><tr><th align="left" valign="bottom" width="33.33333333333333%" id="d0e132">DEPTNAME</th>
|
|
<th align="left" valign="bottom" width="33.33333333333333%" id="d0e134">FIRSTNME</th>
|
|
<th align="left" valign="bottom" width="33.33333333333333%" id="d0e136">LASTNAME</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e132 ">Support services</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e134 ">Christine</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e136 ">Haas</td>
|
|
</tr>
|
|
<tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e132 ">Planning</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e134 ">Christine</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e136 ">Haas</td>
|
|
</tr>
|
|
<tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e132 ">Accounting</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e134 ">Michael</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e136 ">Thompson</td>
|
|
</tr>
|
|
<tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e132 ">Programming</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e134 ">Michael</td>
|
|
<td align="left" valign="top" width="33.33333333333333%" headers="d0e136 ">Thompson</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</td></tr></table>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="joins.htm" title="In addition to the performance considerations for nondistributed join queries, more performance considerations exist for queries involving distributed files.">Implementation and optimization of join operations with DB2 Multisystem</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |