doc-exports/docs/dws/dev/dws_06_0080.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

221 lines
32 KiB
HTML

<a name="EN-US_TOPIC_0000001233708645"></a><a name="EN-US_TOPIC_0000001233708645"></a>
<h1 class="topictitle1">UNION, CASE, and Related Constructs</h1>
<div id="body8662426"><p id="EN-US_TOPIC_0000001233708645__en-us_topic_0059779260_p269514716590">SQL UNION constructs must match up possibly dissimilar types to become a single result set. Since all query results from a <strong id="EN-US_TOPIC_0000001233708645__b44504733933556">SELECT UNION</strong> statement must appear in a single set of columns, the types of the results of each <strong id="EN-US_TOPIC_0000001233708645__b5554435133556">SELECT</strong> clause must be matched up and converted to a uniform set. Similarly, the result expressions of a <strong id="EN-US_TOPIC_0000001233708645__b159580920333556">CASE</strong> construct must be converted to a common type so that the <strong id="EN-US_TOPIC_0000001233708645__b177841883433556">CASE</strong> expression as a whole has a known output type. The same holds for <strong id="EN-US_TOPIC_0000001233708645__b171744690033556">ARRAY</strong> constructs, and for the <strong id="EN-US_TOPIC_0000001233708645__b164854960733556">GREATEST</strong> and <strong id="EN-US_TOPIC_0000001233708645__b142796099633556">LEAST</strong> functions.</p>
<div class="section" id="EN-US_TOPIC_0000001233708645__s5c81516e10974f338b4b7d772d38f497"><h4 class="sectiontitle">Type Resolution for UNION, CASE, and Related Constructs</h4><ul id="EN-US_TOPIC_0000001233708645__u7d71a8ec8a4e4cd49be14956f188a959"><li id="EN-US_TOPIC_0000001233708645__l57f75649247c4f549873fd156157b8cc">If all inputs are of the same type, and it is not unknown, resolve as that type.</li><li id="EN-US_TOPIC_0000001233708645__la0d1d70a218b4404b7271bcaf313075c">If all inputs are of type <strong id="EN-US_TOPIC_0000001233708645__b84235270692017">unknown</strong>, resolve as type <strong id="EN-US_TOPIC_0000001233708645__b84235270692024">text</strong> (the preferred type of the string category). Otherwise, <strong id="EN-US_TOPIC_0000001233708645__b84235270692044">unknown</strong> inputs are ignored.</li><li id="EN-US_TOPIC_0000001233708645__lce61619a8b6b4625b83cef42fce78007">If the non-unknown inputs are not all of the same type category, the query fails. (Type <strong id="EN-US_TOPIC_0000001233708645__b84235270610386">unknown</strong> is not included.)</li><li id="EN-US_TOPIC_0000001233708645__la1cbb755423441f29b266716414b9875">If the non-unknown inputs are all of the same type category, choose the first non-unknown input type which is a preferred type in that category, if there is one. (Exception: The UNION operation regards the type of the first branch as the selected type.)<div class="note" id="EN-US_TOPIC_0000001233708645__n48be18a738e1417baf129c38c36671e2"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001233708645__acd09fdbd7dbb48fd9c16e6fe33fe54cc"><strong id="EN-US_TOPIC_0000001233708645__b842352706171247">typcategory</strong> in the <strong id="EN-US_TOPIC_0000001233708645__b842352706171237">pg_type</strong> system catalog indicates the data type category. <strong id="EN-US_TOPIC_0000001233708645__b84235270617134">typispreferred</strong> indicates whether a type is preferred in <strong id="EN-US_TOPIC_0000001233708645__b842352706171348">typcategory</strong>.</p>
</div></div>
</li><li id="EN-US_TOPIC_0000001233708645__la520dfab50e441e4b8cd81def938de73">All the input is converted to the selected type. (The original length of a string is retained). Fail if there is not an implicit conversion from a given input to the selected type.</li><li id="EN-US_TOPIC_0000001233708645__li17401536195716">If the input contains the json, txid_snapshot, sys_refcursor, or geometry type, <strong id="EN-US_TOPIC_0000001233708645__b3356338519">UNION</strong> cannot be performed.</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001233708645__s6c7bfb5b733c473bbdc05fb34f856021"><h4 class="sectiontitle">Type Resolution for CASE, COALESCE, IF, and IFNULL in TD-Compatible Mode</h4><ul id="EN-US_TOPIC_0000001233708645__uc41f3b659cfa40c59e8397fca7f459cf"><li id="EN-US_TOPIC_0000001233708645__l33cf764b60a04d6db5003c59bead82a8">If all inputs are of the same type, and it is not unknown, resolve as that type.</li><li id="EN-US_TOPIC_0000001233708645__l98abad52c35d4aab8c48a106aa53dcf8">If all inputs are of type <strong id="EN-US_TOPIC_0000001233708645__b71365099919436">unknown</strong>, resolve as type <strong id="EN-US_TOPIC_0000001233708645__b87930857019436">text</strong>.</li><li id="EN-US_TOPIC_0000001233708645__l923249e8d12840659a1c9ca94503359e">If inputs are of string type (including <strong id="EN-US_TOPIC_0000001233708645__b842352706192652">unknown</strong> which is resolved as type <strong id="EN-US_TOPIC_0000001233708645__b842352706192729">text</strong>) and digit type, resolve as the string type. If the inputs are not of the two types, fail.</li><li id="EN-US_TOPIC_0000001233708645__l0561594b643746ea9ff7b49265fe4f21">If the non-unknown inputs are all of the same type category, choose the input type which is a preferred type in that category, if there is one.</li><li id="EN-US_TOPIC_0000001233708645__lb761861c355247109ca3b81846417cde">Convert all inputs to the selected type. Fail if there is not an implicit conversion from a given input to the selected type.</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001233708645__section1421264504414"><h4 class="sectiontitle">Type Resolution for CASE, COALESCE, IF, and IFNULL in MySQL-Compatible Mode</h4><ul id="EN-US_TOPIC_0000001233708645__ul219416462448"><li id="EN-US_TOPIC_0000001233708645__li41947466445">If all inputs are of the same type, and it is not unknown, resolve as that type.</li><li id="EN-US_TOPIC_0000001233708645__li1919414614446">If all inputs are of type <strong id="EN-US_TOPIC_0000001233708645__b1214097006">unknown</strong>, resolve as type <strong id="EN-US_TOPIC_0000001233708645__b1510646878">text</strong>.</li><li id="EN-US_TOPIC_0000001233708645__li998614192154">If some inputs are of type <strong id="EN-US_TOPIC_0000001233708645__b56046393912">unknown</strong> and the others are of a non-<strong id="EN-US_TOPIC_0000001233708645__b09617174224">unknown</strong> type, resolve as that non-<strong id="EN-US_TOPIC_0000001233708645__b059572202219">unknown</strong> type.</li><li id="EN-US_TOPIC_0000001233708645__li4277512162016">If the inputs are of different non-<strong id="EN-US_TOPIC_0000001233708645__b195101231112212">unknown</strong> types, treat type <strong id="EN-US_TOPIC_0000001233708645__b4438106143513">enum</strong> as type <strong id="EN-US_TOPIC_0000001233708645__b14396429153517">text</strong> for comparison.</li><li id="EN-US_TOPIC_0000001233708645__li19194204614416">If the non-<strong id="EN-US_TOPIC_0000001233708645__b1720813520223">unknown</strong> inputs are all of the same type, choose a preferred type, if there is one. If the inputs are of different types, resolve as type <strong id="EN-US_TOPIC_0000001233708645__b118295527412">text</strong>.</li><li id="EN-US_TOPIC_0000001233708645__li181941146154418">Convert all inputs to the selected type. Fail if there is not an implicit conversion from a given input to the selected type.</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001233708645__s64d7c742a50c4e00b2291bb2117d754e"><h4 class="sectiontitle">Examples</h4><p id="EN-US_TOPIC_0000001233708645__a987902d9630d45b1b58f0d4dd02acdfe">Example 1: Use type resolution with unknown types in a union as the first example. Here, the unknown-type literal <strong id="EN-US_TOPIC_0000001233708645__b8423527069274">'b'</strong> will be resolved to type <strong id="EN-US_TOPIC_0000001233708645__b84235270692718">text</strong>.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233708645__s1512f3e03cdb4cc4b6bf521ea25f5a29"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="nb">text</span><span class="w"> </span><span class="s1">'a'</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="ss">&quot;text&quot;</span><span class="w"> </span><span class="k">UNION</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'b'</span><span class="p">;</span>
<span class="w"> </span><span class="nb">text</span>
<span class="c1">------</span>
<span class="w"> </span><span class="n">a</span>
<span class="w"> </span><span class="n">b</span>
<span class="p">(</span><span class="mi">2</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233708645__ad5df48e6c8ae4455830eaf089e388206">Example 2: Use type resolution in a simple union as the second example. The literal <strong id="EN-US_TOPIC_0000001233708645__b84235270692828">1.2</strong> is of type <strong id="EN-US_TOPIC_0000001233708645__b84235270692840">numeric</strong>, and the <strong id="EN-US_TOPIC_0000001233708645__b84235270692845">integer</strong> value <strong id="EN-US_TOPIC_0000001233708645__b84235270692851">1</strong> can be cast implicitly to <strong id="EN-US_TOPIC_0000001233708645__b84235270692857">numeric</strong>, so that type is used.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233708645__sa5d4159da4114e189cc601710930416a"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="mi">1</span><span class="p">.</span><span class="mi">2</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="ss">&quot;numeric&quot;</span><span class="w"> </span><span class="k">UNION</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="w"> </span><span class="nb">numeric</span>
<span class="c1">---------</span>
<span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">1</span><span class="p">.</span><span class="mi">2</span>
<span class="p">(</span><span class="mi">2</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233708645__a5b259cdb95a34ef58a4a66583ce09ea5">Example 3: Use type resolution in a transposed union as the third example. Here, since type <strong id="EN-US_TOPIC_0000001233708645__b105175991233556">real</strong> cannot be implicitly cast to <strong id="EN-US_TOPIC_0000001233708645__b99875165533556">integer</strong>, but <strong id="EN-US_TOPIC_0000001233708645__b108277227833556">integer</strong> can be implicitly cast to <strong id="EN-US_TOPIC_0000001233708645__b49281932133556">real</strong>, the union result type is resolved as <strong id="EN-US_TOPIC_0000001233708645__b67083371133556">real</strong>.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233708645__s6bd7cbf9528b49368b7f1db40a75e970"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="ss">&quot;real&quot;</span><span class="w"> </span><span class="k">UNION</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">CAST</span><span class="p">(</span><span class="s1">'2.2'</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="nb">REAL</span><span class="p">);</span>
<span class="w"> </span><span class="nb">real</span>
<span class="c1">------</span>
<span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">2</span><span class="p">.</span><span class="mi">2</span>
<span class="p">(</span><span class="mi">2</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233708645__p6335859183416">Example 4: Use type resolution in the <strong id="EN-US_TOPIC_0000001233708645__b0426144292512">COALESCE</strong> function with input values of types <strong id="EN-US_TOPIC_0000001233708645__b129251415112618">int</strong> and <strong id="EN-US_TOPIC_0000001233708645__b59210594255">varchar</strong> as the fourth example. Type resolution fails in ORA-compatible mode. The types are resolved as type <strong id="EN-US_TOPIC_0000001233708645__b1010416118296">varchar</strong> in TD-compatible mode, and as type <strong id="EN-US_TOPIC_0000001233708645__b248191320294">text</strong> in MySQL-compatible mode.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233708645__screen1670155193519"><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>
<span class="normal">19</span>
<span class="normal">20</span>
<span class="normal">21</span>
<span class="normal">22</span>
<span class="normal">23</span>
<span class="normal">24</span>
<span class="normal">25</span>
<span class="normal">26</span>
<span class="normal">27</span>
<span class="normal">28</span>
<span class="normal">29</span>
<span class="normal">30</span>
<span class="normal">31</span>
<span class="normal">32</span>
<span class="normal">33</span>
<span class="normal">34</span>
<span class="normal">35</span>
<span class="normal">36</span>
<span class="normal">37</span>
<span class="normal">38</span>
<span class="normal">39</span>
<span class="normal">40</span>
<span class="normal">41</span>
<span class="normal">42</span>
<span class="normal">43</span>
<span class="normal">44</span>
<span class="normal">45</span>
<span class="normal">46</span>
<span class="normal">47</span>
<span class="normal">48</span>
<span class="normal">49</span>
<span class="normal">50</span>
<span class="normal">51</span>
<span class="normal">52</span>
<span class="normal">53</span>
<span class="normal">54</span>
<span class="normal">55</span>
<span class="normal">56</span>
<span class="normal">57</span>
<span class="normal">58</span>
<span class="normal">59</span>
<span class="normal">60</span>
<span class="normal">61</span>
<span class="normal">62</span>
<span class="normal">63</span>
<span class="normal">64</span>
<span class="normal">65</span>
<span class="normal">66</span>
<span class="normal">67</span>
<span class="normal">68</span>
<span class="normal">69</span>
<span class="normal">70</span>
<span class="normal">71</span>
<span class="normal">72</span>
<span class="normal">73</span>
<span class="normal">74</span>
<span class="normal">75</span>
<span class="normal">76</span></pre></div></td><td class="code"><div><pre><span></span><span class="c1">-- Create the ora_db, td_db, and mysql_db databases by setting dbcompatibility to ORA, TD, and MySQL, respectively:</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">DATABASE</span><span class="w"> </span><span class="n">ora_db</span><span class="w"> </span><span class="n">dbcompatibility</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'ORA'</span><span class="p">;</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">DATABASE</span><span class="w"> </span><span class="n">td_db</span><span class="w"> </span><span class="n">dbcompatibility</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'TD'</span><span class="p">;</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">DATABASE</span><span class="w"> </span><span class="n">mysql_db</span><span class="w"> </span><span class="n">dbcompatibility</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'MySQL'</span><span class="p">;</span>
<span class="c1">-- Switch to the ora_db database:</span>
<span class="err">\</span><span class="k">c</span><span class="w"> </span><span class="n">ora_db</span>
<span class="c1">-- Create the t1 table:</span>
<span class="n">ora_db</span><span class="o">=#</span><span class="w"> </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="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">varchar</span><span class="p">(</span><span class="mi">10</span><span class="p">));</span>
<span class="c1">-- Show the execution plan of a statement for querying the types int and varchar of input parameters for COALESCE:</span>
<span class="n">ora_db</span><span class="o">=#</span><span class="w"> </span><span class="k">EXPLAIN</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">coalesce</span><span class="p">(</span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="p">)</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="n">ERROR</span><span class="p">:</span><span class="w"> </span><span class="k">COALESCE</span><span class="w"> </span><span class="n">types</span><span class="w"> </span><span class="nb">integer</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="nb">character</span><span class="w"> </span><span class="nb">varying</span><span class="w"> </span><span class="n">cannot</span><span class="w"> </span><span class="n">be</span><span class="w"> </span><span class="n">matched</span>
<span class="n">CONTEXT</span><span class="p">:</span><span class="w"> </span><span class="n">referenced</span><span class="w"> </span><span class="k">column</span><span class="p">:</span><span class="w"> </span><span class="k">coalesce</span>
<span class="c1">-- Delete the table:</span>
<span class="n">ora_db</span><span class="o">=#</span><span class="w"> </span><span class="k">DROP</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="c1">-- Switch to the td_db database:</span>
<span class="n">ora_db</span><span class="o">=#</span><span class="w"> </span><span class="err">\</span><span class="k">c</span><span class="w"> </span><span class="n">td_db</span>
<span class="c1">-- Create the t2 table:</span>
<span class="n">td_db</span><span class="o">=#</span><span class="w"> </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="p">(</span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">varchar</span><span class="p">(</span><span class="mi">10</span><span class="p">));</span>
<span class="c1">-- Show the execution plan of a statement for querying the types int and varchar of input parameters for COALESCE:</span>
<span class="n">td_db</span><span class="o">=#</span><span class="w"> </span><span class="k">EXPLAIN</span><span class="w"> </span><span class="k">VERBOSE</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">coalesce</span><span class="p">(</span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">t2</span><span class="p">;</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">-----------------------------------------------------------------------------------------------</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">operation</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="k">rows</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="k">distinct</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="n">width</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="n">costs</span>
<span class="w"> </span><span class="c1">----+----------------------------------------------+--------+------------+---------+---------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="ss">&quot;__REMOTE_FQS_QUERY__&quot;</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span>
<span class="w"> </span><span class="n">Targetlist</span><span class="w"> </span><span class="n">Information</span><span class="w"> </span><span class="p">(</span><span class="n">identified</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">plan</span><span class="w"> </span><span class="n">id</span><span class="p">)</span>
<span class="w"> </span><span class="c1">-------------------------------------------------------------------------------------------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="c1">--Data Node Scan on &quot;__REMOTE_FQS_QUERY__&quot;</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="k">COALESCE</span><span class="p">((</span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="p">)::</span><span class="nb">character</span><span class="w"> </span><span class="nb">varying</span><span class="p">,</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">b</span><span class="p">))</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="n">Remote</span><span class="w"> </span><span class="n">query</span><span class="p">:</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">COALESCE</span><span class="p">(</span><span class="n">a</span><span class="p">::</span><span class="nb">character</span><span class="w"> </span><span class="nb">varying</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="ss">&quot;coalesce&quot;</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="k">public</span><span class="p">.</span><span class="n">t2</span>
<span class="p">(</span><span class="mi">10</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
<span class="c1">-- Delete the table:</span>
<span class="n">td_db</span><span class="o">=#</span><span class="w"> </span><span class="k">DROP</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">t2</span><span class="p">;</span>
<span class="c1">-- Switch to the mysql_db database:</span>
<span class="n">td_db</span><span class="o">=#</span><span class="w"> </span><span class="err">\</span><span class="k">c</span><span class="w"> </span><span class="n">mysql_db</span>
<span class="c1">-- Create the t3 table:</span>
<span class="n">mysql_db</span><span class="o">=#</span><span class="w"> </span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">t3</span><span class="p">(</span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">varchar</span><span class="p">(</span><span class="mi">10</span><span class="p">));</span>
<span class="c1">-- Show the execution plan of a statement for querying the types int and varchar of input parameters for COALESCE:</span>
<span class="n">mysql_db</span><span class="o">=#</span><span class="w"> </span><span class="k">EXPLAIN</span><span class="w"> </span><span class="k">VERBOSE</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">coalesce</span><span class="p">(</span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">t3</span><span class="p">;</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">-----------------------------------------------------------------------------------------------</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">operation</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="k">rows</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="k">distinct</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="n">width</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">E</span><span class="o">-</span><span class="n">costs</span>
<span class="w"> </span><span class="c1">----+----------------------------------------------+--------+------------+---------+---------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="ss">&quot;__REMOTE_FQS_QUERY__&quot;</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span>
<span class="w"> </span><span class="n">Targetlist</span><span class="w"> </span><span class="n">Information</span><span class="w"> </span><span class="p">(</span><span class="n">identified</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">plan</span><span class="w"> </span><span class="n">id</span><span class="p">)</span>
<span class="w"> </span><span class="c1">------------------------------------------------------------------------------------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="c1">--Data Node Scan on &quot;__REMOTE_FQS_QUERY__&quot;</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="k">COALESCE</span><span class="p">((</span><span class="n">t3</span><span class="p">.</span><span class="n">a</span><span class="p">)::</span><span class="nb">text</span><span class="p">,</span><span class="w"> </span><span class="p">(</span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="p">)::</span><span class="nb">text</span><span class="p">))</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="n">Remote</span><span class="w"> </span><span class="n">query</span><span class="p">:</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">COALESCE</span><span class="p">(</span><span class="n">a</span><span class="p">::</span><span class="nb">text</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="p">::</span><span class="nb">text</span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="ss">&quot;coalesce&quot;</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="k">public</span><span class="p">.</span><span class="n">t3</span>
<span class="p">(</span><span class="mi">10</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
<span class="c1">-- Delete the table:</span>
<span class="n">mysql_db</span><span class="o">=#</span><span class="w"> </span><span class="k">DROP</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">t3</span><span class="p">;</span>
<span class="c1">-- Switch to the gaussdb database.</span>
<span class="n">mysql_db</span><span class="o">=#</span><span class="w"> </span><span class="err">\</span><span class="k">c</span><span class="w"> </span><span class="n">gaussdb</span>
<span class="c1">-- Delete the databases:</span>
<span class="k">DROP</span><span class="w"> </span><span class="k">DATABASE</span><span class="w"> </span><span class="n">ora_db</span><span class="p">;</span>
<span class="k">DROP</span><span class="w"> </span><span class="k">DATABASE</span><span class="w"> </span><span class="n">td_db</span><span class="p">;</span>
<span class="k">DROP</span><span class="w"> </span><span class="k">DATABASE</span><span class="w"> </span><span class="n">mysql_db</span><span class="p">;</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_0075.html">Type Conversion</a></div>
</div>
</div>