XML Functions
| PostgreSQL 9.3.25 Documentation | ||||
|---|---|---|---|---|
| Prev | Up | Chapter 9. Functions and Operators | Next | |
  The functions and function-like expressions described in this
   section operate on values of type
  
   xml
  
  .  Check
  
   Section 8.13
  
  for information about the
  
   xml
  
  type.  The function-like expressions
  
   xmlparse
  
  and
  
   xmlserialize
  
  for converting to and from
   type
  
   xml
  
  are not repeated here.  Use of most of these
   functions requires the installation to have been built
   with
  
   configure --with-libxml
  
  .
 
9.14.1. Producing XML Content
A set of functions and function-like expressions are available for producing XML content from SQL data. As such, they are particularly suitable for formatting query results into XML documents for processing in client applications.
9.14.1.1. xmlcomment
xmlcomment(text)
    The function
    
     xmlcomment
    
    creates an XML value
     containing an XML comment with the specified text as content.
     The text cannot contain
    
     "
     
      --
     
     "
    
    or end with a
    
     "
     
      -
     
     "
    
    so that the resulting construct is a valid
     XML comment.  If the argument is null, the result is null.
   
Example:
SELECT xmlcomment('hello');
  xmlcomment
--------------
 
   
9.14.1.2. xmlconcat
xmlconcat(xml[, ...])
    The function
    
     xmlconcat
    
    concatenates a list
     of individual XML values to create a single value containing an
     XML content fragment.  Null values are omitted; the result is
     only null if there are no nonnull arguments.
   
Example:
SELECT xmlconcat('foo ');
      xmlconcat
----------------------
 foo 
   
XML declarations, if present, are combined as follows. If all argument values have the same XML version declaration, that version is used in the result, else no version is used. If all argument values have the standalone declaration value "yes" , then that value is used in the result. If all argument values have a standalone declaration value and at least one is "no" , then that is used in the result. Else the result will have no standalone declaration. If the result is determined to require a standalone declaration but no version declaration, a version declaration with version 1.0 will be used because XML requires an XML declaration to contain a version declaration. Encoding declarations are ignored and removed in all cases.
Example:
SELECT xmlconcat('
   
9.14.1.3. xmlelement
xmlelement(name name [, xmlattributes(value [AS attname] [, ... ])] [, content, ...])
    The
    
     xmlelement
    
    expression produces an XML
     element with the given name, attributes, and content.
   
Examples:
SELECT xmlelement(name foo); xmlelement ------------SELECT xmlelement(name foo, xmlattributes('xyz' as bar)); xmlelement ------------------ SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent'); xmlelement ------------------------------------- content 
Element and attribute names that are not valid XML names are escaped by replacing the offending characters by the sequence _x HHHH _ , where HHHH is the character's Unicode codepoint in hexadecimal notation. For example:
SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
            xmlelement
----------------------------------
 
   
An explicit attribute name need not be specified if the attribute value is a column reference, in which case the column's name will be used as the attribute name by default. In other cases, the attribute must be given an explicit name. So this example is valid:
CREATE TABLE test (a xml, b xml); SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
But these are not:
SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
   
Element content, if specified, will be formatted according to its data type. If the content is itself of type xml , complex XML documents can be constructed. For example:
SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
                            xmlelement(name abc),
                            xmlcomment('test'),
                            xmlelement(name xyz));
                  xmlelement
----------------------------------------------
 
   Content of other types will be formatted into valid XML character data. This means in particular that the characters <, >, and & will be converted to entities. Binary data (data type bytea ) will be represented in base64 or hex encoding, depending on the setting of the configuration parameter xmlbinary . The particular behavior for individual data types is expected to evolve in order to align the SQL and PostgreSQL data types with the XML Schema specification, at which point a more precise description will appear.
9.14.1.4. xmlforest
xmlforest(content [AS name] [, ...])
    The
    
     xmlforest
    
    expression produces an XML
     forest (sequence) of elements using the given names and content.
   
Examples:
SELECT xmlforest('abc' AS foo, 123 AS bar);
          xmlforest
------------------------------
 abc 123 
SELECT xmlforest(table_name, column_name)
FROM information_schema.columns
WHERE table_schema = 'pg_catalog';
                                         xmlforest
-------------------------------------------------------------------------------------------
 pg_authid rolname 
 pg_authid rolsuper 
 ...
   As seen in the second example, the element name can be omitted if the content value is a column reference, in which case the column name is used by default. Otherwise, a name must be specified.
    Element names that are not valid XML names are escaped as shown
     for
    
     xmlelement
    
    above.  Similarly, content
     data is escaped to make valid XML content, unless it is already
     of type
    
     xml
    
    .
   
    Note that XML forests are not valid XML documents if they consist
     of more than one element, so it might be useful to wrap
    
     xmlforest
    
    expressions in
    
     xmlelement
    
    .
   
9.14.1.5. xmlpi
xmlpi(name target [, content])
    The
    
     xmlpi
    
    expression creates an XML
     processing instruction.  The content, if present, must not
     contain the character sequence
    
     ?>
    
    .
   
Example:
SELECT xmlpi(name php, 'echo "hello world";');
            xmlpi
-----------------------------
 
   
9.14.1.6. xmlroot
xmlroot(xml, version text | no value [, standalone yes|no|no value])
    The
    
     xmlroot
    
    expression alters the properties
     of the root node of an XML value.  If a version is specified,
     it replaces the value in the root node's version declaration; if a
     standalone setting is specified, it replaces the value in the
     root node's standalone declaration.
   
SELECT xmlroot(xmlparse(document 'abc '), version '1.0', standalone yes); xmlroot ----------------------------------------abc 
9.14.1.7. xmlagg
xmlagg(xml)
    The function
    
     xmlagg
    
    is, unlike the other
     functions described here, an aggregate function.  It concatenates the
     input values to the aggregate function call,
     much like
    
     xmlconcat
    
    does, except that concatenation
     occurs across rows rather than across expressions in a single row.
     See
    
     Section 9.20
    
    for additional information
     about aggregate functions.
   
Example:
CREATE TABLE test (y int, x xml); INSERT INTO test VALUES (1, 'abc '); INSERT INTO test VALUES (2, ''); SELECT xmlagg(x) FROM test; xmlagg ---------------------- abc 
To determine the order of the concatenation, an ORDER BY clause may be added to the aggregate call as described in Section 4.2.7 . For example:
SELECT xmlagg(x ORDER BY y DESC) FROM test;
        xmlagg
----------------------
 abc 
   
The following non-standard approach used to be recommended in previous versions, and may still be useful in specific cases:
SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
        xmlagg
----------------------
 abc 
   
9.14.2. XML Predicates
The expressions described in this section check properties of xml values.
9.14.2.1. IS DOCUMENT
xml IS DOCUMENT
The expression IS DOCUMENT returns true if the argument XML value is a proper XML document, false if it is not (that is, it is a content fragment), or null if the argument is null. See Section 8.13 about the difference between documents and content fragments.
9.14.2.2. IS NOT DOCUMENT
xml IS NOT DOCUMENT
The expression IS NOT DOCUMENT returns false if the argument XML value is a proper XML document, true if it is not (that is, it is a content fragment), or null if the argument is null.
9.14.2.3. XMLEXISTS
XMLEXISTS(text PASSING [BY REF] xml [BY REF])
    The function
    
     xmlexists
    
    returns true if the
     XPath expression in the first argument returns any nodes, and
     false otherwise.  (If either argument is null, the result is
     null.)
   
Example:
SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF 'Toronto Ottawa 
   
    The
    
     BY REF
    
    clauses have no effect in
     PostgreSQL, but are allowed for SQL conformance and compatibility
     with other implementations.  Per SQL standard, the
     first
    
     BY REF
    
    is required, the second is
     optional.  Also note that the SQL standard specifies
     the
    
     xmlexists
    
    construct to take an XQuery
     expression as first argument, but PostgreSQL currently only
     supports XPath, which is a subset of XQuery.
   
9.14.2.4. xml_is_well_formed
xml_is_well_formed(text)xml_is_well_formed_document(text)xml_is_well_formed_content(text)
    These functions check whether a
    
     text
    
    string is well-formed XML,
     returning a Boolean result.
    
     xml_is_well_formed_document
    
    checks for a well-formed
     document, while
    
     xml_is_well_formed_content
    
    checks
     for well-formed content.
    
     xml_is_well_formed
    
    does
     the former if the
    
     xmloption
    
    configuration
     parameter is set to
    
     DOCUMENT
    
    , or the latter if it is set to
    
     CONTENT
    
    .  This means that
    
     xml_is_well_formed
    
    is useful for seeing whether
     a simple cast to type
    
     xml
    
    will succeed, whereas the other two
     functions are useful for seeing whether the corresponding variants of
    
     XMLPARSE
    
    will succeed.
   
Examples:
SET xmloption TO DOCUMENT;
SELECT xml_is_well_formed('<>');
 xml_is_well_formed 
--------------------
 f
(1 row)
SELECT xml_is_well_formed('bar ');
 xml_is_well_formed_document 
-----------------------------
 t
(1 row)
SELECT xml_is_well_formed_document('bar');
 xml_is_well_formed_document 
-----------------------------
 f
(1 row) 
   The last example shows that the checks include whether namespaces are correctly matched.
9.14.3. Processing XML
   To process values of data type
   
    xml
   
   , PostgreSQL offers
    the functions
   
    xpath
   
   and
   
    xpath_exists
   
   , which evaluate XPath 1.0
    expressions.
  
xpath(xpath, xml [, nsarray])
   The function
   
    xpath
   
   evaluates the XPath
    expression
   
    
     xpath
    
   
   (a
   
    text
   
   value)
    against the XML value
   
    
     xml
    
   
   .  It returns an array of XML values
    corresponding to the node set produced by the XPath expression.
    If the XPath expression returns a scalar value rather than a node set,
    a single-element array is returned.
  
The second argument must be a well formed XML document. In particular, it must have a single root node element.
   The optional third argument of the function is an array of namespace
    mappings.  This array should be a two-dimensional
   
    text
   
   array with
    the length of the second axis being equal to 2 (i.e., it should be an
    array of arrays, each of which consists of exactly 2 elements).
    The first element of each array entry is the namespace name (alias), the
    second the namespace URI. It is not required that aliases provided in
    this array be the same as those being used in the XML document itself (in
    other words, both in the XML document and in the
   
    xpath
   
   function context, aliases are
   
    
     local
    
   
   ).
  
Example:
SELECT xpath('/my:a/text()', 'test ',
             ARRAY[ARRAY['my', 'http://example.com']]);
 xpath  
--------
 {test}
(1 row)
  
To deal with default (anonymous) namespaces, do something like this:
SELECT xpath('//mydefns:b/text()', 'test',
             ARRAY[ARRAY['mydefns', 'http://example.com']]);
 xpath
--------
 {test}
(1 row)
  
xpath_exists(xpath, xml [, nsarray])
   The function
   
    xpath_exists
   
   is a specialized form
    of the
   
    xpath
   
   function.  Instead of returning the
    individual XML values that satisfy the XPath, this function returns a
    Boolean indicating whether the query was satisfied or not.  This
    function is equivalent to the standard
   
    XMLEXISTS
   
   predicate,
    except that it also offers support for a namespace mapping argument.
  
Example:
SELECT xpath_exists('/my:a/text()', 'test ',
                     ARRAY[ARRAY['my', 'http://example.com']]);
 xpath_exists  
--------------
 t
(1 row)
  
9.14.4. Mapping Tables to XML
The following functions map the contents of relational tables to XML values. They can be thought of as XML export functionality:
table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
cursor_to_xml(cursor refcursor, count int, nulls boolean,
              tableforest boolean, targetns text)
  The return type of each function is xml .
   
    table_to_xml
   
   maps the content of the named
    table, passed as parameter
   
    tbl
   
   .  The
   
    regclass
   
   type accepts strings identifying tables using the
    usual notation, including optional schema qualifications and
    double quotes.
   
    query_to_xml
   
   executes the
    query whose text is passed as parameter
   
    query
   
   and maps the result set.
   
    cursor_to_xml
   
   fetches the indicated number of
    rows from the cursor specified by the parameter
   
    cursor
   
   .  This variant is recommended if
    large tables have to be mapped, because the result value is built
    up in memory by each function.
  
If tableforest is false, then the resulting XML document looks like this:
|
data data ...
...
If tableforest is true, the result is an XML content fragment that looks like this:
data data ... ...
If no table name is available, that is, when mapping a query or a cursor, the string table is used in the first format, row in the second format.
   The choice between these formats is up to the user.  The first
    format is a proper XML document, which will be important in many
    applications.  The second format tends to be more useful in the
   
    cursor_to_xml
   
   function if the result values are to be
    reassembled into one document later on.  The functions for
    producing XML content discussed above, in particular
   
    xmlelement
   
   , can be used to alter the results
    to taste.
  
   The data values are mapped in the same way as described for the
    function
   
    xmlelement
   
   above.
  
The parameter nulls determines whether null values should be included in the output. If true, null values in columns are represented as:
where xsi is the XML namespace prefix for XML Schema Instance. An appropriate namespace declaration will be added to the result value. If false, columns containing null values are simply omitted from the output.
The parameter targetns specifies the desired XML namespace of the result. If no particular namespace is wanted, an empty string should be passed.
The following functions return XML Schema documents describing the mappings performed by the corresponding functions above:
table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text) query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text) cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
It is essential that the same parameters are passed in order to obtain matching XML data mappings and XML Schema documents.
The following functions produce XML data mappings and the corresponding XML Schema in one document (or forest), linked together. They can be useful where self-contained and self-describing results are wanted:
table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text) query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
In addition, the following functions are available to produce analogous mappings of entire schemas or the entire current database:
schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text) schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text) schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text) database_to_xml(nulls boolean, tableforest boolean, targetns text) database_to_xmlschema(nulls boolean, tableforest boolean, targetns text) database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
Note that these potentially produce a lot of data, which needs to be built up in memory. When requesting content mappings of large schemas or databases, it might be worthwhile to consider mapping the tables separately instead, possibly even through a cursor.
The result of a schema content mapping looks like this:
table1-mapping table2-mapping ... 
where the format of a table mapping depends on the tableforest parameter as explained above.
The result of a database content mapping looks like this:
... ... ...
where the schema mapping is as above.
   As an example of using the output produced by these functions,
   
    Figure 9-1
   
   shows an XSLT stylesheet that
    converts the output of
   
    table_to_xml_and_xmlschema
   
   to an HTML
    document containing a tabular rendition of the table data.  In a
    similar manner, the results from these functions can be
    converted into other XML-based formats.