Description: Generates an XML value from character data.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlparse(document '<foo>bar</foo>'); xmlparse ---------------- <foo>bar</foo> (1 row) |
Description: Generates a string from XML values.
Return type: type, which can be character, character varying, or text (or its alias)
Example:
1 2 3 4 5 | SELECT xmlserialize(content 'good' AS CHAR(10)); xmlserialize -------------- good (1 row) |
Description: Creates an XML note that uses the specified text as the content. The text cannot contain two consecutive hyphens (--) or end with a hyphen (-). If the parameter is null, the result is also null.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlcomment('hello'); xmlcomment -------------- <!--hello--> (1 row) |
Description: Concatenates a list of XML values into a single value. Null values are ignored. If all parameters are null, the result is also null.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlconcat('<abc/>', '<bar>foo</bar>'); xmlconcat ---------------------- <abc/><bar>foo</bar> (1 row) |
Note: If XML declarations exist and they are the same XML version, the result will use the version. Otherwise, the result does not use any version. If all XML values have the standalone attribute whose status is yes, the standalone attribute in the result is yes. If at least one XML value's standalone attribute is no, the standalone attribute in the result is no. Otherwise, the result does not contain the standalone attribute.
Example:
1 2 3 4 5 | SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>'); xmlconcat ----------------------------------- <?xml version="1.1"?><foo/><bar/> (1 row) |
Description: Generates an XML element with the given name, attribute, and content.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent'); xmlelement ------------------------------------- <foo bar="2020-08-15">content</foo> (1 row) |
Description: Generates an XML forest (sequence) of an element with a given name and content.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlforest('abc' AS foo, 123 AS bar); xmlforest ------------------------------ <foo>abc</foo><bar>123</bar> (1 row) |
Description: Creates an XML processing instruction. The content cannot contain the character sequence of ?>.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlpi(name php, 'echo "hello world";'); xmlpi ----------------------------- <?php echo "hello world";?> (1 row) |
Description: Modifies the attributes of the root node of an XML value. If a version is specified, it replaces the value in the version declaration of the root node. If a standalone value is specified, it replaces the standalone value in the root node.
Return type: XML
Example:
1 2 3 4 5 | SELECT xmlroot(xmlparse(document '<?xml version="1.0" standalone="no"?><content>abc</content>'), version '1.1', standalone yes); xmlroot -------------------------------------------------------------- <?xml version="1.1" standalone="yes"?><content>abc</content> (1 row) |
Description: The xmlagg function is an aggregate function that concatenates input values.
Return type: XML
Example:
1 2 3 4 5 6 7 8 | CREATE TABLE test (y int, x xml); INSERT INTO test VALUES (1, '<foo>abc</foo>'); INSERT INTO test VALUES (2, '<bar/>'); SELECT xmlagg(x) FROM test; xmlagg ---------------------- <foo>abc</foo><bar/> (1 row) |
To determine the concatenation sequence, you can add an ORDER BY clause for an aggregate call, for example:
1 2 3 4 5 | SELECT xmlagg(x ORDER BY y DESC) FROM test; xmlagg ---------------------- <bar/><foo>abc</foo> (1 row) |
Description: IS DOCUMENT returns true if the XML value of the parameter is a correct XML document; if the XML document is incorrect, false is returned. If the parameter is null, a null value is returned.
Return type: bool
Description: Returns true if the XML value of the parameter is not a correct XML document. If the XML document is correct, false is returned. If the parameter is null, a null value is returned.
Return type: bool
Description: If the xpath expression in the first parameter returns any node, the XMLEXISTS function returns true. Otherwise, the function returns false. (If any parameter is null, the result is null.) The BY REF clause is invalid and is used to maintain SQL compatibility.
Return type: bool
Example:
1 2 3 4 5 | SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>'); xmlexists ----------- t (1 row) |
Description: Checks whether a text string is a well-formatted XML value and returns a Boolean result. If the xmloption parameter is set to DOCUMENT, the document is checked. If the xmloption parameter is set to CONTENT, the content is checked.
Return type: bool
Example:
1 2 3 4 5 | SELECT xml_is_well_formed('<abc/>'); xml_is_well_formed -------------------- t (1 row) |
Description: Checks whether a text string is a well-formatted text and returns a Boolean result.
Return type: bool
Example:
1 2 3 4 5 | SELECT xml_is_well_formed_document('<test:foo xmlns:test="http://test.com/test">bar</test:foo>'); xml_is_well_formed_document ----------------------------- t (1 row) |
Description: Checks whether a text string is a well-formatted content and returns a Boolean result.
Return type: bool
Example:
1 2 3 4 5 | SELECT xml_is_well_formed_content('content'); xml_is_well_formed_content ---------------------------- t (1 row) |
Description: Returns an array of XML values corresponding to the set of nodes produced by the xpath expression. If the xpath expression returns a scalar value instead of a set of nodes, an array of individual elements is returned. The second parameter xml must be a complete XML document, which must have a root node element. The third parameter is an array map of a namespace. The array should be a two-dimensional text array, and the length of the second dimension should be 2. (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 xpath functions, aliases are local.
Return type: XML value array
Example:
1 2 3 4 5 | SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', ARRAY[ARRAY['my', 'http://example.com']]); xpath -------- {test} (1 row) |
Description: The xpath_exists function is a special form of the xpath function. This function does not return an XML value that satisfies the xpath function; it returns a Boolean value indicating whether the query is satisfied. This function is equivalent to the standard XMLEXISTS predicate, but it also provides support for a namespace mapping parameter.
Return type: bool
Example:
1 2 3 4 5 | SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', ARRAY[ARRAY['my', 'http://example.com']]); xpath_exists -------------- t (1 row) |
Description: Generates a table based on the input XML data, XPath expression, and column definition. An xmltable is similar to a function in syntax, but it can appear only as a table in the FROM clause of a query.
Return value: setof record
Syntax:
1 2 3 4 5 6 | XMLTABLE ( [ XMLNAMESPACES ( namespace_uri AS namespace_name [, ...] ), ] row_expression PASSING [ BY { REF | VALUE } ] document_expression [ BY { REF | VALUE } ] COLUMNS name { type [ PATH column_expression ] [ DEFAULT default_expression ] [ NOT NULL | NULL ] | FOR ORDINALITY } [, ...] ) |
Parameter:
XPath 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.
Example:
1 2 3 4 5 6 7 8 9 10 11 12 | SELECT * FROM XMLTABLE('/ROWS/ROW' PASSING '<ROWS><ROW id="1"><COUNTRY_ID>AU</COUNTRY_ID><COUNTRY_NAME>Australia</COUNTRY_NAME></ROW><ROW id="2"><COUNTRY_ID>FR</COUNTRY_ID><COUNTRY_NAME>France</COUNTRY_NAME></ROW><ROW id="3"><COUNTRY_ID>SG</COUNTRY_ID><COUNTRY_NAME>Singapore</COUNTRY_NAME></ROW></ROWS>' COLUMNS id INT PATH '@id', _id FOR ORDINALITY, country_id TEXT PATH 'COUNTRY_ID', country_name TEXT PATH 'COUNTRY_NAME' NOT NULL); id | _id | country_id | country_name ----+-----+---------------+-------------- 1 | 1 | AU | Australia 2 | 2 | FR | France 3 | 3 | SG | Singapore (3 rows) |
Description: Maps the contents of a table to XML values.
Return type: XML
Description: Maps a relational table schema to an XML schema document.
Return type: XML
Description: Maps a relational table to XML values and schema documents.
Return type: XML
Description: Maps the contents of an SQL query to XML values.
Return type: XML
Description: Maps an SQL query into an XML schema document.
Return type: XML
Description: Maps SQL queries to XML values and schema documents.
Return type: XML
Description: Maps a cursor query to an XML value.
Return type: XML
Description: Maps a cursor query to an XML schema document.
Return type: XML
Description: Maps a table in a schema to an XML value.
Return type: XML
Description: Maps a table in a schema to an XML schema document.
Return type: XML
Description: Maps a table in a schema to an XML value and a schema document.
Return type: XML
Description: Maps a database table to an XML value.
Return type: XML
Description: Maps a database table to an XML schema document.
Return type: XML
Description: Maps database tables to XML values and schema documents.
Return type: XML
The parameters for mapping a table to an XML value are described as follows: