246 lines
13 KiB
HTML
246 lines
13 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="Details on the MQT matching algorithm" />
|
|
<meta name="abstract" content="What follows is a generalized discussion of how the MQT matching algorithm works." />
|
|
<meta name="description" content="What follows is a generalized discussion of how the MQT matching algorithm works." />
|
|
<meta name="DC.Relation" scheme="URI" content="rzajqmqt.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rzajqmqtsupport.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="rzajqmqtalgorithm" />
|
|
<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>Details on the MQT matching algorithm</title>
|
|
</head>
|
|
<body id="rzajqmqtalgorithm"><a name="rzajqmqtalgorithm"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Details on the MQT matching algorithm</h1>
|
|
<div><p>What follows is a generalized discussion of how the MQT matching
|
|
algorithm works.</p>
|
|
<div class="section"><p>The tables specified in the query and the MQT are examined. If
|
|
the MQT and the query specify the same tables, then the MQT can potentially
|
|
be used and matching continues. If the MQT references tables not referenced
|
|
in the query, then the unreferenced table is examined to determine if it is
|
|
a parent table in referential integrity constraint. If the foreign key is
|
|
non-nullable and the two tables are joined using a primary key or foreign
|
|
key equal predicate, then the MQT can still be potentially used.</p>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">Example 3</h4><p>The MQT contains less tables than the
|
|
query: </p>
|
|
<pre>SELECT D.deptname, p.projname, sum(E.salary)
|
|
FROM DEPARTMENT D, EMPLOYEE E, EMPPROJACT EP, PROJECT P
|
|
WHERE D.deptno=E.workdept AND E.Empno=ep.empno
|
|
AND ep.projno=p.projno
|
|
GROUP BY D.DEPTNAME, p.projname</pre>
|
|
<p>Create an MQT based on the
|
|
query above: </p>
|
|
<pre>CREATE TABLE MQT3
|
|
AS (SELECT D.deptname, sum(E.salary) as sum_sal, e.workdept, e.empno
|
|
FROM DEPARTMENT D, EMPLOYEE E
|
|
WHERE D.deptno=E.workdept
|
|
GROUP BY D.Deptname, e.workdept, e.empno)
|
|
DATA INITIALLY IMMEDIATE REFRESH DEFERRED
|
|
ENABLE QUERY OPTIMIZATION
|
|
MAINTAINED BY USER</pre>
|
|
<p>The rewritten query looks like this: </p>
|
|
<pre>SELECT M.deptname, p.projname, SUM(M.sum_sal)
|
|
FROM MQT3 M, EMPPROJACT EP, PROJECT P
|
|
WHERE M.Empno=ep.empno AND ep.projno=p.projno
|
|
GROUP BY M.deptname, p.projname</pre>
|
|
</div>
|
|
<div class="section"><p>All predicates specified in the MQT, must also be specified in
|
|
the query. The query may contain additional predicates. Predicates specified
|
|
in the MQT must match exactly the predicates in the query. Any additional
|
|
predicates specified in the query, but not in the MQT must be able to be derived
|
|
from columns projected from the MQT. See previous example 1.</p>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">Example 4</h4><p>Set the total salary for all departments
|
|
that are located in 'NY'. </p>
|
|
<pre>SELECT D.deptname, sum(E.salary)
|
|
FROM DEPARTMENT D, EMPLOYEE E
|
|
WHERE D.deptno=E.workdept AND D.location = ?
|
|
GROUP BY D.Deptname</pre>
|
|
<p>Create an MQT based on the query above: </p>
|
|
<pre>CREATE TABLE MQT4
|
|
AS (SELECT D.deptname, D.location, sum(E.salary) as sum_sal
|
|
FROM DEPARTMENT D, EMPLOYEE E
|
|
WHERE D.deptno=E.workdept AND D.location = 'NY'
|
|
GROUP BY D.deptnamet, D.location)
|
|
DATA INITIALLY IMMEDIATE REFRESH DEFERRED
|
|
ENABLE QUERY OPTIMIZATION
|
|
MAINTAINED BY USER</pre>
|
|
<p><img src="./delta.gif" alt="Start of change" />In this example, the constant
|
|
'NY' was replaced by a parameter marker and the MQT also had the local selection
|
|
of location='NY' applied to it when the MQT was populated. The MQT matching
|
|
algorithm matches the parameter marker and to the constant 'NY' in the predicate
|
|
D.Location=?. It verifies that the values of the parameter marker is the same
|
|
as the constant in the MQT; therefore the MQT can be used.<img src="./deltaend.gif" alt="End of change" /></p>
|
|
<p><img src="./delta.gif" alt="Start of change" />The
|
|
MQT matching algorithm will also attempt to match where the predicates between
|
|
the MQT and the query are not exactly the same. For example if the MQT has
|
|
a predicate SALARY > 50000 and the query has the predicate SALARY > 70000,
|
|
the MQT contains the rows necessary to run the query. The MQT will be used
|
|
in the query, but the predicate SALARY > 70000 is left as selection in the
|
|
query, so SALARY must be a column of the MQT.<img src="./deltaend.gif" alt="End of change" /></p>
|
|
</div>
|
|
<div class="section"><h4 class="sectiontitle">Example 5</h4><pre>SELECT D.deptname, sum(E.salary)
|
|
FROM DEPARTMENT D, EMPLOYEE E
|
|
WHERE D.deptno=E.workdept AND D.location = 'NY'
|
|
GROUP BY D.deptname</pre>
|
|
<p>Create an MQT based on the query above: </p>
|
|
<pre>CREATE TABLE MQT5
|
|
AS (SELECT D.deptname, E.salary
|
|
FROM DEPARTMENT D, EMPLOYEE E
|
|
WHERE D.deptno=E.workdept)
|
|
DATA INITIALLY IMMEDIATE REFRESH DEFERRED
|
|
ENABLE QUERY OPTIMIZATION
|
|
MAINTAINED BY USER</pre>
|
|
<p>In this example, since D.Location is not
|
|
a column of the MQT, the user query local selection predicate Location='NY'
|
|
cannot be determined, so the MQT cannot be used.</p>
|
|
</div>
|
|
<div class="section"><p>If the MQT contains grouping, then the query must be a grouping
|
|
query. The simplest case is where the MQT and the query specify the same
|
|
list of grouping columns and column functions. In some cases if the MQT specifies
|
|
a list of group by columns that is a superset of query group by columns, the
|
|
query can be rewritten to do a step called regrouping. This will reaggreate
|
|
the groups of the MQT, into the groups required by the query. When regrouping
|
|
is required, the column functions need to be recomputed. The table below
|
|
shows the supported regroup expressions. </p>
|
|
<p>The regroup new expression/aggregation
|
|
rules are:</p>
|
|
|
|
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 1. Expression/aggregation rules for MQTs</caption><thead align="left"><tr valign="bottom"><th valign="bottom" id="d0e76">Query</th>
|
|
<th valign="bottom" id="d0e78">MQT</th>
|
|
<th valign="bottom" id="d0e80">Final query</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td valign="top" headers="d0e76 ">COUNT(*)</td>
|
|
<td valign="top" headers="d0e78 ">COUNT(*) as cnt</td>
|
|
<td valign="top" headers="d0e80 ">SUM(cnt)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(*)</td>
|
|
<td valign="top" headers="d0e78 ">COUNT(C2) as cnt2 (where c2 is non-nullable)</td>
|
|
<td valign="top" headers="d0e80 ">SUM(cnt2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(c1)</td>
|
|
<td valign="top" headers="d0e78 ">COUNT(c1) as cnt</td>
|
|
<td valign="top" headers="d0e80 ">SUM(cnt)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(C1) (where C1 is non-nullable)</td>
|
|
<td valign="top" headers="d0e78 ">COUNT(C2) as cnt2 (where C2 is non-nullable)</td>
|
|
<td valign="top" headers="d0e80 ">SUM(cnt2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(distinct C1)</td>
|
|
<td valign="top" headers="d0e78 ">C1 as group_c1 (where C1 is a grouping column)</td>
|
|
<td valign="top" headers="d0e80 ">COUNT(group_C1)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(distinct C1) </td>
|
|
<td valign="top" headers="d0e78 ">where C1 is not a grouping column </td>
|
|
<td valign="top" headers="d0e80 ">MQT not usable</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(C2) where C2 is from a table not in the MQT </td>
|
|
<td valign="top" headers="d0e78 ">COUNT(*) as cnt</td>
|
|
<td valign="top" headers="d0e80 ">cnt*COUNT(C2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">COUNT(distinct C2) where C2 is from a table not in
|
|
the MQT </td>
|
|
<td valign="top" headers="d0e78 ">Not applicable</td>
|
|
<td valign="top" headers="d0e80 ">COUNT(distinct C2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">SUM(C1) </td>
|
|
<td valign="top" headers="d0e78 ">SUM(C1) as sm </td>
|
|
<td valign="top" headers="d0e80 ">SUM(sm)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">SUM(C1) </td>
|
|
<td valign="top" headers="d0e78 ">C1 as group_c1, COUNT(*) as cnt (where C1 is a grouping
|
|
column) </td>
|
|
<td valign="top" headers="d0e80 ">SUM(group_c1 * cnt)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">SUM(C2) where C2 is from a table not in the MQT </td>
|
|
<td valign="top" headers="d0e78 ">COUNT(*) as cnt</td>
|
|
<td valign="top" headers="d0e80 ">cnt*SUM(C2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">SUM(distinct C1) </td>
|
|
<td valign="top" headers="d0e78 ">C1 as group_c1 (where C1 is a grouping column) </td>
|
|
<td valign="top" headers="d0e80 ">SUM(group_C1)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">SUM(distinct C1) </td>
|
|
<td valign="top" headers="d0e78 ">where C1 is not a grouping column </td>
|
|
<td valign="top" headers="d0e80 ">MQT not usable</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">SUM(distinct C2) where C2 is from a table not in the
|
|
MQT </td>
|
|
<td valign="top" headers="d0e78 ">Not applicable</td>
|
|
<td valign="top" headers="d0e80 ">SUM(distinct C2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">MAX(C1) </td>
|
|
<td valign="top" headers="d0e78 ">MAX(C1) as mx</td>
|
|
<td valign="top" headers="d0e80 ">MAX(mx)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">MAX(C1) </td>
|
|
<td valign="top" headers="d0e78 ">C1 as group_C1 (where C1 is a grouping column)</td>
|
|
<td valign="top" headers="d0e80 ">MAX(group_c1)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">MAX(C2) where C2 is from a table not in the MQT </td>
|
|
<td valign="top" headers="d0e78 ">Not applicable</td>
|
|
<td valign="top" headers="d0e80 ">MAX(C2)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">MIN(C1) </td>
|
|
<td valign="top" headers="d0e78 ">MIN(C1) as mn</td>
|
|
<td valign="top" headers="d0e80 ">MIN(mn)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">MIN(C1) </td>
|
|
<td valign="top" headers="d0e78 ">C1 as group_C1 (where C1 is a grouping column)</td>
|
|
<td valign="top" headers="d0e80 ">MIN(group_c1)</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e76 ">MIN(C2) where C2 is from a table not in the MQT </td>
|
|
<td valign="top" headers="d0e78 ">Not applicable</td>
|
|
<td valign="top" headers="d0e80 ">MIN(C2)</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</div>
|
|
<p>AVG, STDDEV, STDDEV_SAMP, VARIANCE_SAMPand VAR_POP are calculated
|
|
using combinations of COUNT and SUM. If AVG, STDDEV, or VAR_POP are included
|
|
in the MQT and regroup requires recalculation of these functions, the MQT
|
|
cannot be used. It is recommended that the MQT only use COUNT, SUM, MIN,
|
|
and MAX. If the query contains AVG, STDDEV, or VAR_POP, it can be recalculated
|
|
using COUNT and SUM.</p>
|
|
</div>
|
|
<div class="section"><p>If the FETCH FIRST N ROWS clause is specified in the MQT, then
|
|
a FETCH FIRST N ROWS clause must also be specified in the query and the number
|
|
of rows specified for the MQT must be greater than or equal to the number
|
|
of rows specified in the query. It is not recommended that a MQT contain
|
|
the FETCH FIRST N ROWS clause.</p>
|
|
</div>
|
|
<div class="section"><p>The ORDER BY clause on the MQT can be used to order the data in
|
|
the MQT if a REFRESH TABLE is run. It is ignored during MQT matching and
|
|
if the query contains an ORDER BY clause, it will be part of the rewritten
|
|
query.</p>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="rzajqmqt.htm" title="Materialized query tables (MQTs) (also referred to as automatic summary tables or materialized views) can provide performance enhancements for queries.">Materialized query table optimization</a></div>
|
|
</div>
|
|
<div class="relref"><strong>Related reference</strong><br />
|
|
<div><a href="rzajqmqtsupport.htm" title="Although a MQT can contain almost any query, the optimizer only supports a limited set of query functions when matching MQTs to user specified queries. The user specified query and the MQT query must both be supported by the SQE optimizer.">MQT supported function</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |