doc-exports/docs/dws/dev/dws_04_0040.html
Lu, Huayi ef0ada5a59 DWS DEV 20240716 version
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2024-11-02 09:07:47 +00:00

88 lines
18 KiB
HTML

<a name="EN-US_TOPIC_0000001510283769"></a><a name="EN-US_TOPIC_0000001510283769"></a>
<h1 class="topictitle1">Creating and Using Sequences</h1>
<div id="body8662426"><p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_p111618311243">A sequence is a database object that generates unique integers according to a certain rule and is usually used to generate primary key values.</p>
<div class="p" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_p510074455414">You can create a sequence for a column in either of the following methods:<ul id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_ul9475346173310"><li id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li6850853153315">Set the data type of a column to sequence integer. A sequence will be automatically created by the database for this column.</li><li id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li15475446203315">Use <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b17633613419">CREATE SEQUENCE</strong> to create a new sequenc. Use the <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b1899031717362">nextval('</strong><em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i4253142493620">sequence_name</em><strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b355862015365">')</strong> function to increment the sequence and return a new value. Specify the default value of the column as the sequence value returned by the <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b161655119375">nextval('</strong>sequence_name<strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b1536123193710">')</strong> function. In this way, this column can be used as a unique identifier.</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_sa82c57fda672457ea8c6fa934915ba5c"><h4 class="sectiontitle">Creating a Sequence.</h4><div class="p" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_p19100144410545">Method 1: Set the data type of a column to a sequence integer. For example:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_sa01899b22f364d91badd0a3689d3a53e"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">T1</span>
<span class="p">(</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="nb">serial</span><span class="p">,</span>
<span class="w"> </span><span class="n">name</span><span class="w"> </span><span class="nb">text</span>
<span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</div>
<p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_a6e8080438eb2433ea9ea9606b5e8c92e">Method 2: Create a sequence and set the initial value of the <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b17032018804161">nextval</strong>('<em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i12149377144161">sequence_name</em>') function to the default value of a column. You can cache a specific number of sequence values to reduce the requests to the GTM, improving the performance.</p>
<ol id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_ol128283377453"><li id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li208281037164517">Create a sequence.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_screen1282893754511"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="n">SEQUENCE</span><span class="w"> </span><span class="n">seq1</span><span class="w"> </span><span class="k">cache</span><span class="w"> </span><span class="mi">100</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li15580165544516">Set the initial value of the <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b96682320327">nextval</strong>('<em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i766818314322">sequence_name</em>') function to the default value of a column.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_screen1858075515456"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">T2</span><span class="w"> </span>
<span class="p">(</span><span class="w"> </span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="nb">int</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">null</span><span class="w"> </span><span class="k">default</span><span class="w"> </span><span class="n">nextval</span><span class="p">(</span><span class="s1">'seq1'</span><span class="p">),</span>
<span class="w"> </span><span class="n">name</span><span class="w"> </span><span class="nb">text</span>
<span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</li></ol>
<div class="note" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_nebd89c17c96e4d4281ef4594972b179b"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_a62e8fcef7cee4ddcba95bdfd41e2ad43">Methods 1 and 2 are similar except that method 2 specifies cache for the sequence. A sequence using cache has holes (non-consecutive values, for example, 1, 4, 5) and cannot keep the order of the values. After a sequence is deleted, its sub-sequences will be deleted automatically. A sequence shared by multiple columns is not forbidden in a database, but you are not advised to do that.</p>
<p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_a712093feed8c415bb59590d3b9dffc0f">Currently, the preceding two methods cannot be used for existing tables.</p>
</div></div>
</div>
<div class="section" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_section273144710268"><h4 class="sectiontitle">Modifying a Sequence</h4><p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_p17243185212263">The <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b1161884813418">ALTER SEQUENCE</strong> statement changes the attributes of an existing sequence, including the owner, owning column, and maximum value.</p>
<ul id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_ul1281573592820"><li id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li2815173516286">Associate the sequence with a column.<p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_p7259193612381"><a name="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li2815173516286"></a><a name="en-us_topic_0000001233883175_li2815173516286"></a>The sequence will be deleted when you delete the column or the table where the column resides.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_saea6cfa21d814de4a659bdd5df63e056"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">ALTER</span><span class="w"> </span><span class="n">SEQUENCE</span><span class="w"> </span><span class="n">seq1</span><span class="w"> </span><span class="n">OWNED</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">T2</span><span class="p">.</span><span class="n">id</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_li716964462815">Modify the maximum value of <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b20931699594161">serial</strong> to <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b7295424924161">300</strong>.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_screen69312213114"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">ALTER</span><span class="w"> </span><span class="n">SEQUENCE</span><span class="w"> </span><span class="n">seq1</span><span class="w"> </span><span class="k">MAXVALUE</span><span class="w"> </span><span class="mi">300</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_section148219245186"><h4 class="sectiontitle">Deleting a Sequence</h4><p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_p2142184591812">Run the <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b11952930481">DROP SEQUENCE</strong> command to delete a sequence. For example, to delete the sequence named <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b1479516496818">seq1</strong>, run the following command:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_screen1559112539181"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">DROP</span><span class="w"> </span><span class="n">SEQUENCE</span><span class="w"> </span><span class="n">seq1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_s100b6d4658154113becab048fd2be2e2"><h4 class="sectiontitle">Precautions</h4><p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_a0f82b560bdf74713b18ce50436723504">Sequence values are generated by the GTM. By default, each request for a sequence value is sent to the GTM. The GTM calculates the result of the current value plus the step and then returns the result. As GTM is a globally unique node, generating default sequence numbers can cause performance issues. For operations that need frequent sequence number generation, such as bulkload data import, this is not recommended. For example, the <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b4982598334161">INSERT FROM SELECT</strong> statement has poor performance in the following scenario:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_s9a3a6763887b4f3d8ced3cb3bbe13fe7"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span>
<span class="normal">6</span>
<span class="normal">7</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="n">SEQUENCE</span><span class="w"> </span><span class="n">newSeq1</span><span class="p">;</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">newT1</span>
<span class="w"> </span><span class="p">(</span><span class="w"> </span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="nb">int</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">null</span><span class="w"> </span><span class="k">default</span><span class="w"> </span><span class="n">nextval</span><span class="p">(</span><span class="s1">'newSeq1'</span><span class="p">),</span><span class="w"> </span>
<span class="w"> </span><span class="n">name</span><span class="w"> </span><span class="nb">text</span>
<span class="w"> </span><span class="p">);</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">newT1</span><span class="p">(</span><span class="n">name</span><span class="p">)</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">name</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">T1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_aa8ad7b8ae6e04785960cecac9f9f96c8">To improve the performance, run the following statements (assume that data of 10,000 rows will be imported from <em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i2561207904161">T1</em> to <em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i3796884644161">newT1</em>):</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_s8dbe067a7f0e4b47b3012e9afd34e403"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">newT1</span><span class="p">(</span><span class="n">id</span><span class="p">,</span><span class="w"> </span><span class="n">name</span><span class="p">)</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">id</span><span class="p">,</span><span class="n">name</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">T1</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="n">SETVAL</span><span class="p">(</span><span class="s1">'newSeq1'</span><span class="p">,</span><span class="mi">10000</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<div class="note" id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_n1b3ef94778f74cc3a4efd6a73efa3cc9"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_ad47cc27e4a0a4a50b54b0b2cc52a021f">Rollback is not supported by sequence functions, including <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b1438019201391">nextval()</strong> and <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b324432417916">setval()</strong>. The value of the setval function immediately takes effects on nextval in the current session in any cases and takes effects in other sessions only when no cache is specified for them. If cache is specified for a session, it takes effect only after all the cached values have been used. To avoid duplicate values, use setval only when necessary. Do not set it to an existing sequence value or a cached sequence value.</p>
</div></div>
<p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_a63d1fabfa19e48b8a851454b0e0b1ea2">If BulkLoad is used, set sufficient cache for <em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i203932248013">newSeq1</em> and do not set <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b134320561707">Maxvalue</strong> or <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b143615310112">Minvalue</strong>. To improve the performance, database may push down the invocation of <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b139991101526">nextval</strong>('<em id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_i418919151426">sequence_name</em>') to DNs. Currently, the concurrent connection requests that can be processed by the GTM are limited. If there are too many DNs, a large number of concurrent connection requests will be sent to the GTM. In this case, you need to limit the concurrent connection of BulkLoad to save the GTM connection resources. If the target table is a replication table (<strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b366243584161">DISTRIBUTE BY REPLICATION</strong>), pushdown cannot be performed. If the data volume is large, this will be a disaster for the database. In addition, the database space may be exhausted. After the import is complete, do <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b19755615194161">VACUUM FULL</strong>. Therefore, you are not advised to use sequences when BulkLoad is used.</p>
<p id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_ab0129c2c35274c51a5a6fed52b8ad40f">After a sequence is created, a single-row table is maintained on each node to store the sequence definition and value, which is obtained from the last interaction with the GTM rather than updated in real time. The single-row table on a node does not update when other nodes request a new value from the GTM or when the sequence is modified using <strong id="EN-US_TOPIC_0000001510283769__en-us_topic_0000001233883175_b197180393312620">setval</strong>.</p>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0016.html">Defining Database Objects</a></div>
</div>
</div>