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

107 lines
20 KiB
HTML

<a name="EN-US_TOPIC_0000001450456564"></a><a name="EN-US_TOPIC_0000001450456564"></a>
<h1 class="topictitle1">Processing XML</h1>
<div id="body0000001450456564"><p id="EN-US_TOPIC_0000001450456564__p557123910484">To process values of the XML data type, GaussDB (DWS) provides the <strong id="EN-US_TOPIC_0000001450456564__b4977191514313">xpath</strong> and <strong id="EN-US_TOPIC_0000001450456564__b356812195318">xpath_exists</strong> functions, as well as the <strong id="EN-US_TOPIC_0000001450456564__b36851452133117">XMLTABLE</strong> table function.</p>
<div class="section" id="EN-US_TOPIC_0000001450456564__section429715961311"><h4 class="sectiontitle">xpath(xpath, xml [, nsarray])</h4><p id="EN-US_TOPIC_0000001450456564__p195195291069">Description: Returns an array of XML values corresponding to the set of nodes produced by the <strong id="EN-US_TOPIC_0000001450456564__b1172483879112832">xpath</strong> expression. If the <strong id="EN-US_TOPIC_0000001450456564__b136451650113015">xpath</strong> expression returns a scalar value instead of a set of nodes, an array of individual elements is returned.</p>
<p id="EN-US_TOPIC_0000001450456564__p18771152966">The second parameter <strong id="EN-US_TOPIC_0000001450456564__b1471271243112832">xml</strong> must be a complete XML document, which must have a root node element.</p>
<p id="EN-US_TOPIC_0000001450456564__p152977910135">The third parameter is optional and is an array mapping of a namespace. The array should be a two-dimensional text array, and the length of the second dimension should be <strong id="EN-US_TOPIC_0000001450456564__b2520131013215">2</strong>. (It should be an array of arrays, each containing exactly two elements). The first element of each array item is the alias of the namespace name, and the second element is the namespace URI. The alias provided in this array does not have to be the same as the alias used in the XML document itself. In other words, in the context of both XML documents and <strong id="EN-US_TOPIC_0000001450456564__b13531054539401">xpath</strong> functions, aliases are local.</p>
<p id="EN-US_TOPIC_0000001450456564__p14297179141315">Return type: XML value array</p>
<p id="EN-US_TOPIC_0000001450456564__p029716991319">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001450456564__screen14297393133"><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="n">xpath</span><span class="p">(</span><span class="s1">'/my:a/text()'</span><span class="p">,</span><span class="w"> </span><span class="s1">'&lt;my:a xmlns:my=&quot;http://example.com&quot;&gt;test&lt;/my:a&gt;'</span><span class="p">,</span><span class="w"> </span><span class="nb">ARRAY</span><span class="p">[</span><span class="nb">ARRAY</span><span class="p">[</span><span class="s1">'my'</span><span class="p">,</span><span class="w"> </span><span class="s1">'http://example.com'</span><span class="p">]]);</span>
<span class="w"> </span><span class="n">xpath</span>
<span class="c1">--------</span>
<span class="w"> </span><span class="err">{</span><span class="n">test</span><span class="err">}</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>
<p id="EN-US_TOPIC_0000001450456564__p14987248783">Process the default (anonymous) namespace:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001450456564__screen10158163131016"><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="n">xpath</span><span class="p">(</span><span class="s1">'//mydefns:b/text()'</span><span class="p">,</span><span class="w"> </span><span class="s1">'&lt;a xmlns=&quot;http://example.com&quot;&gt;&lt;b&gt;test&lt;/b&gt;&lt;/a&gt;'</span><span class="p">,</span><span class="nb">ARRAY</span><span class="p">[</span><span class="nb">ARRAY</span><span class="p">[</span><span class="s1">'mydefns'</span><span class="p">,</span><span class="w"> </span><span class="s1">'http://example.com'</span><span class="p">]]);</span>
<span class="w"> </span><span class="n">xpath</span>
<span class="c1">--------</span>
<span class="w"> </span><span class="err">{</span><span class="n">test</span><span class="err">}</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>
<div class="section" id="EN-US_TOPIC_0000001450456564__section57847518138"><h4 class="sectiontitle">xpath_exists(xpath, xml [, nsarray])</h4><p id="EN-US_TOPIC_0000001450456564__p197174611342">Description: The <strong id="EN-US_TOPIC_0000001450456564__b12502128379401">xpath_exists</strong> function is a special form of the <strong id="EN-US_TOPIC_0000001450456564__b7537726889401">xpath</strong> function. This function does not return an XML value that satisfies the <strong id="EN-US_TOPIC_0000001450456564__b9466506309401">xpath</strong> function; it returns a Boolean value indicating whether the query is satisfied. This function is equivalent to the standard <strong id="EN-US_TOPIC_0000001450456564__b7114396829401">XMLEXISTS</strong> predicate, but it also provides support for a namespace mapping parameter.</p>
<p id="EN-US_TOPIC_0000001450456564__p1371776133416">Return type: bool</p>
<p id="EN-US_TOPIC_0000001450456564__p10717196183411">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001450456564__screen15771546231"><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="n">xpath_exists</span><span class="p">(</span><span class="s1">'/my:a/text()'</span><span class="p">,</span><span class="w"> </span><span class="s1">'&lt;my:a xmlns:my=&quot;http://example.com&quot;&gt;test&lt;/my:a&gt;'</span><span class="p">,</span><span class="w"> </span><span class="nb">ARRAY</span><span class="p">[</span><span class="nb">ARRAY</span><span class="p">[</span><span class="s1">'my'</span><span class="p">,</span><span class="w"> </span><span class="s1">'http://example.com'</span><span class="p">]]);</span>
<span class="w"> </span><span class="n">xpath_exists</span>
<span class="c1">--------------</span>
<span class="w"> </span><span class="n">t</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>
<div class="section" id="EN-US_TOPIC_0000001450456564__section1417108131"><h4 class="sectiontitle">xmltable</h4><p id="EN-US_TOPIC_0000001450456564__p02334345017">Description: Generates a table based on the input XML data, <strong id="EN-US_TOPIC_0000001450456564__b18039907079401">XPath</strong> expression, and column definition. An <strong id="EN-US_TOPIC_0000001450456564__b9859803809401">xmltable</strong> is similar to a function in syntax, but it can appear only as a table in the FROM clause of a query.</p>
<p id="EN-US_TOPIC_0000001450456564__p1981994731310">Return value: setof record</p>
<p id="EN-US_TOPIC_0000001450456564__p664964111316">Syntax:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001450456564__screen9322411181211"><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="n">XMLTABLE</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">XMLNAMESPACES</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="n">namespace_uri</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">namespace_name</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="n">row_expression</span><span class="w"> </span><span class="n">PASSING</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="k">REF</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">VALUE</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="p">]</span>
<span class="n">document_expression</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="k">REF</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">VALUE</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="p">]</span>
<span class="n">COLUMNS</span><span class="w"> </span><span class="n">name</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="k">type</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">PATH</span><span class="w"> </span><span class="n">column_expression</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">DEFAULT</span><span class="w"> </span><span class="n">default_expression</span><span class="w"> </span><span class="p">]</span><span class="w"> </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="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">NULL</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">FOR</span><span class="w"> </span><span class="k">ORDINALITY</span><span class="w"> </span><span class="err">}</span>
<span class="p">[,</span><span class="w"> </span><span class="p">...]</span>
<span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001450456564__p1961072865612">Parameter:</p>
<ul id="EN-US_TOPIC_0000001450456564__ul10402114141410"><li id="EN-US_TOPIC_0000001450456564__li84021314151417">The optional XMLNAMESPACES clause is a comma-separated list of namespace definitions, where each <strong id="EN-US_TOPIC_0000001450456564__b4034883579401">namespace_uri</strong> is a text-type expression and each <strong id="EN-US_TOPIC_0000001450456564__b10135160899401">namespace_name</strong> is a simple identifier. XMLNAMESPACES specifies the XML namespaces used in the document and their aliases. The default namespace declaration is not supported.</li><li id="EN-US_TOPIC_0000001450456564__li2210857111518">The mandatory parameter <strong id="EN-US_TOPIC_0000001450456564__b14031847639401">row_expression</strong> is an <strong id="EN-US_TOPIC_0000001450456564__b21409934209401">XPath</strong> 1.0 expression. This expression calculates the sequence of XML nodes based on the provided XML document <strong id="EN-US_TOPIC_0000001450456564__b12561575199401">document_expression</strong>. The sequence is the sequence of converting <strong id="EN-US_TOPIC_0000001450456564__b9297628369401">xmltable</strong> to output lines. If the <strong id="EN-US_TOPIC_0000001450456564__b1737637419401">document_expression</strong> value is <strong id="EN-US_TOPIC_0000001450456564__b10325582779401">NULL</strong> or an empty node set generated by <strong id="EN-US_TOPIC_0000001450456564__b16861966809401">row_expression</strong>, no line is returned.</li><li id="EN-US_TOPIC_0000001450456564__li12973125082912">The <strong id="EN-US_TOPIC_0000001450456564__b12947627619401">document_expression</strong> parameter is used to input an XML document. The input document must be in the XML format. XML fragment data or XML documents in incorrect format are not accepted. The BY REF and BY VALUE clauses do not take effect. They are used only to implement SQL standard compatibility.</li><li id="EN-US_TOPIC_0000001450456564__li164031356102920">The COLUMNS clause specifies the column list definition in the output table. The column name and column data type are mandatory, and the path, default value, and whether the clause is empty are optional.<ul id="EN-US_TOPIC_0000001450456564__ul10535447124015"><li id="EN-US_TOPIC_0000001450456564__li19874163534019"><strong id="EN-US_TOPIC_0000001450456564__b2516958609401">column_expression</strong> of a column is an <strong id="EN-US_TOPIC_0000001450456564__b9197519679401">XPath</strong> 1.0 expression used to calculate the value of the column extracted from the current row based on <strong id="EN-US_TOPIC_0000001450456564__b6429556869401">row_expression</strong>. If <strong id="EN-US_TOPIC_0000001450456564__b2013191909401">column_expression</strong> is not specified, the field name is used as an implicit path.</li><li id="EN-US_TOPIC_0000001450456564__li88761835114019">A column can be marked as <strong id="EN-US_TOPIC_0000001450456564__b14187938239401">NOT NULL</strong>. If <strong id="EN-US_TOPIC_0000001450456564__b10176981079401">column_expression</strong> in the <strong id="EN-US_TOPIC_0000001450456564__b10580894009401">NOT NULL</strong> column does not return any data, and there is no DEFAULT clause or the calculation result of <strong id="EN-US_TOPIC_0000001450456564__b9506854229401">default_expression</strong> is <strong id="EN-US_TOPIC_0000001450456564__b16859610399401">NULL</strong>, an error is reported.</li><li id="EN-US_TOPIC_0000001450456564__li98782358404">The columns marked as <strong id="EN-US_TOPIC_0000001450456564__b19821801149401">FOR ORDINALITY</strong> are filled with row numbers starting from <strong id="EN-US_TOPIC_0000001450456564__b4478021509401">1</strong>. The sequence is the node sequence retrieved from the <strong id="EN-US_TOPIC_0000001450456564__b4884204659401">row_expression</strong> result set. A maximum of one column can be marked as <strong id="EN-US_TOPIC_0000001450456564__b18709512929401">FOR ORDINALITY</strong>.<div class="notice" id="EN-US_TOPIC_0000001450456564__note1259264119306"><span class="noticetitle"><img src="public_sys-resources/notice_3.0-en-us.png"> </span><div class="noticebody"><p id="EN-US_TOPIC_0000001450456564__p1543254743012"><strong id="EN-US_TOPIC_0000001450456564__b6417027519401">XPath</strong> 1.0 does not specify the order for nodes, so the order in which results are returned depends on the order in which data is obtained.</p>
</div></div>
</li></ul>
</li></ul>
<p id="EN-US_TOPIC_0000001450456564__p786371111112">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001450456564__screen1178394371413"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">XMLTABLE</span><span class="p">(</span><span class="s1">'/ROWS/ROW'</span>
<span class="n">PASSING</span><span class="w"> </span><span class="s1">'&lt;ROWS&gt;&lt;ROW id=&quot;1&quot;&gt;&lt;CITY_ID&gt;1002a&lt;/CITY_ID&gt;&lt;CITY_NAME&gt;snowcity&lt;/CITY_NAME&gt;&lt;/ROW&gt;&lt;ROW id=&quot;2&quot;&gt;&lt;CITY_ID&gt;1003b&lt;/CITY_ID&gt;&lt;CITY_NAME&gt;icecity&lt;/CITY_NAME&gt;&lt;/ROW&gt;&lt;ROW id=&quot;3&quot;&gt;&lt;CITY_ID&gt;1004c&lt;/CITY_ID&gt;&lt;CITY_NAME&gt;windcity&lt;/CITY_NAME&gt;&lt;/ROW&gt;&lt;/ROWS&gt;'</span>
<span class="n">COLUMNS</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="n">PATH</span><span class="w"> </span><span class="s1">'@id'</span><span class="p">,</span>
<span class="k">ordinality</span><span class="w"> </span><span class="k">FOR</span><span class="w"> </span><span class="k">ORDINALITY</span><span class="p">,</span>
<span class="n">CITY_id</span><span class="w"> </span><span class="nb">TEXT</span><span class="w"> </span><span class="n">PATH</span><span class="w"> </span><span class="s1">'CITY_ID'</span><span class="p">,</span><span class="n">CITY_name</span><span class="w"> </span><span class="nb">TEXT</span><span class="w"> </span><span class="n">PATH</span><span class="w"> </span><span class="s1">'CITY_NAME'</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">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">ordinality</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">city_id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">city_name</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="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1002</span><span class="n">a</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">snowcity</span>
<span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1003</span><span class="n">b</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">icecity</span>
<span class="w"> </span><span class="mi">3</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1004</span><span class="k">c</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">windcity</span>
<span class="p">(</span><span class="mi">3</span><span class="w"> </span><span class="k">rows</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_0067.html">XML Functions</a></div>
</div>
</div>