doc-exports/docs/dws/dev/dws_06_0153.html
Lu, Huayi a24ca60074 DWS DEVELOPER 811 version
Reviewed-by: Hasko, Vladimir <vladimir.hasko@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2023-01-19 13:37:49 +00:00

108 lines
19 KiB
HTML

<a name="EN-US_TOPIC_0000001098990984"></a><a name="EN-US_TOPIC_0000001098990984"></a>
<h1 class="topictitle1">CLUSTER</h1>
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001098990984__s8d2e25c7c6c94c89b0f53628723b262f"><h4 class="sectiontitle">Function</h4><p id="EN-US_TOPIC_0000001098990984__a370e8e971b2e45b2b757f03610a8341a">Cluster a table according to an index.</p>
<p id="EN-US_TOPIC_0000001098990984__aace93833760c4857be33d84fe7d64149"><strong id="EN-US_TOPIC_0000001098990984__b842352706161917">CLUSTER</strong> instructs <span id="EN-US_TOPIC_0000001098990984__text1109146878">GaussDB(DWS)</span> to cluster the table specified by <strong id="EN-US_TOPIC_0000001098990984__b842352706144543">table_name</strong> based on the index specified by <strong id="EN-US_TOPIC_0000001098990984__b84235270616155">index_name</strong>. The index must have been defined on <strong id="EN-US_TOPIC_0000001098990984__en-us_topic_0085032662_b84235270617181">table_name</strong>.</p>
<p id="EN-US_TOPIC_0000001098990984__a014feec92f46441ead33b37757989837">When a table is clustered, it is physically reordered based on the index information. Clustering is a one-time operation: when the table is subsequently updated, the changes are not clustered. That is, no attempt is made to store new or updated rows according to their index order.</p>
<p id="EN-US_TOPIC_0000001098990984__a766fa9f1b74140b8b82f91c61f4fd5ed">When a table is clustered, <span id="EN-US_TOPIC_0000001098990984__text749227493">GaussDB(DWS)</span> records which index the table was clustered by. The form <strong id="EN-US_TOPIC_0000001098990984__en-us_topic_0085032662_en-us_topic_0058965844_b842352706144714">CLUSTER table_name</strong> reclusters the table using the same index as before. You can also use the <strong id="EN-US_TOPIC_0000001098990984__b842352706161947">CLUSTER</strong> or <strong id="EN-US_TOPIC_0000001098990984__b842352706161952">SET WITHOUT CLUSTER</strong> forms of <strong id="EN-US_TOPIC_0000001098990984__b842352706161958">ALTER TABLE</strong> to set the index to be used for future cluster operations, or to clear any previous setting.</p>
<p id="EN-US_TOPIC_0000001098990984__aa140f68f11d04270b11334e5da690b36"><strong id="EN-US_TOPIC_0000001098990984__b842352706144741">CLUSTER</strong> without any parameter reclusters all the previously-clustered tables in the current database that the calling user owns, or all such tables if called by an administrator.</p>
<p id="EN-US_TOPIC_0000001098990984__a50f7928dfd9c4506a6627affc9edf4a9">When a table is being clustered, an <strong id="EN-US_TOPIC_0000001098990984__b842352706162023">ACCESS EXCLUSIVE</strong> lock is acquired on it. This prevents any other database operations (both reads and writes) from operating on the table until the <strong id="EN-US_TOPIC_0000001098990984__b842352706162031">CLUSTER</strong> is finished.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001098990984__s36a26e001a494541a2bfcfadc223b5fa"><h4 class="sectiontitle">Precautions</h4><p id="EN-US_TOPIC_0000001098990984__p1096825613104">Only row-store B-tree indexes support <strong id="EN-US_TOPIC_0000001098990984__b06650447323">CLUSTER</strong>.</p>
<p id="EN-US_TOPIC_0000001098990984__a84bbc6662f3c44b4b18dec940ae5fb15">In cases where you are accessing single rows randomly within a table, the actual order of the data in the table is unimportant. However, if you tend to access some data more than others, and there is an index that groups them together, you will benefit from using <strong id="EN-US_TOPIC_0000001098990984__b842352706161455">CLUSTER</strong>. If you are requesting a range of indexed values from a table, or a single indexed value that has multiple rows that match, <strong id="EN-US_TOPIC_0000001098990984__b1403471560">CLUSTER</strong> will help because once the index identifies the table page for the first row that matches, all other rows that match are probably already on the same table page, and so you save disk accesses and speed up the query.</p>
<p id="EN-US_TOPIC_0000001098990984__a7f4b07cd401a42a8a07df79e8add8ecd">When an index scan is used, a temporary copy of the table is created that contains the table data in the index order. Temporary copies of each index on the table are created as well. Therefore, you need free space on disk at least equal to the sum of the table size and the index sizes. </p>
<p id="EN-US_TOPIC_0000001098990984__aea2fd25888d241278c88bf91a9859c0a">Because <strong id="EN-US_TOPIC_0000001098990984__b842352706161518">CLUSTER</strong> remembers which indexes are clustered, one can cluster the tables manually the first time, then set up a time like <strong id="EN-US_TOPIC_0000001098990984__b842352706161523">VACUUM</strong> without any parameters, so that the desired tables are periodically reclustered.</p>
<p id="EN-US_TOPIC_0000001098990984__a2f6e20f9d33241f09b8a8093e8b5936d">Because the optimizer records statistics about the ordering of tables, it is advisable to run <strong id="EN-US_TOPIC_0000001098990984__b84235270616172">ANALYZE</strong> on the newly clustered table. Otherwise, the optimizer might make poor choices of query plans. </p>
<p id="EN-US_TOPIC_0000001098990984__a801ab8eb7ebd4ae8b736e670a154eef1"><strong id="EN-US_TOPIC_0000001098990984__b842352706161710">CLUSTER</strong> cannot be executed in transactions.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001098990984__s0b06afbf8f9443f7afa2c2cf581f561e"><h4 class="sectiontitle">Syntax</h4><ul id="EN-US_TOPIC_0000001098990984__u3d33c613f59549728d67476803e67c81"><li id="EN-US_TOPIC_0000001098990984__l7a5f141f4f8e4b628878f9bb7d2dc306">Cluster a table.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__sdc3f6734254340d59ac968be22719f22"><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">CLUSTER</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">VERBOSE</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="k">table_name</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">index_name</span><span class="w"> </span><span class="p">];</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001098990984__l7b48fd5951c340bb9e0316960837e1ab">Cluster a partition.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__sd11334f48e3d472f83e2b201f0166127"><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">CLUSTER</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">VERBOSE</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="k">table_name</span><span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="n">partition_name</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">index_name</span><span class="w"> </span><span class="p">];</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001098990984__lea139c56472241c88f965dad9f8964a5">Cluster the table that has previously been clustered.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__s3db51d317a14456cb360fff6ddf030d9"><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">CLUSTER</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">VERBOSE</span><span class="w"> </span><span class="p">];</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001098990984__s24952dc4013b4092b619f92ba26ffedd"><h4 class="sectiontitle">Parameter Description</h4><ul id="EN-US_TOPIC_0000001098990984__udbb32496640a48acacd8a9a3e43a4353"><li id="EN-US_TOPIC_0000001098990984__lb290a4e096034328a0f28b09a5107fcb"><strong id="EN-US_TOPIC_0000001098990984__aa16ec03b88c84d4f8b7d56e6506aac32">VERBOSE</strong><p id="EN-US_TOPIC_0000001098990984__a76d34acf4d6a4394933de2dae033e52c">Enables the display of progress messages.</p>
</li><li id="EN-US_TOPIC_0000001098990984__l1175c04440934eb9a2cad2d592061c8d"><strong id="EN-US_TOPIC_0000001098990984__addac9d00d7014a98b375ea72155e80d6">table_name</strong><p id="EN-US_TOPIC_0000001098990984__ae8d0dd404755480a9468484f10dee712">Specifies the name of the table.</p>
<p id="EN-US_TOPIC_0000001098990984__ae75f27e0355f4ca18afdded7e5d3b27b">Value range: an existing table name</p>
</li><li id="EN-US_TOPIC_0000001098990984__ld4792d2dff454165a4853cf9c4e494d8"><strong id="EN-US_TOPIC_0000001098990984__a94c420db92f04e838425d9f5d29c969d">index_name</strong><p id="EN-US_TOPIC_0000001098990984__a41adbf6f16ac424692e9e2d40f3cb440">Name of this index</p>
<p id="EN-US_TOPIC_0000001098990984__a37c64da3cf094f19b2900ffc2316dbf5">Value range: An existing index name.</p>
</li><li id="EN-US_TOPIC_0000001098990984__l9a89b278e2884a4dbaecd70fcc018691"><strong id="EN-US_TOPIC_0000001098990984__ad973e7df25834f61a8ec3c822a75aa45">partition_name</strong><p id="EN-US_TOPIC_0000001098990984__aaa9ef6e647a34d28b28a3947b1ed2185">Specifies the partition name.</p>
<p id="EN-US_TOPIC_0000001098990984__af759174c060641b08d33c4ddb30cbc98">Value range: An existing partition name.</p>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001098990984__s4f9b2f1143a14369bc7510af91fe041c"><h4 class="sectiontitle">Examples</h4><p id="EN-US_TOPIC_0000001098990984__p15727143810344">Create a partitioned table.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__screen354881914360"><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>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</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">tpcds</span><span class="p">.</span><span class="n">inventory_p1</span><span class="w"></span>
<span class="p">(</span><span class="w"></span>
<span class="w"> </span><span class="n">INV_DATE_SK</span><span class="w"> </span><span class="nb">INTEGER</span><span class="w"> </span><span class="k">NOT</span><span class="w"> </span><span class="k">NULL</span><span class="p">,</span><span class="w"></span>
<span class="w"> </span><span class="n">INV_ITEM_SK</span><span class="w"> </span><span class="nb">INTEGER</span><span class="w"> </span><span class="k">NOT</span><span class="w"> </span><span class="k">NULL</span><span class="p">,</span><span class="w"></span>
<span class="w"> </span><span class="n">INV_WAREHOUSE_SK</span><span class="w"> </span><span class="nb">INTEGER</span><span class="w"> </span><span class="k">NOT</span><span class="w"> </span><span class="k">NULL</span><span class="p">,</span><span class="w"></span>
<span class="w"> </span><span class="n">INV_QUANTITY_ON_HAND</span><span class="w"> </span><span class="nb">INTEGER</span><span class="w"></span>
<span class="p">)</span><span class="w"></span>
<span class="n">DISTRIBUTE</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">HASH</span><span class="p">(</span><span class="n">INV_ITEM_SK</span><span class="p">)</span><span class="w"></span>
<span class="n">PARTITION</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">RANGE</span><span class="p">(</span><span class="n">INV_DATE_SK</span><span class="p">)</span><span class="w"></span>
<span class="p">(</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P1</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="mi">2451179</span><span class="p">),</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P2</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="mi">2451544</span><span class="p">),</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P3</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="mi">2451910</span><span class="p">),</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P4</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="mi">2452275</span><span class="p">),</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P5</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="mi">2452640</span><span class="p">),</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P6</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="mi">2453005</span><span class="p">),</span><span class="w"></span>
<span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="n">P7</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="k">LESS</span><span class="w"> </span><span class="k">THAN</span><span class="p">(</span><span class="k">MAXVALUE</span><span class="p">)</span><span class="w"></span>
<span class="p">);</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001098990984__p37261338193417">Create an index named <strong id="EN-US_TOPIC_0000001098990984__b113924014018">ds_inventory_p1_index1</strong>.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__screen17768162693618"><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="k">INDEX</span><span class="w"> </span><span class="n">ds_inventory_p1_index1</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">tpcds</span><span class="p">.</span><span class="n">inventory_p1</span><span class="w"> </span><span class="p">(</span><span class="n">INV_ITEM_SK</span><span class="p">)</span><span class="w"> </span><span class="k">LOCAL</span><span class="p">;</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001098990984__p187265387345">Cluster the <strong id="EN-US_TOPIC_0000001098990984__b126126414018"><span id="EN-US_TOPIC_0000001098990984__text177261381343">tpcds.</span>inventory_p1</strong> table.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__screen136213217369"><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">CLUSTER</span><span class="w"> </span><span class="n">tpcds</span><span class="p">.</span><span class="n">inventory_p1</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">ds_inventory_p1_index1</span><span class="p">;</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001098990984__p1172613843410">Cluster the <strong id="EN-US_TOPIC_0000001098990984__b981518202">p3</strong> partition.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__screen1638312364367"><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">CLUSTER</span><span class="w"> </span><span class="n">tpcds</span><span class="p">.</span><span class="n">inventory_p1</span><span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="p">(</span><span class="n">p3</span><span class="p">)</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">ds_inventory_p1_index1</span><span class="p">;</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001098990984__p0726338173419">Cluster the tables that can be clustered in the database.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098990984__screen1270184063618"><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">CLUSTER</span><span class="p">;</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_06_0118.html">DDL Syntax</a></div>
</div>
</div>