125 lines
7.0 KiB
HTML
125 lines
7.0 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="Use the OPTIMIZE clause" />
|
||
<meta name="abstract" content="If an application is not going to retrieve the entire result table for a cursor, using the OPTIMIZE clause can improve performance. The query optimizer modifies the cost estimates to retrieve the subset of rows using the value specified on the OPTIMIZE clause." />
|
||
<meta name="description" content="If an application is not going to retrieve the entire result table for a cursor, using the OPTIMIZE clause can improve performance. The query optimizer modifies the cost estimates to retrieve the subset of rows using the value specified on the OPTIMIZE clause." />
|
||
<meta name="DC.Relation" scheme="URI" content="progtech.htm" />
|
||
<meta name="DC.Relation" scheme="URI" content="../db2/rbafzmstintsel.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="impopt" />
|
||
<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>Use the OPTIMIZE clause</title>
|
||
</head>
|
||
<body id="impopt"><a name="impopt"><!-- --></a>
|
||
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
||
<h1 class="topictitle1">Use the OPTIMIZE clause</h1>
|
||
<div><p>If an application is not going to retrieve the entire result table
|
||
for a cursor, using the OPTIMIZE clause can improve performance. The query
|
||
optimizer modifies the cost estimates to retrieve the subset of rows using
|
||
the value specified on the OPTIMIZE clause.</p>
|
||
<div class="section"><p>Assume that the following query returns 1000 rows: </p>
|
||
<pre>EXEC SQL
|
||
<strong>DECLARE</strong> C1 <strong>CURSOR FOR</strong>
|
||
<strong>SELECT</strong> EMPNO, LASTNAME, WORKDEPT
|
||
<strong>FROM</strong> CORPDATA.EMPLOYEE
|
||
<strong>WHERE</strong> WORKDEPT = 'A00'
|
||
<strong>ORDER BY</strong> LASTNAME
|
||
<strong>OPTIMIZE FOR</strong> 100 <strong>ROWS</strong>
|
||
END EXEC.
|
||
</pre>
|
||
</div>
|
||
<div class="section"> <div class="note"><span class="notetitle">Note:</span> The values that can be used for the OPTIMIZE clause above
|
||
are 1–9999999 or ALL.</div>
|
||
</div>
|
||
<div class="section"><p>The optimizer calculates the following costs.</p>
|
||
</div>
|
||
<div class="section"><p>The optimize ratio = optimize for n rows value / estimated number
|
||
of rows in answer set.</p>
|
||
</div>
|
||
<div class="example"> <pre>Cost using a temporarily created index:
|
||
|
||
Cost to retrieve answer set rows
|
||
+ Cost to create the index
|
||
+ Cost to retrieve the rows again
|
||
with a temporary index * optimize ratio
|
||
|
||
Cost using a SORT:
|
||
|
||
Cost to retrieve answer set rows
|
||
+ Cost for SORT input processing
|
||
+ Cost for SORT output processing * optimize ratio
|
||
|
||
|
||
Cost using an existing index:
|
||
|
||
Cost to retrieve answer set rows
|
||
using an existing index * optimize ratio
|
||
</pre>
|
||
</div>
|
||
<div class="section"><p>In the previous examples, the estimated cost to sort or to create
|
||
an index is not adjusted by the optimize ratio. This enables the optimizer
|
||
to balance the optimization and preprocessing requirements. If the optimize
|
||
number is larger than the number of rows in the result table, no adjustments
|
||
are made to the cost estimates. If the OPTIMIZE clause is not specified for
|
||
a query, a default value is used based on the statement type, value of ALWCPYDTA
|
||
specified, or output device.</p>
|
||
</div>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" width="100%" frame="hsides" border="1" rules="all"><thead align="left"><tr><th align="left" valign="bottom" width="33.33333333333333%" id="d0e68">Statement Type</th>
|
||
<th align="left" valign="bottom" width="33.33333333333333%" id="d0e70">ALWCPYDTA(*OPTIMIZE)</th>
|
||
<th align="left" valign="bottom" width="33.33333333333333%" id="d0e72">ALWCPYDTA(*YES or *NO)</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e68 ">DECLARE CURSOR</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e70 ">The number or rows in the result table.</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e72 ">3% or the number of rows in the result table.</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e68 ">Embedded Select</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e70 ">2</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e72 ">2</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e68 ">INTERACTIVE Select output to display</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e70 ">3% or the number of rows in the result table.</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e72 ">3% or the number of rows in the result table.</td>
|
||
</tr>
|
||
<tr><td align="left" valign="top" width="33.33333333333333%" headers="d0e68 ">INTERACTIVE Select output to printer or database
|
||
table</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e70 ">The number of rows in the result table.</td>
|
||
<td align="left" valign="top" width="33.33333333333333%" headers="d0e72 ">The number of rows in the result table.</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
<div class="section"><p>The OPTIMIZE clause influences the optimization of a query: </p>
|
||
<ul><li>To use an existing index (by specifying a small number).</li>
|
||
<li>To enable the creation of an index or to run a sort or a hash by specifying
|
||
a large number of possible rows in the answer set.</li>
|
||
</ul>
|
||
</div>
|
||
</div>
|
||
<div>
|
||
<div class="familylinks">
|
||
<div class="parentlink"><strong>Parent topic:</strong> <a href="progtech.htm" title="By changing the coding of your queries, you can improve their performance.">Programming techniques for database performance</a></div>
|
||
</div>
|
||
<div class="relinfo"><strong>Related information</strong><br />
|
||
<div><a href="../db2/rbafzmstintsel.htm">select-statement</a></div>
|
||
</div>
|
||
</div>
|
||
</body>
|
||
</html> |