111 lines
7.0 KiB
HTML
111 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="Create and alter a materialized query table" />
|
|
<meta name="abstract" content="A materialized query table is a table whose definition is based on the result of a query. As such, the materialized query table typically contains precomputed results based on the data existing in the table or tables that its definition is based on." />
|
|
<meta name="description" content="A materialized query table is a table whose definition is based on the result of a query. As such, the materialized query table typically contains precomputed results based on the data existing in the table or tables that its definition is based on." />
|
|
<meta name="DC.subject" content="CREATE TABLE statement, materialized query table, REFRESH TABLE statement, statements, REFRESH TABLE statement, examples, CREATE TABLE AS materialized query table statement" />
|
|
<meta name="keywords" content="CREATE TABLE statement, materialized query table, REFRESH TABLE statement, statements, REFRESH TABLE statement, examples, CREATE TABLE AS materialized query table statement" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafysqltech.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafycontables.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="rbafymqt" />
|
|
<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>Create and alter a materialized query table</title>
|
|
</head>
|
|
<body id="rbafymqt"><a name="rbafymqt"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Create and alter a materialized query table</h1>
|
|
<div><p>A materialized query table is a table whose definition is based
|
|
on the result of a query. As such, the materialized query table typically
|
|
contains precomputed results based on the data existing in the table or tables
|
|
that its definition is based on.</p>
|
|
<div class="section"><p>The optimizer will look at the materialized query
|
|
table and determine whether a query will run more efficiently against a materialized
|
|
query table than the base table or tables. If it will run faster, then the
|
|
query will run against the materialized query table. You can directly query
|
|
a materialized query table. For more information on how the optimizer uses
|
|
materialized query tables, see the <a href="../rzajq/rzajqkickoff.htm">Database
|
|
performance and query optimization</a> topic.</p>
|
|
</div>
|
|
<div class="section"><p>Assume a very large transaction table named TRANS contains one
|
|
row for each transaction processed by a company. The table is defined with
|
|
many columns. Create a materialized query table for the TRANS table that contains
|
|
daily summary data for the date and amount of a transaction by issuing the
|
|
following: </p>
|
|
<pre><strong>CREATE TABLE</strong> STRANS
|
|
<strong>AS (SELECT</strong> YEAR <strong>AS</strong> SYEAR, MONTH <strong>AS</strong> SMONTH, DAY <strong>AS</strong> SDAY, <strong>SUM</strong>(AMOUNT) <strong>AS</strong> SSUM
|
|
<strong>FROM</strong> TRANS
|
|
<strong>GROUP BY</strong> YEAR, MONTH, DAY )
|
|
<strong> DATA INITIALLY DEFERRED
|
|
REFRESH DEFERRED
|
|
MAINTAINED BY USER</strong></pre>
|
|
</div>
|
|
<div class="section"><p>This materialized query table specifies that the table is not
|
|
populated at the time that it is created by using the DATA INITIALLY DEFERRED
|
|
clause. REFRESH DEFERRED indicates that changes made to TRANS are not reflected
|
|
in STRANS. Additionally, this table is maintained by the user, enabling the
|
|
user to use ALTER, INSERT, DELETE, and UPDATE.</p>
|
|
</div>
|
|
<div class="section"><p>To populate the materialized query table or refresh the table
|
|
after it has already been populated, use the REFRESH TABLE statement. This
|
|
will cause the query associated with the materialized query table to be run
|
|
and the table filled with the results of the query. To populate table STRANS,
|
|
run the following statement: </p>
|
|
<pre><strong>REFRESH TABLE</strong> STRANS</pre>
|
|
</div>
|
|
<div class="section"><p>You can create a materialized query table from an existing base
|
|
table as long as the result of the select-statement provides a set of columns
|
|
that match the columns in the existing table (same number of columns and compatible
|
|
column definitions). For example, create a table TRANSCOUNT. Then, change
|
|
the base table TRANSCOUNT into a materialized query table:</p>
|
|
</div>
|
|
<div class="section"><p>To create the table:</p>
|
|
<pre><strong>CREATE TABLE</strong> TRANSCOUNT
|
|
(ACCTID <strong>SMALLINT NOT NULL</strong>,
|
|
LOCID <strong>SMALLINT</strong>,
|
|
YEAR <strong>DATE</strong>
|
|
CNT <strong>INTEGER</strong>)</pre>
|
|
<p>You can alter this table to be a materialized query table:</p>
|
|
<pre><strong>ALTER TABLE</strong> TRANSCOUNT
|
|
<strong>ADD MATERIALIZED QUERY</strong>
|
|
<strong>(SELECT</strong> ACCTID, LOCID, YEAR, <strong>COUNT</strong>(*) <strong>AS</strong> CNT
|
|
<strong>FROM</strong> TRANS
|
|
<strong>GROUP BY</strong> ACCTID, LOCID, YEAR )
|
|
<strong>DATA INITIALLY DEFERRED
|
|
REFRESH DEFERRED
|
|
MAINTAINED BY USER</strong></pre>
|
|
</div>
|
|
<div class="section"><p>Finally, you can change a materialized query table back to a base
|
|
table. For example: </p>
|
|
<pre><strong>ALTER TABLE</strong> TRANSCOUNT
|
|
<strong>DROP MATERIALIZED QUERY</strong></pre>
|
|
<p>In this example, the table
|
|
TRANSCOUNT is not dropped, but it is no longer a materialized query table.</p>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafysqltech.htm" title="Data definition language (DDL) describes the portion of SQL that allows you to create, alter, and destroy database objects. These database objects include schemas, tables, views, sequences, catalogs, indexes, and aliases.">Data definition language (DDL)</a></div>
|
|
</div>
|
|
<div class="relconcepts"><strong>Related concepts</strong><br />
|
|
<div><a href="rbafycontables.htm" title="A table is a two-dimensional arrangement of data consisting of rows and columns.">Tables, rows, and columns</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |