176 lines
9.4 KiB
HTML
176 lines
9.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="Create and use sequences" />
|
|
<meta name="abstract" content="A sequence is an object that allows you to generate values quickly and easily." />
|
|
<meta name="description" content="A sequence is an object that allows you to generate values quickly and easily." />
|
|
<meta name="DC.subject" content="sequences, create, CREATE SEQUENCE statement, statements, CREATE SEQUENCE statement, examples" />
|
|
<meta name="keywords" content="sequences, create, CREATE SEQUENCE statement, statements, CREATE SEQUENCE statement, examples" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafysqltech.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyidentsequence.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafy1sequence.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyidentsequence.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="rbafysequence" />
|
|
<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 use sequences</title>
|
|
</head>
|
|
<body id="rbafysequence"><a name="rbafysequence"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Create and use sequences</h1>
|
|
<div><p>A sequence is an object that allows you to generate values quickly
|
|
and easily.</p>
|
|
<div class="section"><p>Sequences are similar to identity columns in that they both generate
|
|
unique values. However, sequences are independent objects from a table. As
|
|
such, they are not tied to a column and are accessed separately. Additionally,
|
|
they are not treated as any part of a transaction's unit of work.</p>
|
|
</div>
|
|
<div class="section"><p>You create a sequence using the CREATE SEQUENCE statement. For
|
|
an example similar to the identity column example, create a sequence ORDER_SEQ: </p>
|
|
<pre><strong>CREATE SEQUENCE</strong> ORDER_SEQ
|
|
<strong>START WITH</strong> 500
|
|
<strong>INCREMENT BY</strong> 1
|
|
<strong>MAXVALUE</strong> 1000
|
|
<strong>CYCLE</strong>
|
|
<strong>CACHE 24</strong></pre>
|
|
<p>This sequence is defined with starting value of 500, incremented
|
|
by 1 for every use, and will recycle when the maximum value is reached. In
|
|
this example, the maximum value for the sequence is 1000. When this value
|
|
reaches 1000, it will restart at 500 again.</p>
|
|
</div>
|
|
<div class="section"><p>Once this sequence is created, you can insert values into a column
|
|
using the sequence. For example, insert the next value of the sequence ORDER_SEQ
|
|
into a table ORDERS with columns ORDERNO and CUSTNO. </p>
|
|
</div>
|
|
<div class="section"><p>First, create table ORDERS:</p>
|
|
<pre><strong>CREATE TABLE</strong> ORDERS
|
|
(ORDERNO<strong> SMALLINT NOT NULL,</strong>
|
|
CUSTNO <strong>SMALLINT);</strong></pre>
|
|
</div>
|
|
<div class="section"><p>Then, insert the sequence value:</p>
|
|
<pre><strong>INSERT INTO</strong> ORDERS (ORDERNO, CUSTNO)
|
|
<strong>VALUES</strong> (<strong>NEXT VALUE FOR</strong> ORDER_SEQ, 12)</pre>
|
|
</div>
|
|
<div class="section"><p>Running the following statement, returns the values in the columns: </p>
|
|
<pre><strong>SELECT * </strong>
|
|
<strong>FROM</strong> ORDERS</pre>
|
|
|
|
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 1. Results for SELECT from table
|
|
ORDERS</caption><thead align="left"><tr><th valign="top" id="d0e105">ORDERNO</th>
|
|
<th valign="top" id="d0e107">CUSTNO</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td valign="top" headers="d0e105 ">500</td>
|
|
<td valign="top" headers="d0e107 ">12</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</div>
|
|
<p>In this example, the next value for the sequence ORDER is inserted
|
|
into the ORDERNO column. Issue the INSERT statement again. Then run the SELECT.</p>
|
|
|
|
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 2. Results for SELECT from table ORDERS</caption><thead align="left"><tr><th valign="top" id="d0e125">ORDERNO</th>
|
|
<th valign="top" id="d0e127">CUSTNO</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td valign="top" headers="d0e125 ">500</td>
|
|
<td valign="top" headers="d0e127 ">12</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e125 ">501</td>
|
|
<td valign="top" headers="d0e127 ">12</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</div>
|
|
</div>
|
|
<div class="section"><p>You can also insert the previous value for sequence ORDER by using
|
|
the PREVIOUS VALUE expression. You can use NEXT VALUE and PREVIOUS VALUE in
|
|
the following expressions:</p>
|
|
<ul><li>Within the <em>select-clause</em> of a SELECT statement or SELECT INTO statement
|
|
as long as the statement does not contain a DISTINCT keyword, a GROUP BY clause,
|
|
an ORDER BY clause, a UNION keyword, an INTERSECT keyword, or EXCEPT keyword </li>
|
|
<li>Within a VALUES clause of an INSERT statement </li>
|
|
<li>Within the <em>select-clause</em> of the fullselect of an INSERT statement </li>
|
|
<li>Within the SET clause of a searched or positioned UPDATE statement, though
|
|
NEXT VALUE cannot be specified in the <em>select-clause</em> of the subselect
|
|
of an expression in the SET clause </li>
|
|
</ul>
|
|
</div>
|
|
<div class="section"><p>You can alter a sequence by issuing the ALTER SEQUENCE statement.
|
|
Sequences can be altered in the following ways:</p>
|
|
<ul><li>Restarting the sequence</li>
|
|
<li>Changing the increment between future sequence values</li>
|
|
<li>Setting or eliminating the minimum or maximum values</li>
|
|
<li>Changing the number of cached sequence numbers</li>
|
|
<li>Changing the attribute that determines whether the sequence can cycle
|
|
or not</li>
|
|
<li>Changing whether sequence numbers must be generated in order of request</li>
|
|
</ul>
|
|
<p>For example, change the increment of values of sequence ORDER from
|
|
1 to 5:</p>
|
|
<pre><strong>ALTER SEQUENCE</strong> ORDER_SEQ
|
|
<strong>INCREMENT BY</strong> 5</pre>
|
|
<p>After this alter is complete, run the INSERT statement again,
|
|
and then the SELECT. Now the table contains the following columns:</p>
|
|
|
|
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 3. Results for SELECT from table ORDERS</caption><thead align="left"><tr><th valign="top" id="d0e196">ORDERNO</th>
|
|
<th valign="top" id="d0e198">CUSTNO</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody><tr><td valign="top" headers="d0e196 ">500</td>
|
|
<td valign="top" headers="d0e198 ">12</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e196 ">501</td>
|
|
<td valign="top" headers="d0e198 ">12</td>
|
|
</tr>
|
|
<tr><td valign="top" headers="d0e196 ">528</td>
|
|
<td valign="top" headers="d0e198 ">12</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
</div>
|
|
<p>Notice that the next value that the sequence uses is a 528. At
|
|
first glance, this number appears to be incorrect. However, look at the events
|
|
that lead up to this assignment. First, when the sequence was originally create,
|
|
a cache value of 24 was assigned. The system assigns the first 24 values for
|
|
this cache. Next, the sequence was altered. When the ALTER SEQUENCE statement
|
|
is issued, the system drops the assigned values and starts up again with the
|
|
next available value; in this case the original 24 that was cached, plus the
|
|
next increment, 5. If the original CREATE SEQUENCE statement did not have
|
|
the CACHE clause, the system automatically assigns a default cache value of
|
|
20. If that sequence was altered, then the next available value is 25.</p>
|
|
</div>
|
|
</div>
|
|
<div>
|
|
<ul class="ullinks">
|
|
<li class="ulchildlink"><strong><a href="rbafyidentsequence.htm">Comparison of identity columns and sequences</a></strong><br />
|
|
While IDENTITY columns and sequences are similar in many ways, there are also differences.</li>
|
|
</ul>
|
|
|
|
<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="rbafy1sequence.htm" title="A sequence is a data area object that provides a quick and easy way of generating unique numbers.">Sequences</a></div>
|
|
</div>
|
|
<div class="relref"><strong>Related reference</strong><br />
|
|
<div><a href="rbafyidentsequence.htm" title="While IDENTITY columns and sequences are similar in many ways, there are also differences.">Comparison of identity columns and sequences</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |