112 lines
6.4 KiB
HTML
112 lines
6.4 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="Optimizing grouping by using index skip key processing" />
|
|
<meta name="abstract" content="Index Skip Key processing can be used when grouping with the keyed sequence implementation algorithm which uses an existing index. It is a specialized version of ordered grouping that processes very few records in each group rather than all records in each group." />
|
|
<meta name="description" content="Index Skip Key processing can be used when grouping with the keyed sequence implementation algorithm which uses an existing index. It is a specialized version of ordered grouping that processes very few records in each group rather than all records in each group." />
|
|
<meta name="DC.Relation" scheme="URI" content="groupopt.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="rzajqgroupidx" />
|
|
<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>Optimizing grouping by using index skip key processing</title>
|
|
</head>
|
|
<body id="rzajqgroupidx"><a name="rzajqgroupidx"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Optimizing grouping by using index skip key processing</h1>
|
|
<div><p>Index Skip Key processing can be used when grouping with the keyed
|
|
sequence implementation algorithm which uses an existing index. It is a specialized
|
|
version of ordered grouping that processes very few records in each group
|
|
rather than all records in each group.</p>
|
|
<div class="section"><p>The index skip key processing algorithm:</p>
|
|
</div>
|
|
<div class="section"> <ol><li>Uses the index to position to a group and</li>
|
|
<li>finds the first row matching the selection criteria for the group, and
|
|
if specified the first non-null MIN or MAX value in the group</li>
|
|
<li>Returns the group to the user</li>
|
|
<li>"Skip" to the next group and repeat processing</li>
|
|
</ol>
|
|
</div>
|
|
<div class="section"><p>This will improve performance by potentially not processing all
|
|
index key values for a group.</p>
|
|
</div>
|
|
<div class="section"><p>Index skip key processing can be used: </p>
|
|
<ul><li>For single table queries using the keyed sequence grouping implementation
|
|
when: <ul><li>There are no column functions in the query, or</li>
|
|
<li>There is only a single MIN or MAX column function in the query and the
|
|
operand of the MIN or MAX is the next key column in the index after the grouping
|
|
columns. There can be no other grouping functions in the query. For the
|
|
MIN function, the key column must be an ascending key; for the MAX function,
|
|
the key column must be a descending key. If the query is whole table grouping,
|
|
the operand of the MIN or MAX must be the first key column. <div class="p">Example 1,
|
|
using SQL: <pre><strong>CREATE INDEX</strong> IX1 <strong>ON</strong> EMPLOYEE (SALARY DESC)
|
|
|
|
<strong>DECLARE</strong> C1 <strong>CURSOR FOR</strong>
|
|
<strong>SELECT MAX</strong>(SALARY) <strong>FROM</strong> EMPLOYEE;</pre>
|
|
</div>
|
|
<p>The query optimizer will chose to use the index IX1. The
|
|
SLIC runtime code will scan the index until it finds the first non-null value
|
|
for SALARY. Assuming that SALARY is not null, the runtime code will position
|
|
to the first index key and return that key value as the MAX of salary. No
|
|
more index keys will be processed.</p>
|
|
<div class="p">Example 2, using SQL: <pre><strong>CREATE INDEX</strong> IX2 <strong>ON</strong> EMPLOYEE (DEPT, JOB,SALARY)
|
|
|
|
<strong>DECLARE</strong> C1 <strong>CURSOR FOR</strong>
|
|
<strong>SELECT</strong> DEPT, <strong>MIN</strong>(SALARY)
|
|
<strong>FROM</strong> EMPLOYEE
|
|
<strong>WHERE</strong> JOB='CLERK'
|
|
<strong>GROUP BY</strong> DEPT</pre>
|
|
</div>
|
|
<p>The query optimizer will chose to use Index IX2. The database
|
|
manager will position to the first group for DEPT where JOB equals 'CLERK'
|
|
and will return the SALARY. The code will then skip to the next DEPT group
|
|
where JOB equals 'CLERK'.</p>
|
|
</li>
|
|
</ul>
|
|
</li>
|
|
<li>For join queries: <ul><li>All grouping columns must be from a single table.</li>
|
|
<li>For each dial there can be at most one MIN or MAX column function operand
|
|
that references the dial and no other column functions can exist in the query.</li>
|
|
<li>If the MIN or MAX function operand is from the same dial as the grouping
|
|
columns, then it uses the same rules as single table queries.</li>
|
|
<li>If the MIN or MAX function operand is from a different dial then the join
|
|
column for that dial must join to one of the grouping columns and the index
|
|
for that dial must contain the join columns followed by the MIN or MAX operand. <p>Example
|
|
1, using SQL: </p>
|
|
<pre><strong>CREATE INDEX</strong> IX1 <strong>ON</strong> DEPARTMENT(DEPTNAME)
|
|
|
|
<strong>CREATE INDEX</strong> IX2 <strong>ON</strong> EMPLOYEE(WORKDEPT, SALARY)
|
|
|
|
<strong>DECLARE</strong> C1 <strong>CURSOR FOR</strong>
|
|
<strong>SELECT</strong> DEPTNAME, <strong>MIN</strong>(SALARY)
|
|
<strong>FROM</strong> DEPARTMENT, EMPLOYEE
|
|
<strong>WHERE</strong> DEPARTMENT.DEPTNO=EMPLOYEE.WORKDEPT
|
|
<strong>GROUP BY</strong> DEPARTMENT.DEPTNO;
|
|
</pre>
|
|
</li>
|
|
</ul>
|
|
</li>
|
|
</ul>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="groupopt.htm" title="DB2 Universal Database for iSeries has certain techniques to use when the optimizer encounters grouping. The query optimizer chooses its methods for optimizing your query.">Grouping optimization</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |