doc-exports/docs/dws/dev/dws_04_0228.html
Lu, Huayi e6fa411af0 DWS DEV 830.201 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-05-16 07:24:04 +00:00

188 lines
34 KiB
HTML

<a name="EN-US_TOPIC_0000001233681759"></a><a name="EN-US_TOPIC_0000001233681759"></a>
<h1 class="topictitle1">Checking for Data Skew</h1>
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001233681759__sd1223eaa8578416ab98e795a129e8f95"><h4 class="sectiontitle">Scenarios</h4><p id="EN-US_TOPIC_0000001233681759__a404d064159214bcbb8b03b6a9a697a65">Data skew causes the query performance to deteriorate. Before importing all the data from a table consisting of over 10 million records, you are advised to import some of the data and check whether data skew occurs and whether the distribution keys need to be changed. Troubleshoot the problems if any. It is costly to address data skew and change the distribution keys after a large amount of data has been imported.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001233681759__s6b43644b3a3b41339eddf599f11935b0"><h4 class="sectiontitle">Context</h4><p id="EN-US_TOPIC_0000001233681759__ad245b2b09caa4c69aa4e9fcaf1482f88"><span id="EN-US_TOPIC_0000001233681759__text1655012983">GaussDB(DWS)</span> uses a massively parallel processing (MPP) system of the shared-nothing architecture. The MPP performs horizontal partitioning to store tuples in service data tables on all DNs using proper distribution policies.</p>
<p id="EN-US_TOPIC_0000001233681759__a6f61499f1dea444d9c171761e2f927ff">The following user table distribution policies are supported:</p>
<ul id="EN-US_TOPIC_0000001233681759__ufde0b90a6fa1489f8c04339d93ed2789"><li id="EN-US_TOPIC_0000001233681759__l37d6a10af1e242efb88d9ccb0c3ba97e">Replication: stores a full table on each DN. You are advised to use the replication mode for tables containing a small volume of data.</li><li id="EN-US_TOPIC_0000001233681759__le2cbc9ef9941449db085202851c0e42a">Hash: A distribution key must be specified for a user table. When a record is inserted, the system hashes it based on the distribution key and then stores it on the corresponding DN. You are advised to use the hash distribution policy for tables with a large volume of data.</li><li id="EN-US_TOPIC_0000001233681759__li129301115378">Round-robin: Each row in the table is sent to each DN in turn. Therefore, data is evenly distributed on each DN. If no proper distribution column can be found in a table with a large amount of data in hash mode, you are advised to use the round-robin distribution policy.</li></ul>
</div>
<p id="EN-US_TOPIC_0000001233681759__a7a099833f9ec4c07bf6c2d1f3f654e19">If an inappropriate distribution key is used, data skew may occur when you use the hash policy. Check for data skew when you use the hash distribution policy so that data can be evenly distributed to each DN. You are advised to use the column with few replicated values as the distribution key.</p>
<div class="section" id="EN-US_TOPIC_0000001233681759__s947ce1270ece495ab862dcb2dd6bfa43"><h4 class="sectiontitle">Procedure</h4><ol id="EN-US_TOPIC_0000001233681759__ocad38a85674c49d784311b1dca2e3f62"><li id="EN-US_TOPIC_0000001233681759__l1ee01c1fa7dd4411b64ee6dfd8052b9a"><a name="EN-US_TOPIC_0000001233681759__l1ee01c1fa7dd4411b64ee6dfd8052b9a"></a><a name="l1ee01c1fa7dd4411b64ee6dfd8052b9a"></a><span>Analyze data source features and select candidate distribution columns that have more distinct values and evenly distributed data.</span></li><li id="EN-US_TOPIC_0000001233681759__l281215ae79184a889db073ca60eef8f2"><a name="EN-US_TOPIC_0000001233681759__l281215ae79184a889db073ca60eef8f2"></a><a name="l281215ae79184a889db073ca60eef8f2"></a><span>Select a candidate column from <a href="#EN-US_TOPIC_0000001233681759__l1ee01c1fa7dd4411b64ee6dfd8052b9a">1</a> to create a target table.</span><p><div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__saa054bc7f2314797ad1198331418aa47"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">GLOBAL</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">LOCAL</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="k">TEMPORARY</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">TEMP</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">UNLOGGED</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">IF</span><span class="w"> </span><span class="k">NOT</span><span class="w"> </span><span class="k">EXISTS</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="w"> </span><span class="p">(</span><span class="err">{</span><span class="w"> </span><span class="k">column_name</span><span class="w"> </span><span class="n">data_type</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">compress_mode</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">COLLATE</span><span class="w"> </span><span class="k">collation</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">column_constraint</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="p">...</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">]</span>
<span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">table_constraint</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">LIKE</span><span class="w"> </span><span class="n">source_table</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">like_option</span><span class="w"> </span><span class="p">[...]</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="err">}</span>
<span class="w"> </span><span class="p">[,</span><span class="w"> </span><span class="p">...</span><span class="w"> </span><span class="p">])</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">WITH</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="err">{</span><span class="n">storage_parameter</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">value</span><span class="err">}</span><span class="w"> </span><span class="p">[,</span><span class="w"> </span><span class="p">...</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="p">]</span>
<span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="k">COMMIT</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="k">PRESERVE</span><span class="w"> </span><span class="k">ROWS</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">DELETE</span><span class="w"> </span><span class="k">ROWS</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">DROP</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="p">]</span>
<span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">COMPRESS</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">NOCOMPRESS</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">TABLESPACE</span><span class="w"> </span><span class="n">tablespace_name</span><span class="w"> </span><span class="p">]</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="err">{</span><span class="w"> </span><span class="n">REPLICATION</span><span class="w"> </span>
<span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">ROUNDROBIN</span>
<span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="n">HASH</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="k">column_name</span><span class="w"> </span><span class="p">[,...]</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="p">];</span>
</pre></div></td></tr></table></div>
</div>
</p></li><li id="EN-US_TOPIC_0000001233681759__ldc325018534545c9ba321da8c4eb3e23"><span>Import a small batch of data to the target table.</span><p><p id="EN-US_TOPIC_0000001233681759__p181719280514">When importing a single data file, you can evenly split this file and import a part of it to check for the data skew in the target table.</p>
</p></li><li id="EN-US_TOPIC_0000001233681759__laaba2ab42be141a9b69fdc266932c039"><span>Check for data skew. (Replace <em id="EN-US_TOPIC_0000001233681759__i842352697104048">table_name</em> with the actual table name.)</span><p><div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__sbf1e8deb87f248ed925da2881178fca1"><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">SELECT</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="k">count</span><span class="p">,</span><span class="n">b</span><span class="p">.</span><span class="n">node_name</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="p">(</span><span class="k">SELECT</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="k">count</span><span class="p">,</span><span class="n">xc_node_id</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="k">table_name</span><span class="w"> </span><span class="k">GROUP</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">xc_node_id</span><span class="p">)</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">pgxc_node</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="n">xc_node_id</span><span class="o">=</span><span class="n">b</span><span class="p">.</span><span class="n">node_id</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="k">count</span><span class="w"> </span><span class="k">desc</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</p></li><li id="EN-US_TOPIC_0000001233681759__lb6b04bdf47b3436cb325e8cf06d3c55e"><a name="EN-US_TOPIC_0000001233681759__lb6b04bdf47b3436cb325e8cf06d3c55e"></a><a name="lb6b04bdf47b3436cb325e8cf06d3c55e"></a><span>If the data distribution deviation is less than 10% across DNs, data is evenly distributed and an appropriate distribution key has been selected. Delete the small batch of imported data and import full data to complete data migration.</span><p><p id="EN-US_TOPIC_0000001233681759__a2ced46b23e0547b8bf2537c00f88d2f2">If data distribution deviation across DNs is greater than or equal to 10%, data skew occurs. Remove this distribution key from the candidates in <a href="#EN-US_TOPIC_0000001233681759__l1ee01c1fa7dd4411b64ee6dfd8052b9a">1</a>, delete the target table, and repeat <a href="#EN-US_TOPIC_0000001233681759__l281215ae79184a889db073ca60eef8f2">2</a> through <a href="#EN-US_TOPIC_0000001233681759__lb6b04bdf47b3436cb325e8cf06d3c55e">5</a>.</p>
<div class="note" id="EN-US_TOPIC_0000001233681759__note211621313217"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001233681759__p1696594012280">The data distribution deviation indicates the difference between the actual data volume on DNs and the average data volume on DNs. You can view the distribution difference in the <a href="dws_04_0805.html">PGXC_GET_TABLE_SKEWNESS</a> view.</p>
</div></div>
</p></li><li id="EN-US_TOPIC_0000001233681759__li10769517049"><span>(Optional) If you fail to select an appropriate distribution key after performing the preceding steps, select multiple columns from the candidates as distribution keys.</span></li></ol>
</div>
<div class="section" id="EN-US_TOPIC_0000001233681759__s5765ad855ca644348b72af39db2ab067"><h4 class="sectiontitle">Examples</h4><p id="EN-US_TOPIC_0000001233681759__a3491368c2264499282b340c276c99b85">Assume you want to select an appropriate distribution key for the <strong id="EN-US_TOPIC_0000001233681759__b842352706164723">staffs</strong> table.</p>
<ol id="EN-US_TOPIC_0000001233681759__o0d12289a822c4dccba44bbb304a94dc3"><li id="EN-US_TOPIC_0000001233681759__ldcfa8fcaea994a2a968b794a58c22c32">Analyze the source data for the <strong id="EN-US_TOPIC_0000001233681759__b842352706164736">staffs</strong> table and select the <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223320">staff_ID</strong>, <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223319">FIRST_NAME</strong>, and <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223317">LAST_NAME</strong> columns as candidate distribution keys.</li><li id="EN-US_TOPIC_0000001233681759__la515550d7dd84f84bac8832a0852a6a4">Select the <strong id="EN-US_TOPIC_0000001233681759__b19132162313288">staff_ID</strong> column as the distribution key and create the target table <strong id="EN-US_TOPIC_0000001233681759__b842352706164746">staffs</strong>.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__s3dfbe45d1b9d47cbba540ceb76380724"><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></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">staffs</span>
<span class="p">(</span>
<span class="w"> </span><span class="n">staff_ID</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">6</span><span class="p">)</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="n">FIRST_NAME</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">),</span>
<span class="w"> </span><span class="n">LAST_NAME</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">25</span><span class="p">),</span>
<span class="w"> </span><span class="n">EMAIL</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">25</span><span class="p">),</span>
<span class="w"> </span><span class="n">PHONE_NUMBER</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">),</span>
<span class="w"> </span><span class="n">HIRE_DATE</span><span class="w"> </span><span class="nb">DATE</span><span class="p">,</span>
<span class="w"> </span><span class="n">employment_ID</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">10</span><span class="p">),</span>
<span class="w"> </span><span class="n">SALARY</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">8</span><span class="p">,</span><span class="mi">2</span><span class="p">),</span>
<span class="w"> </span><span class="n">COMMISSION_PCT</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">2</span><span class="p">,</span><span class="mi">2</span><span class="p">),</span>
<span class="w"> </span><span class="n">MANAGER_ID</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">6</span><span class="p">),</span>
<span class="w"> </span><span class="n">section_ID</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">4</span><span class="p">)</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">staff_ID</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__l1781311bd0934221912c78890e879d0d">Import a small batch of data to the target table <strong id="EN-US_TOPIC_0000001233681759__b842352706183053">staffs</strong>.<div class="p" id="EN-US_TOPIC_0000001233681759__a28f17bdeff224c4e87f8b7aeeabaec68">There are eight DNs in the cluster based on the following query, and you are advised to import 80,000 records.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__s42686a5f166549cfafd0916e2f4a0e75"><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">SELECT</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">pgxc_node</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">node_type</span><span class="o">=</span><span class="s1">'D'</span><span class="p">;</span>
<span class="w"> </span><span class="k">count</span><span class="w"> </span>
<span class="c1">-------</span>
<span class="w"> </span><span class="mi">8</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__l2b767a5e8f3844a9964ee9e749c569f8">Verify the data skew of the target table <strong id="EN-US_TOPIC_0000001233681759__b842352706164836">staffs</strong> whose distribution key is <strong id="EN-US_TOPIC_0000001233681759__b842352706164845">staff_ID</strong>:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__s8fb7a5148c5d4a2198dd9f218ad19383"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="k">count</span><span class="p">,</span><span class="n">b</span><span class="p">.</span><span class="n">node_name</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="k">count</span><span class="p">,</span><span class="n">xc_node_id</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">staffs</span><span class="w"> </span><span class="k">GROUP</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">xc_node_id</span><span class="p">)</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">pgxc_node</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="n">xc_node_id</span><span class="o">=</span><span class="n">b</span><span class="p">.</span><span class="n">node_id</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="k">count</span><span class="w"> </span><span class="k">desc</span><span class="p">;</span>
<span class="k">count</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">node_name</span>
<span class="c1">------+-----------</span>
<span class="mi">11010</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode4</span>
<span class="mi">10000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode3</span>
<span class="mi">12001</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode2</span>
<span class="w"> </span><span class="mi">8995</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode1</span>
<span class="mi">10000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode5</span>
<span class="w"> </span><span class="mi">7999</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode6</span>
<span class="w"> </span><span class="mi">9995</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode7</span>
<span class="mi">10000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode8</span>
<span class="p">(</span><span class="mi">8</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__l50e3c464bd5b4d1bbcd3a06f7010c0f2">The preceding query result indicates that the distribution deviation across DNs is greater than 10%. The data skew occurs. Therefore, delete <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223418">staff_ID</strong> from the distribution key candidates and delete the <strong id="EN-US_TOPIC_0000001233681759__b842352706164925">staffs</strong> table.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__sfaad16eb60c4439e908bc52e401d7f2a"><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="k">TABLE</span><span class="w"> </span><span class="n">staffs</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__lb240652d80c440db903747a2f2de2592">Use <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223449">staff_ID</strong>, <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223452">FIRST_NAME</strong>, and <strong id="EN-US_TOPIC_0000001233681759__en-us_topic_0058967677_b842352706223453">LAST_NAME</strong> as distribution keys and create the target table <strong id="EN-US_TOPIC_0000001233681759__b842352706164944">staffs</strong>.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__saf4e5087f74b433cad4428130bd9ef22"><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></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">staffs</span>
<span class="p">(</span><span class="w"> </span>
<span class="w"> </span><span class="n">staff_ID</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">6</span><span class="p">)</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="n">FIRST_NAME</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">),</span>
<span class="w"> </span><span class="n">LAST_NAME</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">25</span><span class="p">),</span>
<span class="w"> </span><span class="n">EMAIL</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">25</span><span class="p">),</span>
<span class="w"> </span><span class="n">PHONE_NUMBER</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">20</span><span class="p">),</span>
<span class="w"> </span><span class="n">HIRE_DATE</span><span class="w"> </span><span class="nb">DATE</span><span class="p">,</span>
<span class="w"> </span><span class="n">employment_ID</span><span class="w"> </span><span class="n">VARCHAR2</span><span class="p">(</span><span class="mi">10</span><span class="p">),</span>
<span class="w"> </span><span class="n">SALARY</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">8</span><span class="p">,</span><span class="mi">2</span><span class="p">),</span>
<span class="w"> </span><span class="n">COMMISSION_PCT</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">2</span><span class="p">,</span><span class="mi">2</span><span class="p">),</span>
<span class="w"> </span><span class="n">MANAGER_ID</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">6</span><span class="p">),</span>
<span class="w"> </span><span class="n">section_ID</span><span class="w"> </span><span class="nb">NUMBER</span><span class="p">(</span><span class="mi">4</span><span class="p">)</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">staff_ID</span><span class="p">,</span><span class="n">FIRST_NAME</span><span class="p">,</span><span class="n">LAST_NAME</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__lc5953f9686f0438bb12655e25acc0c41">Verify the data skew of the target table <strong id="EN-US_TOPIC_0000001233681759__b7436122312511">staffs</strong> whose distribution keys are <strong id="EN-US_TOPIC_0000001233681759__b343742315516">staff_ID</strong>, <strong id="EN-US_TOPIC_0000001233681759__b843913231156">FIRST_NAME</strong>, and <strong id="EN-US_TOPIC_0000001233681759__b14439823955">LAST_NAME</strong>.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__s4cb55053033a41b4ae85da794b68b2b3"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="k">count</span><span class="p">,</span><span class="n">b</span><span class="p">.</span><span class="n">node_name</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="k">count</span><span class="p">,</span><span class="n">xc_node_id</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">staffs</span><span class="w"> </span><span class="k">GROUP</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">xc_node_id</span><span class="p">)</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">pgxc_node</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="n">xc_node_id</span><span class="o">=</span><span class="n">b</span><span class="p">.</span><span class="n">node_id</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">a</span><span class="p">.</span><span class="k">count</span><span class="w"> </span><span class="k">desc</span><span class="p">;</span>
<span class="k">count</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">node_name</span>
<span class="c1">------+-----------</span>
<span class="mi">10010</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode4</span>
<span class="mi">10000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode3</span>
<span class="mi">10001</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode2</span>
<span class="w"> </span><span class="mi">9995</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode1</span>
<span class="mi">10000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode5</span>
<span class="w"> </span><span class="mi">9999</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode6</span>
<span class="w"> </span><span class="mi">9995</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode7</span>
<span class="mi">10000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">datanode8</span>
<span class="p">(</span><span class="mi">8</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__lf107d31047d54e9fb9abd6a41171a2cb">The preceding query result indicates that the data deviation across DNs is less than 10%. The data is evenly distributed and the appropriate distribution keys have been selected.</li><li id="EN-US_TOPIC_0000001233681759__l765427cb3765428caa493afd1b9ffc76">Delete the imported small-batch data.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233681759__sed72e7084f494f86b05331eb1c1653d7"><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">TRUNCATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">staffs</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233681759__l04bee51cea78418b8d7163105ec739f9">Import the full data to complete data migration.</li></ol>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0988.html">Other Operations</a></div>
</div>
</div>