233 lines
16 KiB
HTML
233 lines
16 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="Implementation and optimization of a single file query with DB2 Multisystem" />
|
|
<meta name="abstract" content="To do a single file query, the system where the query was specified, the coordinator node, determines the nodes of the file to which to send the query. Those nodes run the query and return the queried records to the coordinator node." />
|
|
<meta name="description" content="To do a single file query, the system where the query was specified, the coordinator node, determines the nodes of the file to which to send the query. Those nodes run the query and return the queried records to the coordinator node." />
|
|
<meta name="DC.subject" content="query, single file, optimization, implementation, single file query" />
|
|
<meta name="keywords" content="query, single file, optimization, implementation, single file query" />
|
|
<meta name="DC.Relation" scheme="URI" content="qqp.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="sfquery" />
|
|
<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>Implementation and optimization of a single file query with DB2 Multisystem</title>
|
|
</head>
|
|
<body id="sfquery"><a name="sfquery"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Implementation and optimization of a single file query with DB2<sup>®</sup> Multisystem</h1>
|
|
<div><p>To do a single file query, the system where the query was specified,
|
|
the coordinator node, determines the nodes of the file to which to send the
|
|
query. Those nodes run the query and return the queried records to the coordinator
|
|
node.</p>
|
|
<div class="section"><p>All of the examples in this chapter use the following distributed files:
|
|
DEPARTMENT and EMPLOYEE. The node group for these files consists of SYSA,
|
|
SYSB, and SYSC. The data is partitioned on the department number.</p>
|
|
<div class="p">The
|
|
following SQL statement creates the DEPARTMENT distributed file. <pre>CREATE TABLE DEPARTMENT
|
|
(DEPTNO CHAR(3) NOT NULL,
|
|
DEPTNAME VARCHAR(20) NOT NULL,
|
|
MGRNO CHAR(6),
|
|
ADMRDEPT CHAR(3) NOT NULL)
|
|
IN NODGRP1 PARTITIONING KEY(DEPTNO)</pre>
|
|
</div>
|
|
|
|
<table cellpadding="4" cellspacing="0" border="1" class="tableborder"><tr><td>
|
|
<table cellpadding="4" cellspacing="0" summary="" border="0"><caption>Table 1. DEPARTMENT table</caption><thead align="left"><tr><th align="center" valign="bottom" width="11.923076923076923%" id="d0e54">Node</th>
|
|
<th align="center" valign="bottom" width="13.846153846153847%" id="d0e56">Record number</th>
|
|
<th align="center" valign="bottom" width="15.96153846153846%" id="d0e58">DEPTNO</th>
|
|
<th align="left" valign="bottom" width="20.192307692307693%" id="d0e60">DEPTNAME</th>
|
|
<th align="center" valign="bottom" width="17.884615384615383%" id="d0e62">MGRNO</th>
|
|
<th align="center" valign="bottom" width="20.192307692307693%" id="d0e64">ADMRDEPT</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td align="center" valign="top" width="11.923076923076923%" headers="d0e54 ">SYSA</td>
|
|
<td align="center" valign="top" width="13.846153846153847%" headers="d0e56 ">1</td>
|
|
<td align="center" valign="top" width="15.96153846153846%" headers="d0e58 ">A00</td>
|
|
<td align="left" valign="top" width="20.192307692307693%" headers="d0e60 ">Support services</td>
|
|
<td align="center" valign="top" width="17.884615384615383%" headers="d0e62 ">000010</td>
|
|
<td align="center" valign="top" width="20.192307692307693%" headers="d0e64 ">A00</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="11.923076923076923%" headers="d0e54 ">SYSB</td>
|
|
<td align="center" valign="top" width="13.846153846153847%" headers="d0e56 ">2</td>
|
|
<td align="center" valign="top" width="15.96153846153846%" headers="d0e58 ">A01</td>
|
|
<td align="left" valign="top" width="20.192307692307693%" headers="d0e60 ">Planning</td>
|
|
<td align="center" valign="top" width="17.884615384615383%" headers="d0e62 ">000010</td>
|
|
<td align="center" valign="top" width="20.192307692307693%" headers="d0e64 ">A00</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="11.923076923076923%" headers="d0e54 ">SYSC</td>
|
|
<td align="center" valign="top" width="13.846153846153847%" headers="d0e56 ">3</td>
|
|
<td align="center" valign="top" width="15.96153846153846%" headers="d0e58 ">B00</td>
|
|
<td align="left" valign="top" width="20.192307692307693%" headers="d0e60 ">Accounting</td>
|
|
<td align="center" valign="top" width="17.884615384615383%" headers="d0e62 ">000050</td>
|
|
<td align="center" valign="top" width="20.192307692307693%" headers="d0e64 ">B00</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="11.923076923076923%" headers="d0e54 ">SYSA</td>
|
|
<td align="center" valign="top" width="13.846153846153847%" headers="d0e56 ">4</td>
|
|
<td align="center" valign="top" width="15.96153846153846%" headers="d0e58 ">B01</td>
|
|
<td align="left" valign="top" width="20.192307692307693%" headers="d0e60 ">Programming</td>
|
|
<td align="center" valign="top" width="17.884615384615383%" headers="d0e62 ">000050</td>
|
|
<td align="center" valign="top" width="20.192307692307693%" headers="d0e64 ">B00</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</td></tr></table>
|
|
<div class="p">The following SQL statement creates the EMPLOYEE distributed file.
|
|
<pre>CREATE TABLE EMPLOYEE
|
|
(EMPNO CHAR(6) NOT NULL,
|
|
FIRSTNME VARCHAR(12) NOT NULL,
|
|
LASTNAME VARCHAR(15) NOT NULL,
|
|
WORKDEPT CHAR(3) NOT NULL,
|
|
JOB CHAR(8),
|
|
SALARY DECIMAL(9,2))
|
|
IN NODGRP1 PARTITIONING KEY(WORKDEPT)</pre>
|
|
</div>
|
|
|
|
<table cellpadding="4" cellspacing="0" border="1" class="tableborder"><tr><td>
|
|
<table cellpadding="4" cellspacing="0" summary="" width="100%" border="0"><caption>Table 2. EMPLOYEE table</caption><thead align="left"><tr><th align="center" valign="bottom" width="7.894736842105263%" id="d0e137">Node</th>
|
|
<th align="center" valign="bottom" width="13.157894736842104%" id="d0e139">Record number</th>
|
|
<th align="center" valign="bottom" width="13.157894736842104%" id="d0e141">EMPNO</th>
|
|
<th align="left" valign="bottom" width="13.157894736842104%" id="d0e143">FIRSTNME</th>
|
|
<th align="left" valign="bottom" width="13.157894736842104%" id="d0e145">LASTNAME</th>
|
|
<th align="center" valign="bottom" width="13.157894736842104%" id="d0e147">WORK DEPT</th>
|
|
<th align="left" valign="bottom" width="13.157894736842104%" id="d0e149">JOB</th>
|
|
<th align="center" valign="bottom" width="13.157894736842104%" id="d0e151">SALARY</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSA</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">1</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000010</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">Christine</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Haas</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">A00</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Manager</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">41250</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSA</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">2</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000020</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">Sally</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Kwan</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">A00</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Clerk</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">25000</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSB</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">3</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000030</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">John</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Geyer</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">A01</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Planner</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">35150</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSB</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">4</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000040</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">Irving</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Stern</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">A01</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Clerk</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">32320</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSC</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">5</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000050</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">Michael</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Thompson</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">B00</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Manager</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">38440</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSC</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">6</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000060</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">Eileen</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Henderson</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">B00</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Accountant</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">33790</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSA</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">7</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000070</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">Jennifer</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">Lutz</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">B01</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Programmer</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">42325</td>
|
|
</tr>
|
|
<tr><td align="center" valign="top" width="7.894736842105263%" headers="d0e137 ">SYSA</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e139 ">8</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e141 ">000080</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e143 ">David</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e145 ">White</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e147 ">B01</td>
|
|
<td align="left" valign="top" width="13.157894736842104%" headers="d0e149 ">Programmer</td>
|
|
<td align="center" valign="top" width="13.157894736842104%" headers="d0e151 ">36450</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</td></tr></table>
|
|
<p>What follows is a query using the above defined distributed file
|
|
EMPLOYEE, with index EMPIDX created over the field SALARY. The query is entered
|
|
on SYSA.</p>
|
|
<p>SQL statement:</p>
|
|
<pre> SELECT * FROM EMPLOYEE WHERE SALARY > 40000
|
|
</pre>
|
|
<p>OPNQRYF command:</p>
|
|
<pre> OPNQRYF FILE((EMPLOYEE)) QRYSLT('SALARY > 40000')</pre>
|
|
<p>In
|
|
this case, SYSA sends the above query to all the nodes of EMPLOYEE, including
|
|
SYSA. Each node runs the query and returns the records to SYSA. Because a
|
|
distributed index exists on field SALARY of file EMPLOYEE, optimization that
|
|
is done on each node decides whether to use the index.</p>
|
|
<p>In the next example,
|
|
the query is specified on SYSA, but the query is sent to a subset of the nodes
|
|
where the EMPLOYEE file exists. In this case, the query is run locally on
|
|
SYSA only.</p>
|
|
<p>SQL statement:</p>
|
|
<pre> SELECT * FROM EMPLOYEE WHERE WORKDEPT = 'A00'</pre>
|
|
<p>OPNQRYF command:</p>
|
|
<pre> OPNQRYF FILE((EMPLOYEE)) QRYSLT('WORKDEPT = 'A00')</pre>
|
|
<p>The distributed query optimizer determines that
|
|
there is an isolatable record selection, WORKDEPT = 'A00', involving the partitioning
|
|
key, WORKDEPT, for this query. The optimizer hashes the value 'A00' and based
|
|
on the hash value, finds the node at which all of the records satisfying this
|
|
condition are located. In this case, all of the records satisfying this condition
|
|
are on SYSA, thus the query is sent only to that node. Because the query originated
|
|
on SYSA, the query is run locally on SYSA.</p>
|
|
<p>The following conditions
|
|
subset the number of nodes at which a query runs:</p>
|
|
<ul><li>All fields of the partitioning key must be isolatable record selection</li>
|
|
<li>All predicates must use the equal (=) operator</li>
|
|
<li>All fields of the partitioning key must be compared to a
|
|
literal</li>
|
|
</ul>
|
|
<div class="note"><span class="notetitle">Note:</span> For performance reasons, you should specify record selection predicates
|
|
that match the partitioning key in order to direct the query to a particular
|
|
node. Record selection with scalar functions of NODENAME, PARTITION, and NODENUMBER
|
|
can also direct the query to specific nodes.</div>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="qqp.htm" title="This topic provides you with some guidelines for designing queries so that they use query resources more efficiently when you run queries that use distributed files.">Query design for performance with DB2 Multisystem</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |