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 many of these
functions requires the installation to have been built
with configure --with-libxml.
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.
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 -------------- <!--hello-->
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('<abc/>', '<bar>foo</bar>'); xmlconcat ---------------------- <abc/><bar>foo</bar>
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('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>'); xmlconcat ----------------------------------- <?xml version="1.1"?><foo/><bar/>
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 ------------ <foo/> SELECT xmlelement(name foo, xmlattributes('xyz' as bar)); xmlelement ------------------ <foo bar="xyz"/> SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent'); xmlelement ------------------------------------- <foo bar="2007-01-26">content</foo>
Element and attribute names that are not valid XML names are escaped by replacing the offending characters by the sequence _xHHHH_, where HHHH is the character's Unicode codepoint in hexadecimal notation. For example:
SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b")); xmlelement ---------------------------------- <foo_x0024_bar a_x0026_b="xyz"/>
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 attribute name by default. In any other case, 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 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 ---------------------------------------------- <foo bar="xyz"><abc/><!--test--><xyz/></foo>
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.
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 ------------------------------ <foo>abc</foo><bar>123</bar> SELECT xmlforest(table_name, column_name) FROM information_schema.columns WHERE table_schema = 'pg_catalog'; xmlforest ------------------------------------------------------------------------------------------- <table_name>pg_authid</table_name><column_name>rolname</column_name> <table_name>pg_authid</table_name><column_name>rolsuper</column_name> ...
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
.
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 ----------------------------- <?php echo "hello world";?>
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,
this replaces the value in the version declaration, if a
standalone value is specified, this replaces the value in the
standalone declaration.
SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), version '1.0', standalone yes); xmlroot ---------------------------------------- <?xml version="1.0" standalone="yes"?> <content>abc</content>
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.
To process values of data type xml, PostgreSQL offers
the function xpath
, which evaluates XPath 1.0
expressions.
xpath
(xpath, xml[, nsarray])
The function xpath
evaluates the XPath
expression xpath against the XML value
xml. It returns an array of XML values
corresponding to the node set produced by the XPath expression.
The third argument of the function is an array of namespace mappings. This array should be a two-dimensional 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, the second the namespace URI.
Example:
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)
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 recommendable 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:
<tablename> <row> <columnname1>data</columnname1> <columnname2>data</columnname2> </row> <row> ... </row> ... </tablename>
If tableforest is true, the result is an XML content fragment that looks like this:
<tablename> <columnname1>data</columnname1> <columnname2>data</columnname2> </tablename> <tablename> ... </tablename> ...
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
<columnname xsi:nil="true"/>
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 made by the data mappings produced 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 may be worthwhile to consider mapping the tables separately instead, possibly even through a cursor.
The result of a schema content mapping looks like this:
<schemaname> table1-mapping table2-mapping ... </schemaname>
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:
<dbname> <schema1name> ... </schema1name> <schema2name> ... </schema2name> ... </dbname>
where the schema mapping is as above.
As an example for 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 result data of these functions can be
converted into other XML-based formats.
Figure 9-1. XSLT stylesheet for converting SQL/XML output to HTML
<?xml version="1.0"?> <xsl:stylesheet version="1.0" xmlns:xsl="http://www.w3.org/1999/XSL/Transform" xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns="http://www.w3.org/1999/xhtml" > <xsl:output method="xml" doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd" doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN" indent="yes"/> <xsl:template match="/*"> <xsl:variable name="schema" select="//xsd:schema"/> <xsl:variable name="tabletypename" select="$schema/xsd:element[@name=name(current())]/@type"/> <xsl:variable name="rowtypename" select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/> <html> <head> <title><xsl:value-of select="name(current())"/></title> </head> <body> <table> <tr> <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name"> <th><xsl:value-of select="."/></th> </xsl:for-each> </tr> <xsl:for-each select="row"> <tr> <xsl:for-each select="*"> <td><xsl:value-of select="."/></td> </xsl:for-each> </tr> </xsl:for-each> </table> </body> </html> </xsl:template> </xsl:stylesheet>