Functions of the XMLType Type
- createxml(varchar2[,varchar2,numeric,numeric])
Description: Statically creates the XMLType type. The input parameters are of the varchar2 type.
Parameters: The first parameter is the character string to be converted to XMLType (mandatory column). The second parameter is the optional schema URL used to make the input comply with the specified schema (optional column, which is empty by default and does not take effect currently). The third parameter is the flag indicating whether the instance is valid according to the given XML schema (optional column, which is 0 by default and does not take effect currently). The fourth parameter is the flag indicating whether the instance is well-formed (optional column, which is 0 by default and does not take effect currently).
Return type: XMLType
Example:1 2 3 4 5
gaussdb=# SELECT createxml('<a>123</a>'); createxml -------------- <a>123</a> (1 row)
- Different from that in database A, in PL/SQL, createxml allows input parameters to be empty strings and returns NULL.
- For character encoding, only UTF-8, GBK, ZHS16GBK, and LATIN1 to LATIN10 are supported, and the version column can only be set to 1.x.
- The createxml function can be invoked using the xmltype.createxml() syntax.
- In this chapter, the function whose input parameter is xmltype() can be invoked in xmltype().func() mode. The XMLType type returned by a function is transferred to the next function as the input parameter. This syntax supports multi-layer nesting. (If the input parameter is defined as XMLType by a user, this syntax is not supported.)
Example:
1 2 3 4 5
gaussdb=# SELECT xmltype('<a>123<b>456</b></a>').extract('/a/b').getstringval(); xmltypefunc ------------- <b>456</b> (1 row)
The actual effect of the preceding example is the same as that of the following function nesting:1 2 3 4 5
gaussdb=# SELECT getstringval(extractxml(xmltype('<a>123<b>456</b></a>'),'/a/b')); getstringval -------------- <b>456</b> (1 row)
- In a stored procedure, variables of the XMLType type can invoke functions in a.func() mode. This syntax supports one-layer nesting.
1 2 3 4 5 6 7 8 9 10
gaussdb=# declare a xmltype; b varchar2; begin a:=xmltype('<a>123<b>456</b></a>'); b:=a.getstringval(); RAISE NOTICE 'xmltype_str is : %',b; end; / NOTICE: xmltype_str is : <a>123<b>456</b></a>
- createxml(clob [,varchar2,numeric ,numeric])
Description: Statically creates the XMLType type. The input parameters are of the CLOB type.
Parameters: The first parameter is the CLOB to be converted to XMLType (mandatory column). The second parameter is the optional schema URL used to make the input comply with the specified schema (optional column, which is empty by default and does not take effect currently). The third parameter is the flag indicating whether the instance is valid according to the given XML schema (optional column, which is 0 by default and does not take effect currently). The fourth parameter is the flag indicating whether the instance is well-formed (optional column, which is 0 by default and does not take effect currently).
Return type: XMLType
Example:1 2 3 4 5 6 7 8 9 10 11 12
gaussdb=# declare xmltype_clob clob; xmltype_obj xmltype; xmltype_str varchar2(1000); begin xmltype_clob := '<a>123</a>'; xmltype_obj := createxml(xmltype_clob); xmltype_str := xmltype_obj.getstringval(); RAISE NOTICE 'xmltype_str is : %',xmltype_str; end; / NOTICE: xmltype_str is : <a>123</a>
The maximum size of the input parameter of the CLOB type is 1 GB minus 1 byte.
- createxml(blob,numeric[,varchar2,numeric,numeric])
Description: Statically creates the XMLType type. The input parameters are of the BLOB type.
Parameters: The first parameter is the BLOB to be converted to XMLType (mandatory column). The second parameter is the character set ID of the input XML data (mandatory column). The third parameter is the optional schema URL used to make the input comply with the specified schema (optional column, which is empty by default and does not take effect currently). The fourth parameter is the flag indicating whether the instance is valid according to the given XML schema (optional column, which is 0 by default and does not take effect currently). The fifth parameter is the flag indicating whether the instance is well-formed (optional column, which is 0 by default and does not take effect currently).
Return type: XMLType
Example:1 2 3 4 5 6 7 8 9 10 11 12 13
gaussdb=# declare xmltype_blob blob; xmltype_obj xmltype; xmltype_str varchar2(1000); begin xmltype_blob := xmltype('<a>123</a>').getblobval(7); xmltype_obj := createxml(xmltype_blob,7); xmltype_str := xmltype_obj.getstringval(); RAISE NOTICE 'xmltype_str is : %',xmltype_str; end; / NOTICE: xmltype_str is : <?xml version="1.0" encoding="UTF8"?> <a>123</a>
- The maximum size of input parameters of the BLOB type is 256 MB minus 1 byte.
- The character set ID ranges from 1 to 43.
- getblobval(xmltype,numeric)
Description: Converts the XMLType type to the BLOB type. The xmltype().func() method can be invoked.
Parameters: The first parameter is of the XMLType type, and the second parameter is the ID of the target character set to be converted.
Return type: BLOB
Example:1 2 3 4 5
gaussdb=# SELECT getblobval(xmltype('<asd/>'),7); getblobval ------------------------------------------------------------------------------------------ 3C3F786D6C2076657273696F6E3D22312E302220656E636F64696E673D2255544638223F3E0A3C6173642F3E (1 row)
xmltype ().func ():1 2 3 4 5
gaussdb=# SELECT xmltype('<asd/>').getblobVal(7); xmltypefunc ------------------------------------------------------------------------------------------ 3C3F786D6C2076657273696F6E3D22312E302220656E636F64696E673D2255544638223F3E0A3C6173642F3E (1 row)
The maximum length of the input parameter of the XMLType type is 256 MB minus 1 byte.
- getclobval(xmltype)
Description: Converts the XMLType type to the CLOB type. The xmltype().func() method can be invoked.
Parameter: The input parameter is of the XMLType type.
Return type: CLOB
Example:1 2 3 4 5
gaussdb=# SELECT getclobval(xmltype('<a>123</a>')); getclobval -------------- <a>123</a> (1 row)
xmltype ().func ():1 2 3 4 5
gaussdb=# SELECT xmltype('<a>123</a>').getclobval(); xmltypefunc -------------- <a>123</a> (1 row)
- getnumberval(xmltype)
Description: Converts the XMLType type to the numeric type. The xmltype().func() method can be invoked.
Parameter: The input parameter is of the XMLType type.
Return type: numeric
Example:1 2 3 4 5
gaussdb=# SELECT getnumberval(xmltype('<a>123</a>').extract('/a/text()')); getnumberval -------------- 123 (1 row)
xmltype ().func ():1 2 3 4 5
gaussdb=# SELECT xmltype('<a>123</a>').extract('/a/text()').getnumberval(); xmltypefunc -------------- 123 (1 row)
- isfragment(xmltype)
Description: Returns a result indicating whether the XMLType type is fragment (1) or document (0). The xmltype().func() method can be invoked.
Parameter: The input parameter is of the XMLType type.
Return type: numeric
Example:1 2 3 4 5
gaussdb=# SELECT isfragment(xmltype('<a>123</a>')); isfragment -------------- 0 (1 row)
xmltype ().func ():1 2 3 4 5
gaussdb=# SELECT xmltype('<a>123</a>').isfragment(); xmltypefunc -------------- 0 (1 row)
- xmltype(varchar2[,varchar2,numeric,numeric])
Description: Creates the XMLType type from the varchar2 type.
Parameters: The first parameter is the character string to be converted to XMLType (mandatory column). The second parameter is the optional schema URL used to make the input comply with the specified schema (optional column, which is empty by default and does not take effect currently). The third parameter is the flag indicating whether the instance is valid according to the given XML schema (optional column, which is 0 by default and does not take effect currently). The fourth parameter is the flag indicating whether the instance is well-formed (optional column, which is 0 by default and does not take effect currently).
Return type: XMLType
Example:1 2 3 4 5
gaussdb=# SELECT xmltype('<a>123</a>'); xmltype -------------- <a>123</a> (1 row)
- Different from that in database A, in PL/SQL, XMLType allows input parameters to be empty strings and returns NULL.
- For character encoding, only UTF-8, GBK, ZHS16GBK, and LATIN1 to LATIN10 are supported, and the version column can only be set to 1.x.
- xmltype(clob[,varchar2,numeric,numeric])
Description: Creates the XMLType type from the CLOB type.
Parameters: The first parameter is the CLOB to be converted to XMLType (mandatory column). The second parameter is the optional schema URL used to make the input comply with the specified schema (optional column, which is empty by default and does not take effect currently). The third parameter is the flag indicating whether the instance is valid according to the given XML schema (optional column, which is 0 by default and does not take effect currently). The fourth parameter is the flag indicating whether the instance is well-formed (optional column, which is 0 by default and does not take effect currently).
Return type: XMLType
Example:1 2 3 4 5 6 7 8 9 10 11 12
gaussdb=# declare xmltype_clob clob; xmltype_obj xmltype; xmltype_str varchar2(1000); begin xmltype_clob := '<a>123</a>'; xmltype_obj := xmltype(xmltype_clob); xmltype_str := xmltype_obj.getstringval(); RAISE NOTICE 'xmltype_str is : %',xmltype_str; end; / NOTICE: xmltype_str is : <a>123</a>
The maximum size of the input parameter of the CLOB type is 1 GB minus 1 byte.
- xmltype(blob, numeric [,varchar2,numeric ,numeric])
Description: Creates the XMLType type from the BLOB type.
Parameters: The first parameter is the BLOB to be converted to XMLType (mandatory column). The second parameter is the character set ID of the input XML data. The third parameter is the optional schema URL used to make the input comply with the specified schema (optional column, which is empty by default and does not take effect currently). The fourth parameter is the flag indicating whether the instance is valid according to the given XML schema (optional column, which is 0 by default and does not take effect currently). The fifth parameter is the flag indicating whether the instance is well-formed (optional column, which is 0 by default and does not take effect currently).
Return type: XMLType
Example:1 2 3 4 5 6 7 8 9 10 11 12 13
gaussdb=# declare xmltype_blob blob; xmltype_obj xmltype; xmltype_str varchar2(1000); begin xmltype_blob := getblobval(createxml('<a>123</a>'),7); xmltype_obj := xmltype(xmltype_blob,7); xmltype_str := xmltype_obj.getstringval(); RAISE NOTICE 'xmltype_str is : %',xmltype_str; end; / NOTICE: xmltype_str is : <?xml version="1.0" encoding="UTF8"?> <a>123</a>
- The maximum size of input parameters of the BLOB type is 256 MB minus 1 byte.
- The character set ID ranges from 1 to 42.
- getstringval(xmltype)
Description: Converts the XMLType to a string.
Parameter: XMLType to be converted.
Return type: varchar2
The getstringval function can be invoked in either of the following ways:
Example 1:
gaussdb=# SELECT getstringval('<a>123<b>456</b></a>'); getstringval ---------------------- <a>123<b>456</b></a> (1 row)
Example 2: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<a>123<b>456</b></a>').getstringval(); xmltypefunc ---------------------- <a>123<b>456</b></a> (1 row)
- getrootelement(xmltype)
Description: Gets the root element of the XMLType type.
Parameter: XMLType whose root element is to be obtained.
Return type: varchar2
The getrootelement function can be invoked in either of the following ways:
Example 1:
gaussdb=# SELECT getrootelement('<a>123<b>456</b></a>'); getrootelement ---------------- a (1 row)
Example 2: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<a>123<b>456</b></a>').getrootelement(); xmltypefunc ------------- a (1 row)
- getnamespace(xmltype)
Description: Gets the namespace of the XMLType top-level element.
Parameter: XMLType whose namespace is to be obtained.
Return type: varchar2
The getnamespace function can be invoked in either of the following ways:
Example 1:
gaussdb=# SELECT getnamespace('<c:a xmlns:c="asd">123<d:b xmlns:d="qwe">456</d:b></c:a>'); getnamespace -------------- asd (1 row)
Example 2: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<c:a xmlns:c="asd">123<d:b xmlns:d="qwe">456</d:b></c:a>').getnamespace(); xmltypefunc ------------- asd (1 row)
- existsnode(xmltype, varchar2[, varchar2])
Description: Determines whether the XML node exists in XMLType based on the XPath expression. If the XML node exists, 1 is returned. Otherwise, 0 is returned.
Parameters: XMLType to be queried, path of the XPath node to be queried, and namespace of the XPath path (If the input parameter has a namespace, aliases must be defined for both the XPath and namespace, as shown in example 3.)
Return type: numeric
The existsnode function can be invoked in either of the following ways:
Example 1:
gaussdb=# SELECT existsnode('<a>123<b>456</b></a>','/a/b'); existsnode ------------ 1 (1 row)
Example 2: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<a>123<b>456</b></a>').existsnode('/a/b'); xmltypefunc ------------- 1 (1 row)
Example 3:
gaussdb=# SELECT existsnode('<a:b xmlns:a="asd">123<c>456</c></a:b>','/a:b/c','xmlns:a="asd"'); existsnode ------------ 1 (1 row)
Example 4: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<a:b xmlns:a="asd">123<c>456</c></a:b>').existsnode('/a:b/c','xmlns:a="asd"'); xmltypefunc ------------- 1 (1 row)
- extractxml(xmltype, varchar2[, varchar2])
Description: Checks whether an XML node exists in the given XMLType based on the XPath expression. If yes, the XMLType containing the node is returned. If no, NULL is returned. The return value can be inserted into a table of the XMLType type.
Parameters: XMLType to be queried, path of the XPath node to be queried, and namespace of the XPath path (If the input parameter has a namespace, aliases must be defined for both the XPath and namespace, as shown in example 3.)
Return type: XMLType
The extractxml function can be invoked in either of the following ways:
Example 1:
gaussdb=# SELECT extractxml('<a>123<b>456</b></a>','/a/b'); extractxml ------------ <b>456</b> (1 row)
Example 2: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<a>123<b>456</b></a>').extract('/a/b'); xmltypefunc ------------- <b>456</b> (1 row) gaussdb=# SELECT xmltype('<a>123<b>456</b></a>').extractxml('/a/b'); xmltypefunc ------------- <b>456</b> (1 row)
Example 3:
gaussdb=# SELECT extractxml('<a:b xmlns:a="asd">123<c>456</c></a:b>','/a:b','xmlns:a="asd"'); extractxml ---------------------------------------- <a:b xmlns:a="asd">123<c>456</c></a:b> (1 row)
Example 4: The invoking mode is compatible with the ORA syntax.
gaussdb=# SELECT xmltype('<a:b xmlns:a="asd">123<c>456</c></a:b>').extract('/a:b','xmlns:a="asd"'); xmltypefunc ---------------------------------------- <a:b xmlns:a="asd">123<c>456</c></a:b> (1 row) gaussdb=# SELECT xmltype('<a:b xmlns:a="asd">123<c>456</c></a:b>').extractxml('/a:b','xmlns:a="asd"'); xmltypefunc ---------------------------------------- <a:b xmlns:a="asd">123<c>456</c></a:b> (1 row)
- extractvalue(xmltype | xml, varchar2[, varchar2])
Description: Extracts the value of an XPath expression from an XML file based on the XPath expression (only XPath 1.0 is supported). The result of the XPath expression must be a single node and must be a text node, attribute, or element. If the XPath expression contains an element expression, the element must have a text node as a child node. The function returns the text. If the result is an attribute, the function returns the value of the attribute.
Parameters: xmltype | xml: XML text to be queried; varchar2: XPath expression to be queried (XPath node path); [, varchar2] (optional): Namespace of the XPath node path. (If the input parameter contains a namespace with an alias, you need to define an alias for both the XPath expression and namespace. If the default namespace is used, you do not need to define an alias, as shown in example 3.)
Return type: varchar2
The extractvalue function can be invoked in two ways: input without namespace and input with namespace.
Example 1: The input does not contain a namespace.
gaussdb=# SELECT EXTRACTVALUE(xmltype('<book><title>Harry Potter</title><author>J.K. Rowling</author></book>'), '/book/title') AS book_title; book_title -------------- Harry Potter (1 row)
Example 2: The input contains a namespace.
gaussdb=# SELECT EXTRACTVALUE(xmltype('<ns:book xmlns:ns="http://www.example.com"><ns:title>Harry Potter</ns:title><ns:author>J.K. Rowling</ns:author></ns:book>'), '/ns:book/ns:title', 'xmlns:ns="http://www.example.com"') AS book_title; book_title -------------- Harry Potter (1 row)
Example 3: The input contains multiple namespaces.
gaussdb=# SELECT EXTRACTVALUE(xmltype('<ns:book xmlns:ns="http://www.example.com" xmlns:ff="http://www.ff.com"><ff:title>Harry Potter</ff:title><ns:author>J.K. Rowling</ns:author></ns:book>'), '/ns:book/ff:title', 'xmlns:ns="http://www.example.com" xmlns:ff="http://www.ff.com"') AS book_title; book_title -------------- Harry Potter (1 row) gaussdb=# SELECT EXTRACTVALUE(xmltype('<store><book xmlns="abc"><root xmlns="abcd">mike</root><root>mikeab</root></book><root xmlns="abcd">mikedwsa</root></store>'), '//root', 'xmlns="abc" xmlns:ns2="abc1" xmlns="abcd"') FROM dual; extractvalue -------------- mikeab (1 row)
- If the input contains multiple namespaces, they can be separated by one or more spaces (or newline characters). However, the namespace expression is in the xmlns:Name="Namespace" format and the default namespace rule is in the xmlns='URL' format.
- This function is compatible with the xmltype expression function, but the node value returned by the xmltype text must be unique.
- The XPath expression supports only XPath 1.0.
- Currently, the namespace URL in the XML text cannot be a space, and the namespace URL in the namespace expression cannot be a space.
- In the default namespace scenario, the default namespace declared first in the namespace expression is the default namespace of the current XML text.
- xmlsequence(xmltype)
Description: Converts an XMLTYPE parameter into an array of the XMLTYPE type. Each array element is an XMLTYPE object. The input parameter of this function cannot be null and must be a valid XML document. If the input parameter does not meet the requirements, the function returns a null value or throws an exception. This function can be used to process multiple child nodes in an XML document or split an XML document into multiple fragments.
Parameter: The input parameter is of the XMLType type.
Return value type: array of the XMLType type
Example 1: If you want to convert this document into an array containing three elements, each of which is a book node, use the following statement:gaussdb=# SELECT xmlsequence(xmltype('<books><book><title>The Catcher in the Rye</title><author>J.D. Salinger</author><year>1951</year></book><book><title>1984</title><author>George Orwell</author><year>1949</year></book><book><title>The Hitchhiker''s Guide to the Galaxy</title><author>Douglas Adams</author><year>1979</year></book></books>')); xmlsequence ----------------------------------------------------------- {"<books> + <book> + <title>The Catcher in the Rye</title> + <author>J.D. Salinger</author> + <year>1951</year> + </book> + <book> + <title>1984</title> + <author>George Orwell</author> + <year>1949</year> + </book> + <book> + <title>The Hitchhiker's Guide to the Galaxy</title>+ <author>Douglas Adams</author> + <year>1979</year> + </book> + </books>"} (1 row)
Example 2: If you want to extract the title and author of each book from this array, use the following statement:gaussdb=# SELECT unnest(xmlsequence(xmltype('<books><book><title>The Catcher in the Rye</title><author>J.D. Salinger</author><year>1951</year></book><book><title>1984</title><author>George Orwell</author><year>1949</year></book><book><title>The Hitchhiker''s Guide to the Galaxy</title><author>Douglas Adams</author><year>1979</year></book></books>').extract('//title/text()'))) AS title , unnest(xmlsequence(xmltype('<books><book><title>The Catcher in the Rye</title><author>J.D. Salinger</author><year>1951</year></book><book><title>1984</title><author>George Orwell</author><year>1949</year></book><book><title>The Hitchhiker''s Guide to the Galaxy</title><author>Douglas Adams</author><year>1979</year></book></books>').extract('//author/text()'))) AS author; title | author ----------------------------------------------------------------+----------------------------------------- The Catcher in the Rye1984The Hitchhiker's Guide to the Galaxy | J.D. SalingerGeorge OrwellDouglas Adams (1 row)
Example 3: If you want to convert the array into a JSON string, use the following statement:gaussdb=# SELECT array_to_json(array_agg(row_to_json(t))) FROM ( SELECT unnest(xmlsequence(xmltype('<books><book><title>The Catcher in the Rye</title><author>J.D. Salinger</author><year>1951</year></book><book><title>1984</title><author>George Orwell</author><year>1949</year></book><book><title>The Hitchhiker''s Guide to the Galaxy</title><author>Douglas Adams</author><year>1979</year></book></books>').extract('//title/text()'))) AS title , unnest(xmlsequence(xmltype('<books><book><title>The Catcher in the Rye</title><author>J.D. Salinnger</author><year>1951</year></book><book><title>1984</title><author>George Orwell</author><year>1949</year></book><book><title>The Hitchhiker''s Guide to the Galaxy</title><author>Douglas Adams</author><year>1979</year></book></books>').extract('//author/text()'))) AS author ) t; array_to_json --------------------------------------------------------------------------------------------------------- [{"title":"The Catcher in the Rye1984The Hitchhiker's Guide to the Galaxy","author":"J.D. SalinngerGeorge OrwellDouglas Adams"}] (1 row)
If an XML file contains double quotation marks, the result of the xmlsequence function contains escape characters of double quotation marks when you query the xmlsequence function independently. The use of the xmlsequence function is not affected.
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot