[PoC] XMLCast (SQL/XML X025)

Started by Jim Jonesover 1 year ago31 messages
#1Jim Jones
jim.jones@uni-muenster.de
1 attachment(s)

Hi,

This is a PoC that implements XMLCast (SQL/XML X025), which enables
conversions between SQL and XML data type.

It basically does the following:

* When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
* When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

SELECT xmlcast(now() AS xml);
             xmlcast              
----------------------------------
 2024-07-02T17:03:11.189073+02:00
(1 row)

SELECT xmlcast('2024-07-02T17:03:11.189073+02:00'::xml AS timestamp with
time zone);
            xmlcast            
-------------------------------
 2024-07-02 17:03:11.189073+02
(1 row)

SELECT xmlcast('P1Y2M3DT4H5M6S'::xml AS interval);
            xmlcast            
-------------------------------
 1 year 2 mons 3 days 04:05:06
(1 row)

SELECT xmlcast('<foo&bar>'::xml AS text);
  xmlcast  
-----------
 <foo&bar>
(1 row)

SELECT xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6
seconds'::interval AS xml) ;
    xmlcast     
----------------
 P1Y2M3DT4H5M6S
(1 row)

SELECT xmlcast('42.73'::xml AS numeric);
 xmlcast
---------
   42.73
(1 row)

SELECT xmlcast(42730102030405 AS xml);
    xmlcast     
----------------
 42730102030405
(1 row)

Is it starting in the right direction? Any feedback would be much
appreciated.

Best,
Jim

Attachments:

v1-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v1-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 945a18ba2ee20b32e5694c4285f44a70c913151b Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Wed, 19 Jun 2024 09:11:39 +0200
Subject: [PATCH v1] Add XMLCast function (SQL/XML X025)

This function implements the SQL/XML function xmlcast, which
enables conversions between SQL data types and the XML data type.

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  71 +++++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 ++++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  13 +-
 src/backend/parser/parse_expr.c       |  82 +++++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |   4 +
 src/backend/utils/adt/xml.c           |  28 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 326 ++++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 258 ++++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 326 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 152 ++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 1371 insertions(+), 8 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 6646820d6a..3bce8eb674 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4459,14 +4459,77 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index c002f37202..a4d8f7a2ac 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 852186312c..e2078380e1 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4075,10 +4076,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 89ee4b61f2..37a8c59752 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 			/* just use typename's location */
 			loc = exprLocation((Node *) ((const FunctionParameter *) expr)->argType);
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4430,6 +4433,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 4d582950b7..22b7e1e82b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -795,7 +795,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -15909,6 +15909,15 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -17959,6 +17968,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18546,6 +18556,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index aba3546ed1..f03e19e4ad 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -42,6 +42,11 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -69,6 +74,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -277,6 +283,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2456,6 +2466,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2472,6 +2486,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index ee6fcd0503..0e68ee8bdf 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1947,6 +1947,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1973,6 +1976,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 653685bffc..6eb41411cb 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -9700,6 +9700,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -9746,6 +9749,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 3e4ca874d8..125c39342a 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2659,6 +2659,34 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape characters in XML text nodes
+ */
+char *
+unescape_xml(const char *str)
+{
+#ifdef USE_LIBXML
+
+	volatile xmlParserCtxtPtr ctxt = NULL;
+	xmlChar *xmlbuf = NULL;
+	char *res;
+
+	ctxt = xmlNewParserCtxt();
+	xmlbuf = xmlStringDecodeEntities(ctxt, (xmlChar*) str, XML_SUBSTITUTE_REF, 0, 0, 0);
+
+	Assert(xmlbuf);
+
+	res = pstrdup((char *) xmlbuf);
+
+	xmlFree(xmlbuf);
+	xmlFreeParserCtxt(ctxt);
+
+	return res;
+#else
+	NO_XML_SUPPORT();
+#endif /* not USE_LIBXML */
+}
+
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e..578d83bc20 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -849,6 +849,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4830efc573..e5662e8752 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1577,6 +1577,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1613,6 +1614,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f7fe834cf4..17065f36dc 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -505,6 +505,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index ed20e21375..78727a0d19 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 6500cff885..d4b1667564 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1862,3 +1862,329 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-07 | xml
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 9323b84ae2..ff8b470236 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1466,3 +1466,261 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index e1d165c6c9..94a5b00b61 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1842,3 +1842,329 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-07 | xml
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 953bac09e4..bce758e610 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -670,3 +670,155 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 4f57078d13..a27fe8c827 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3224,6 +3224,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#2Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#1)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

On 02.07.24 18:02, Jim Jones wrote:

It basically does the following:

* When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
* When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

v2 attached adds missing return for NO_XML_SUPPORT control path in
unescape_xml

--
Jim

Attachments:

v2-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v2-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From e30ded6ea7b3a18e2c26150ebd415a2853bad094 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 5 Jul 2024 15:26:09 +0200
Subject: [PATCH v2] Add XMLCast function (SQL/XML X025)

This function implements the SQL/XML function xmlcast, which
enables conversions between SQL data types and the XML data type.

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  71 +++++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 ++++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  13 +-
 src/backend/parser/parse_expr.c       |  82 +++++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |   4 +
 src/backend/utils/adt/xml.c           |  29 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 326 ++++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 258 ++++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 326 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 152 ++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 1372 insertions(+), 8 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 6646820d6a..3bce8eb674 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4459,14 +4459,77 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index c002f37202..a4d8f7a2ac 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d8735286c4..5a60627b6f 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4075,10 +4076,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index d2e2af4f81..66af81e2c2 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1726,6 +1726,9 @@ exprLocation(const Node *expr)
 			/* just use typename's location */
 			loc = exprLocation((Node *) ((const FunctionParameter *) expr)->argType);
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4421,6 +4424,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a043fd4c66..38bc00cc37 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -795,7 +795,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -15909,6 +15909,15 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -17959,6 +17968,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18546,6 +18556,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 560b360644..4993e44110 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -42,6 +42,11 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -69,6 +74,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -276,6 +282,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2455,6 +2465,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2471,6 +2485,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index ee6fcd0503..0e68ee8bdf 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1947,6 +1947,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1973,6 +1976,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 653685bffc..6eb41411cb 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -9700,6 +9700,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -9746,6 +9749,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 3e4ca874d8..d357f458a6 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2659,6 +2659,35 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape characters in XML text nodes
+ */
+char *
+unescape_xml(const char *str)
+{
+#ifdef USE_LIBXML
+
+	volatile xmlParserCtxtPtr ctxt = NULL;
+	xmlChar *xmlbuf = NULL;
+	char *res;
+
+	ctxt = xmlNewParserCtxt();
+	xmlbuf = xmlStringDecodeEntities(ctxt, (xmlChar*) str, XML_SUBSTITUTE_REF, 0, 0, 0);
+
+	Assert(xmlbuf);
+
+	res = pstrdup((char *) xmlbuf);
+
+	xmlFree(xmlbuf);
+	xmlFreeParserCtxt(ctxt);
+
+	return res;
+#else
+	NO_XML_SUPPORT();
+	return NULL;
+#endif /* not USE_LIBXML */
+}
+
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e..578d83bc20 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -849,6 +849,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index ea47652adb..6c6f3591e6 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1577,6 +1577,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1613,6 +1614,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f7fe834cf4..17065f36dc 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -505,6 +505,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index ed20e21375..78727a0d19 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 6500cff885..d4b1667564 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1862,3 +1862,329 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-07 | xml
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 9323b84ae2..ff8b470236 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1466,3 +1466,261 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index e1d165c6c9..94a5b00b61 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1842,3 +1842,329 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-07 | xml
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 953bac09e4..bce758e610 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -670,3 +670,155 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e6c1caf649..e59838b967 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3224,6 +3224,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#3Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#2)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

On 05.07.24 16:18, Jim Jones wrote:

On 02.07.24 18:02, Jim Jones wrote:

It basically does the following:

* When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
* When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

v2 attached adds missing return for NO_XML_SUPPORT control path in
unescape_xml

v3 adds the missing XML passing mechanism BY VALUE and BY REF, as
described in the  XMLCast specification:

XMLCAST (<XML cast operand> AS <XML cast target> [ <XML passing
mechanism> ])

Tests and documentation were updated accordingly.

--
Jim

Attachments:

v3-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v3-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 0679e82e9653183190a6af6c97de1887f567ef72 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Thu, 15 Aug 2024 20:27:36 +0200
Subject: [PATCH v3] Add XMLCast function (SQL/XML X025)

This function implements the SQL/XML function xmlcast, which
enables conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 ++++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 ++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |   4 +
 src/backend/utils/adt/xml.c           |  29 ++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 429 ++++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 346 +++++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 429 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 210 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 1739 insertions(+), 8 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index e0d33f12e1..28c93460a5 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4472,14 +4472,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index c002f37202..a4d8f7a2ac 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index ea47c4d6f9..1eb2231aa1 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4101,10 +4102,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index d2e2af4f81..66af81e2c2 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1726,6 +1726,9 @@ exprLocation(const Node *expr)
 			/* just use typename's location */
 			loc = exprLocation((Node *) ((const FunctionParameter *) expr)->argType);
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4421,6 +4424,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3f25582c3..23b2928d9b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -795,7 +795,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -15891,6 +15891,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -17940,6 +17958,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18526,6 +18545,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 56e413da9f..8e76d72c07 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -42,6 +42,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -69,6 +73,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -276,6 +281,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2456,6 +2465,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2472,6 +2485,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index ee6fcd0503..0e68ee8bdf 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1947,6 +1947,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1973,6 +1976,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 4039ee0df7..3c8e3baf32 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -9724,6 +9724,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -9770,6 +9773,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 447e72b21e..280fb58ab8 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2701,6 +2701,35 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape characters in XML text nodes
+ */
+char *
+unescape_xml(const char *str)
+{
+#ifdef USE_LIBXML
+
+	volatile xmlParserCtxtPtr ctxt = NULL;
+	xmlChar *xmlbuf = NULL;
+	char *res;
+
+	ctxt = xmlNewParserCtxt();
+	xmlbuf = xmlStringDecodeEntities(ctxt, (xmlChar*) str, XML_SUBSTITUTE_REF, 0, 0, 0);
+
+	Assert(xmlbuf);
+
+	res = pstrdup((char *) xmlbuf);
+
+	xmlFree(xmlbuf);
+	xmlFreeParserCtxt(ctxt);
+
+	return res;
+#else
+	NO_XML_SUPPORT();
+	return NULL;
+#endif /* not USE_LIBXML */
+}
+
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e..578d83bc20 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -849,6 +849,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index ea47652adb..6c6f3591e6 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1577,6 +1577,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1613,6 +1614,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index bb191b1f46..b17653cc2b 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -504,6 +504,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index ed20e21375..78727a0d19 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 93a79cda8f..b8aba206d4 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1853,3 +1853,432 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-07 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 9323b84ae2..cf1544a88a 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1466,3 +1466,349 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index f956322c69..80d6517fc7 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1839,3 +1839,432 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-07 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 953bac09e4..c7e597fbeb 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -670,3 +670,213 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 547d14b3e7..58aa3dad52 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3236,6 +3236,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#4Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#3)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebase.

--
Jim

Attachments:

v4-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v4-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From a43036de62a69c00d0c5c4469af02c8ded438530 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Sun, 10 Nov 2024 16:13:18 +0100
Subject: [PATCH v4] Add XMLCast function (SQL/XML X025)

This function implements the SQL/XML function xmlcast, which
enables conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 ++++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 ++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |   4 +
 src/backend/utils/adt/xml.c           |  29 ++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 431 ++++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 348 +++++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 431 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 213 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 1748 insertions(+), 8 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index e0d33f12e1..28c93460a5 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4472,14 +4472,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index c002f37202..a4d8f7a2ac 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 30c5a19aad..69a7bbae94 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4213,10 +4214,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 3060847b13..f16a1475dc 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1725,6 +1725,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4434,6 +4437,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 67eb96396a..4d70c42f56 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -780,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -15948,6 +15948,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -17998,6 +18016,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18583,6 +18602,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index c2806297aa..8651115b42 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2454,6 +2463,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2470,6 +2483,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 76bf88c3ca..403ef683cd 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index a39068d1bf..150a047b99 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -9966,6 +9966,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10012,6 +10015,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 040a896263..cae7206037 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,35 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape characters in XML text nodes
+ */
+char *
+unescape_xml(const char *str)
+{
+#ifdef USE_LIBXML
+
+	volatile xmlParserCtxtPtr ctxt = NULL;
+	xmlChar *xmlbuf = NULL;
+	char *res;
+
+	ctxt = xmlNewParserCtxt();
+	xmlbuf = xmlStringDecodeEntities(ctxt, (xmlChar*) str, XML_SUBSTITUTE_REF, 0, 0, 0);
+
+	Assert(xmlbuf);
+
+	res = pstrdup((char *) xmlbuf);
+
+	xmlFree(xmlbuf);
+	xmlFreeParserCtxt(ctxt);
+
+	return res;
+#else
+	NO_XML_SUPPORT();
+	return NULL;
+#endif /* not USE_LIBXML */
+}
+
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e..f904b39d88 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -851,6 +851,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index b0ef1952e8..f10729f4de 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1577,6 +1577,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1613,6 +1614,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 899d64ad55..18706dd84c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -503,6 +503,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index ed20e21375..78727a0d19 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index fb5f345855..9477b7331a 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1869,3 +1869,434 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index ef7dc03c69..954453ea62 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1480,3 +1480,351 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index 4a9cdd2afe..fd94d5fa44 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1855,3 +1855,434 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index f752ecb142..d649bdb389 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -673,3 +673,216 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 1847bbfa95..98f9541324 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3244,6 +3244,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#5Robert Haas
robertmhaas@gmail.com
In reply to: Jim Jones (#4)
Re: [PoC] XMLCast (SQL/XML X025)

On Sun, Nov 10, 2024 at 1:14 PM Jim Jones <jim.jones@uni-muenster.de> wrote:

rebase.

Hmm, this patch has gotten no responses for 4 months. That's kind of
unfortunate. Sadly, there's not a whole lot that I can do to better
the situation, because I know very little either about XML-related
standards or about how people make use of XML in practice. It's not
that much code, so if it does a useful thing that we actually want, we
can probably figure out how to verify that the code is correct, or fix
it. But I don't know whether it's a useful thing that we actually
want. Syntactically, XMLCAST() looks a lot like CAST(), so one might
ask whether the things that it does can already be accomplished using
CAST(); or whether, perhaps, we have some other existing method for
performing such conversions.

The only thing I found during a quick perusal of the documentation was
XMLTABLE(), which seems a bit baroque if you just want to convert one
value. Is this intended to plug that gap? Is there any other current
way of doing it?

Do we need to ensure some kind of consistency between XMLTABLE() and
XMLCAST() in terms of how they behave? The documentation at
https://www.postgresql.org/docs/current/xml-limits-conformance.html#FUNCTIONS-XML-LIMITS-CASTS
says that "When PostgreSQL maps SQL data values to XML (as in
xmlelement), or XML to SQL (as in the output columns of xmltable),
except for a few cases treated specially, PostgreSQL simply assumes
that the XML data type's XPath 1.0 string form will be valid as the
text-input form of the SQL datatype, and conversely." Unfortunately,
it does not specify what those cases treated specially are, and the
commit that added that documentation text is not the one that added
the underlying code, so I don't actually know where that code is, but
one would expect this function to conform to that general rule.

I emphasize again that if there are people other than the submitter
who are interested in this patch, they should really chime in. This
can't progress in a vacuum.

--
Robert Haas
EDB: http://www.enterprisedb.com

#6Jim Jones
jim.jones@uni-muenster.de
In reply to: Robert Haas (#5)
Re: [PoC] XMLCast (SQL/XML X025)

Hi Robert
Thanks for taking a look at it.

On 11.11.24 19:15, Robert Haas wrote:

Hmm, this patch has gotten no responses for 4 months. That's kind of
unfortunate. Sadly, there's not a whole lot that I can do to better
the situation, because I know very little either about XML-related
standards or about how people make use of XML in practice. It's not
that much code, so if it does a useful thing that we actually want, we
can probably figure out how to verify that the code is correct, or fix
it. But I don't know whether it's a useful thing that we actually
want. Syntactically, XMLCAST() looks a lot like CAST(), so one might
ask whether the things that it does can already be accomplished using
CAST(); or whether, perhaps, we have some other existing method for
performing such conversions.

It indeed has a huge overlap with CAST(), except for a few handy SQL <->
XML mappings, such as

SELECT xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text);

    xmlcast    
---------------
 foo & <"bar">
(1 row)

--

SELECT
  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone
AS xml),
  xmlcast('2024-05-29T12:04:10.703585'::xml AS timestamp without time zone);
 
          xmlcast           |          xmlcast           
----------------------------+----------------------------
 2024-05-29T12:04:10.703585 | 2024-05-29 12:04:10.703585
(1 row)

--

SELECT
  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval),
  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::interval
AS xml);
 
            xmlcast            |    xmlcast     
-------------------------------+----------------
 1 year 2 mons 3 days 04:05:06 | P1Y2M3DT4H5M6S
(1 row)

--

SELECT CAST('42'::xml AS int);

ERROR:  cannot cast type xml to integer
LINE 1: SELECT CAST('42'::xml AS int);
               ^
--

SELECT XMLCAST('42'::xml AS int);
 xmlcast
---------
      42
(1 row)

The only thing I found during a quick perusal of the documentation was
XMLTABLE(), which seems a bit baroque if you just want to convert one
value. Is this intended to plug that gap? Is there any other current
way of doing it?

Do we need to ensure some kind of consistency between XMLTABLE() and
XMLCAST() in terms of how they behave?

I haven't considered any compatibility to XMLTABLE(), as it has a
different spec (X300-X305), but I can take a look at it! To implement
this function I just followed the SQL/XML spec "ISO/IEC IWD 9075-14" -
and from time to time I also took a look on how other databases
implemented it.[1]

The documentation at
https://www.postgresql.org/docs/current/xml-limits-conformance.html#FUNCTIONS-XML-LIMITS-CASTS
says that "When PostgreSQL maps SQL data values to XML (as in
xmlelement), or XML to SQL (as in the output columns of xmltable),
except for a few cases treated specially, PostgreSQL simply assumes
that the XML data type's XPath 1.0 string form will be valid as the
text-input form of the SQL datatype, and conversely." Unfortunately,
it does not specify what those cases treated specially are, and the
commit that added that documentation text is not the one that added
the underlying code, so I don't actually know where that code is, but
one would expect this function to conform to that general rule.

I agree. It would be nice to know which cases those are.
However, invalid inputs should normally return an error, e.g.

SELECT xmlcast('foo&bar'::xml AS text);

ERROR:  invalid XML content
LINE 1: SELECT xmlcast('foo&bar'::xml AS text);
                       ^
DETAIL:  line 1: EntityRef: expecting ';'
foo&bar
       ^
--

SELECT xmlcast('foo'::xml AS date);
ERROR:  invalid input syntax for type date: "foo"

--

.. but perhaps the text means something else?

Thanks!

Best, Jim

1 - https://dbfiddle.uk/ZSpsyIal

#7Robert Haas
robertmhaas@gmail.com
In reply to: Jim Jones (#6)
Re: [PoC] XMLCast (SQL/XML X025)

Hi Jim,

On Mon, Nov 11, 2024 at 2:43 PM Jim Jones <jim.jones@uni-muenster.de> wrote:

The only thing I found during a quick perusal of the documentation was
XMLTABLE(), which seems a bit baroque if you just want to convert one
value. Is this intended to plug that gap? Is there any other current
way of doing it?

Do we need to ensure some kind of consistency between XMLTABLE() and
XMLCAST() in terms of how they behave?

I haven't considered any compatibility to XMLTABLE(), as it has a
different spec (X300-X305), but I can take a look at it! To implement
this function I just followed the SQL/XML spec "ISO/IEC IWD 9075-14" -
and from time to time I also took a look on how other databases
implemented it.[1]

Those are good things to check, but we also need to consider how it
interacts with features PostgreSQL itself already has. In particular,
I'm concerned about the special handling you seem to have for times
and intervals. That handling might be different from what, say,
XMLTABLE() does. In a perfect world, we'd probably like the features
to share code, unless there is some good reason to do otherwise. But
at the very least we want them to work in compatible ways. For
example, if the way you convert a date into the JSON-preferred format
happened to use slightly different time zone handling than the way
that some other existing feature does it, that would be extremely sad.
Or if the existing features don't have interval handling and you do,
perhaps we ought to add that capability to the existing features and
then have your new feature call the same code so that it works the
same way. I haven't researched what the exact situation is here too
and these examples I'm giving you here are strictly hypothetical --
they're just the kind of thing that needs to be sorted out before we
can think about committing anything.

There's still also the question of desirability. I take it for granted
that you want this feature and consider it valuable, but sometimes
people submit patches for a feature that only the submitter wants and
nobody else cares about it (or even, other people actively dislike
it). I am in a very poor position to assess how important this feature
is or to what extent it complies with the relevant specification. Vik,
who I see you copied, is probably in a much better position to
interpret the spec than I am, and may or may not also know something
about whether people want this. I continue to hope that we'll get some
comments from others as well.

--
Robert Haas
EDB: http://www.enterprisedb.com

#8Jim Jones
jim.jones@uni-muenster.de
In reply to: Robert Haas (#7)
Re: [PoC] XMLCast (SQL/XML X025)

On 12.11.24 15:59, Robert Haas wrote:

Those are good things to check, but we also need to consider how it
interacts with features PostgreSQL itself already has.

I totally agree. It just didn't occur to me to check how XMLTABLE()
deals with these conversions :)

In particular,
I'm concerned about the special handling you seem to have for times
and intervals.

The spec dictates that SQL types should be converted to their xsd
equivalents, e.g.

6.7 <XML cast specification>: Syntax Rules
...
15 e)
 * i)   If the type designator of SQLT is DATE, then let XT be xs:date.
 * ii)  If the type designator of SQLT is TIME WITH TIME ZONE, then let
XT be xs:time.
 * iii) If the type designator of SQLT is TIME WITHOUT TIME ZONE, then
let XT be xs:time.
 * iv)  If the type designator of SQLT is TIMESTAMP WITH TIME ZONE, then
let XT be xs:dateTime.
 * v)   If the type designator of SQLT is TIMESTAMP WITHOUT TIME ZONE,
then let XT be xs:dateTime.

That handling might be different from what, say,
XMLTABLE() does.

XMLTABLE() does seem to have a similar behaviour (also regarding
intervals and timestamps):

WITH j (val) AS (
 SELECT
  '<foo>
    <interval>P1Y2M3DT4H5M6S</interval>
    <timestamp>2002-05-30T09:30:10</timestamp>
    <integer>42</integer>
    <numeric>-42.73</numeric>
    <text>foo &amp; &lt;&quot;bar&quot;&gt;</text>
    <boolean>false</boolean>
  </foo>'::xml
)
SELECT a, b, c, d, e, f
FROM j,
  XMLTABLE(
    '/foo'
    PASSING val
    COLUMNS
      a interval PATH 'interval',
      b timestamp PATH 'timestamp',
      c integer PATH 'integer',
      d numeric PATH 'numeric',
      e text PATH 'text',
      f boolean PATH 'boolean');
               a               |          b          | c  |   d   
|       e       | f
-------------------------------+---------------------+----+--------+---------------+---
 1 year 2 mons 3 days 04:05:06 | 2002-05-30 09:30:10 | 42 | -42.73 | foo
& <"bar"> | f
(1 row)

In a perfect world, we'd probably like the features
to share code, unless there is some good reason to do otherwise. But
at the very least we want them to work in compatible ways. For
example, if the way you convert a date into the JSON-preferred format
happened to use slightly different time zone handling than the way
that some other existing feature does it, that would be extremely sad.
Or if the existing features don't have interval handling and you do,
perhaps we ought to add that capability to the existing features and
then have your new feature call the same code so that it works the
same way.

At least XMLTABLE() does handle intervals in the same way. I'll do some
research to check if maybe other related XML features follow a different
path.

I haven't researched what the exact situation is here too
and these examples I'm giving you here are strictly hypothetical --
they're just the kind of thing that needs to be sorted out before we
can think about committing anything.

+1

There's still also the question of desirability. I take it for granted
that you want this feature and consider it valuable, but sometimes
people submit patches for a feature that only the submitter wants and
nobody else cares about it (or even, other people actively dislike
it).

I've been there a few times :)

I am in a very poor position to assess how important this feature
is or to what extent it complies with the relevant specification. Vik,
who I see you copied, is probably in a much better position to
interpret the spec than I am, and may or may not also know something
about whether people want this. I continue to hope that we'll get some
comments from others as well.

Thanks for taking a look at this patch. Much appreciated!

--
Jim

#9Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#8)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebase.

v5 also attached removes the libxml2 dependency of unescape_xml().

Background: the existing function escape_xml() intentionally avoids
libxml2 dependency and the previously used libxml2 functions
xmlStringDecodeEntities() and xmlDecodeEntities() got deprecated.

--
Jim

Attachments:

v5-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v5-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From f38c714220be8f2f4f939bedc46d8630ec5cd6dc Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Mon, 30 Dec 2024 09:57:05 +0100
Subject: [PATCH v5] Add XMLCast function (SQL/XML X025)

This implements the SQL/XML function xmlcast, which enables
conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 ++++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 ++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |   4 +
 src/backend/utils/adt/xml.c           |  61 ++++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 443 ++++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 354 ++++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 443 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 215 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 1812 insertions(+), 8 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 3e6751d64c..7673bec402 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4472,14 +4472,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index c002f37202..a4d8f7a2ac 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d2987663e6..d1d84f21b8 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4429,10 +4430,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 50705a1e15..9f35d2cb94 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1725,6 +1725,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4434,6 +4437,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index bd5ebb35c4..b0ce33a532 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -780,7 +780,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -15948,6 +15948,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -17998,6 +18016,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18583,6 +18602,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index c2806297aa..8651115b42 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2454,6 +2463,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2470,6 +2483,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 76bf88c3ca..403ef683cd 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index be1f1f50b7..6ae3b21a2a 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -9974,6 +9974,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10020,6 +10023,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 0898cb1be4..70ec2cc641 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0f9462493e..f904b39d88 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -851,6 +851,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index b0ef1952e8..f10729f4de 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1577,6 +1577,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1613,6 +1614,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 899d64ad55..18706dd84c 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -503,6 +503,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index ed20e21375..78727a0d19 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index fb5f345855..3dc11e9e69 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1869,3 +1869,446 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index ef7dc03c69..10deb57235 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1480,3 +1480,357 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index 4a9cdd2afe..0bc318521c 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1855,3 +1855,446 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index f752ecb142..92560e9989 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -673,3 +673,218 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e1c4f913f8..8ab457123b 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3255,6 +3255,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#10Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#9)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

On 30.12.24 10:29, Jim Jones wrote:

rebase.

v5 attached removes the libxml2 dependency of unescape_xml().

Background: the existing function escape_xml() intentionally avoids
libxml2 dependency and the previously used libxml2 functions
xmlStringDecodeEntities() and xmlDecodeEntities() got deprecated.

v6 attached adds missing regression tests for XMLCast backward parsing.

Jim

Attachments:

v6-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v6-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From c81299327e30db88b8e990ceec817129c040f907 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 21 Feb 2025 01:19:16 +0100
Subject: [PATCH v6] Add XMLCast function (SQL/XML X025)

This implements the SQL/XML function XMLCast, which enables
conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 +++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 ++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2201 insertions(+), 9 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 87679dc4a1..7e8bfaf1a1 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4487,14 +4487,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 2f250d2c57..0b68e9b17f 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 1c3477b03c..8432846ec8 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4562,10 +4563,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 7bc823507f..88c0a53e53 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1736,6 +1736,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4468,6 +4471,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7d99c9355c..9591a97a56 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -788,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16023,6 +16023,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18075,6 +18093,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18662,6 +18681,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index bad1df732e..50800ebe3b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2454,6 +2463,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2470,6 +2483,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 4aba0d9d4d..6edc0a19c5 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 54dad97555..0a771d359e 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10029,6 +10029,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10039,7 +10042,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10075,6 +10078,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10145,6 +10149,10 @@ get_rule_expr(Node *node, deparse_context *context,
 					appendStringInfo(buf, " AS %s",
 									 format_type_with_typemod(xexpr->type,
 															  xexpr->typmod));
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index db8d0d6a7e..24fca428f6 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0b208f51bd..5cd5d42de7 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -860,6 +860,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 839e71d52f..00a28a0de4 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1582,6 +1582,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1618,6 +1619,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 40cf090ce6..40f412dab3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -505,6 +505,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 2e9616acda..f26d4897db 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1873,3 +1873,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST('11:11:11.5-08'::time with time zone::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |               c13                |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T03:04:10.703585-07:00 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 11:11:11.5-08
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AS c5,
+    XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AS c6,
+    XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AS c7,
+    XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AS c8,
+    XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c9,
+    XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |              c8              |              c9              |             c10              |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+------------------------------+------------------------------+------------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 09:30:10+00 | 09:30:10-06 | 09:30:10+06 | Thu May 30 02:30:10 2002 PDT | Thu May 30 08:30:10 2002 PDT | Wed May 29 20:30:10 2002 PDT | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 7505a14077..a18306c5fb 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1482,3 +1482,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index c07ed2b269..a02f518226 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1859,3 +1859,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST('11:11:11.5-08'::time with time zone::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |               c13                |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T03:04:10.703585-07:00 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 11:11:11.5-08
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AS c5,
+    XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AS c6,
+    XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AS c7,
+    XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AS c8,
+    XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c9,
+    XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |              c8              |              c9              |             c10              |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+------------------------------+------------------------------+------------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 09:30:10+00 | 09:30:10-06 | 09:30:10+06 | Thu May 30 02:30:10 2002 PDT | Thu May 30 08:30:10 2002 PDT | Wed May 29 20:30:10 2002 PDT | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index bac0388ac1..eed9299086 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -675,3 +675,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 98ab45adfa..3731f43ac5 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3274,6 +3274,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#11Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#10)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebase due to changes in 984410b923263cac901fa81e0efbe523e9c36df3

Jim

Attachments:

v7-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v7-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From ece6a7421fc8a250d8da14c89817774802508b10 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 21 Feb 2025 11:27:09 +0100
Subject: [PATCH v7] Add XMLCast function (SQL/XML X025)

This implements the SQL/XML function XMLCast, which enables
conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 +++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 ++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2201 insertions(+), 9 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 87679dc4a1..7e8bfaf1a1 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4487,14 +4487,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 2f250d2c57..0b68e9b17f 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 1c3477b03c..8432846ec8 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4562,10 +4563,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 7bc823507f..88c0a53e53 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1736,6 +1736,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4468,6 +4471,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7d99c9355c..9591a97a56 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -788,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16023,6 +16023,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18075,6 +18093,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18662,6 +18681,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index bad1df732e..50800ebe3b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2454,6 +2463,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2470,6 +2483,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 4aba0d9d4d..6edc0a19c5 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d11a8a20ee..ced41b24de 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10029,6 +10029,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10039,7 +10042,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10075,6 +10078,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10152,6 +10156,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index db8d0d6a7e..24fca428f6 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0b208f51bd..5cd5d42de7 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -860,6 +860,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 839e71d52f..00a28a0de4 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1582,6 +1582,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1618,6 +1619,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 40cf090ce6..40f412dab3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -505,6 +505,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index bcc743f485..37c4328700 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1877,3 +1877,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST('11:11:11.5-08'::time with time zone::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |               c13                |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T03:04:10.703585-07:00 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 11:11:11.5-08
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AS c5,
+    XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AS c6,
+    XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AS c7,
+    XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AS c8,
+    XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c9,
+    XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |              c8              |              c9              |             c10              |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+------------------------------+------------------------------+------------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 09:30:10+00 | 09:30:10-06 | 09:30:10+06 | Thu May 30 02:30:10 2002 PDT | Thu May 30 08:30:10 2002 PDT | Wed May 29 20:30:10 2002 PDT | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index a1c5d31417..8794cddbe1 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1492,3 +1492,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index 045641dae6..a9849fc7c0 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1863,3 +1863,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+                j                 | pg_typeof 
+----------------------------------+-----------
+ 2024-05-29T03:04:10.703585-07:00 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 11:11:11.5-08 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST('11:11:11.5-08'::time with time zone::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |               c13                |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T03:04:10.703585-07:00 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 11:11:11.5-08
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AS c5,
+    XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AS c6,
+    XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AS c7,
+    XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AS c8,
+    XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c9,
+    XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |              c8              |              c9              |             c10              |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+------------------------------+------------------------------+------------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 09:30:10+00 | 09:30:10-06 | 09:30:10+06 | Thu May 30 02:30:10 2002 PDT | Thu May 30 08:30:10 2002 PDT | Wed May 29 20:30:10 2002 PDT | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 4c3520ce89..b3a1b19a93 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -677,3 +677,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index b09d8af718..f5336a5d10 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3284,6 +3284,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#12Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#11)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebase

Jim

Attachments:

v8-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v8-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From d8627405b82f56117afa44b96e970a44684d45ca Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Mon, 10 Mar 2025 10:17:48 +0100
Subject: [PATCH v8] Add XMLCast function (SQL/XML X025)

This implements the SQL/XML function XMLCast, which enables
conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 +++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 ++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2201 insertions(+), 9 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 09309ba039..f1b2f91924 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4496,14 +4496,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 2f250d2c57..0b68e9b17f 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 1c3477b03c..8432846ec8 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4562,10 +4563,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 7bc823507f..88c0a53e53 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1736,6 +1736,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4468,6 +4471,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 271ae26cba..1fe495cee5 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -788,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16051,6 +16051,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18103,6 +18121,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18690,6 +18709,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index bad1df732e..50800ebe3b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2454,6 +2463,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2470,6 +2483,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 4aba0d9d4d..6edc0a19c5 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index d11a8a20ee..ced41b24de 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10029,6 +10029,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10039,7 +10042,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10075,6 +10078,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10152,6 +10156,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index db8d0d6a7e..24fca428f6 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 23c9e3c5ab..114987d20a 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -860,6 +860,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index d0576da3e2..ef80b3511e 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1582,6 +1582,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1618,6 +1619,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 40cf090ce6..40f412dab3 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -505,6 +505,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index bcc743f485..aaf851adb2 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1877,3 +1877,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 19:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 19:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index a1c5d31417..fc110ae26c 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1492,3 +1492,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index 045641dae6..808d73fde4 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1863,3 +1863,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 19:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 19:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 4c3520ce89..9ec5f6c070 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -677,3 +677,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9840060997..5342414894 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3293,6 +3293,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#13Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#12)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebase

--
Jim

Attachments:

v9-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v9-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 407ef65a398aa2d968d7b3d7d86548e3edcddd99 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Mon, 19 May 2025 14:57:27 +0200
Subject: [PATCH v9] Add XMLCast function (SQL/XML X025)

This implements the SQL/XML function XMLCast, which enables
conversions between SQL data types and the XML data type.

XMLCAST ( expression AS type [ BY REF | BY VALUE ] )

When casting an XML value to a SQL data type, XML values containing
XSD literals will be converted to their equivalent SQL data type.
When casting from a SQL data type to XML, the cast operand will be
translated to its corresponding XSD data type.

This patch also includes documentation and regression tests.
---
 doc/src/sgml/datatype.sgml            |  78 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c |  83 +++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 ++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2201 insertions(+), 9 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 09309ba039..f1b2f91924 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4496,14 +4496,84 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option to convert character strings into xml is the function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. This can be useful for creating XML
+    documents using SQL or when parsing the contents of XML documents. The function <function>xmlcast</function> works with the
+    following criteria:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <literal>xml</literal>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <literal>xml</literal> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>s containing XML predifined entities
+          will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          The <replaceable>expression</replaceable>s of type <literal>date</literal>, <literal>time [with time zone]</literal>, <literal>timestamp [with time zone]</literal>,
+          and <literal>interval</literal> will be converted to their XSD equivalents, <literal>xs:date</literal>, <literal>xs:time</literal>,
+          <literal>xs:dateTime</literal>, and <literal>xs:duration</literal>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index ebe85337c2..5f34d95d64 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 8a72b5e70a..a1c2e529f1 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,10 +4644,88 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/* These data types must be converted to their ISO 8601 representations */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/* INTERVAL data nust be converted to ISO 8601, e.g. '1 year 2 mons' -> 'P1Y2M' */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				default:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				}
+
+				*op->resnull = false;
+			}
 			break;
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
 	}
 }
 
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 7bc823507f..88c0a53e53 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1736,6 +1736,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4468,6 +4471,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..5767a69219 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -788,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16053,6 +16053,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18106,6 +18124,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18694,6 +18713,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1f8e2d5467..6041248b6c 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2462,6 +2471,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2478,6 +2491,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 4aba0d9d4d..6edc0a19c5 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 467b08198b..cd5581b6ef 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10081,6 +10081,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10091,7 +10094,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10127,6 +10130,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10204,6 +10208,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index db8d0d6a7e..24fca428f6 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..d3d82a6e7f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -860,6 +860,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 7d3b4198f2..8cc25f7f56 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1582,6 +1582,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1618,6 +1619,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a..65750625b1 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -506,6 +506,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..9ba5400d2b 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+02 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+02
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 11:30:10+02 | 17:30:10+02 | 05:30:10+02 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..40d642d59d 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..520329fbcb 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+02 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+02
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 11:30:10+02 | 17:30:10+02 | 05:30:10+02 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..1fae5b4b00 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9ea573fae2..ab1dc2a9bd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3355,6 +3355,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#14Robert Haas
robertmhaas@gmail.com
In reply to: Jim Jones (#13)
Re: [PoC] XMLCast (SQL/XML X025)

On Mon, May 19, 2025 at 9:23 AM Jim Jones <jim.jones@uni-muenster.de> wrote:

rebase

Hi,

Well, this patch is now more than 10 months old, and it's still the
case that nobody other than the author has said that they want this.
Is it time to give up?

I still don't think it's very clear either from the patch or from the
thread how this differs from existing facilities. As far as I can see,
there are zero comments in the patch explaining the design decisions
that it makes, and nothing in the commit message, the comments, or
even the thread itself addressing my concern from my previous review:
how is this consistent, or inconsistent, with what we do in other
similar cases, and why?

To make that more concrete, the patch says:

+    Another option to convert character strings into xml is the
function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>,
and vice versa.

But while it explains the behavior of this option, it does not explain
how the behavior is the same or different from other options, or why.

In the comments it says:

+ /* These data types must be converted to their ISO 8601 representations */

To me this just begs the question "says who?". I think there should be
a bunch of comments in this referencing whatever document specifies
the behavior of XMLCAST, so that someone who is good at reading
specification documents (not me) can compare the implementation with
the spec and see if they agree with the decisions that were made.

+ default:
+ *op->resvalue = PointerGetDatum(DatumGetTextP(value));
+ break;

This doesn't seem very safe at all. If we know what type OIDs we
intend this to handle, then we could list them out explicitly as is
already done for TEXTOID, VARCHAROID, etc. If we don't, then why
should we believe that it's a data type for which DatumGetTextP will
produce a non-garbage return value? Maybe there's an answer to that
question, but there's no comment spelling it out; or maybe it's
actually just broken.

--
Robert Haas
EDB: http://www.enterprisedb.com

#15Jim Jones
jim.jones@uni-muenster.de
In reply to: Robert Haas (#14)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

Hi Robert

On 19.05.25 16:26, Robert Haas wrote:

Well, this patch is now more than 10 months old, and it's still the
case that nobody other than the author has said that they want this.
Is it time to give up?

Not quite yet -- unless there is an expiration date that I am not aware
of :). If we decide we don't need XMLCast on Postgres after all, I'd
suggest to delete it from the todo list on the wiki [1] - I've already
added a link to this thread there.

I still don't think it's very clear either from the patch or from the
thread how this differs from existing facilities. As far as I can see,
there are zero comments in the patch explaining the design decisions
that it makes, and nothing in the commit message, the comments, or
even the thread itself addressing my concern from my previous review:
how is this consistent, or inconsistent, with what we do in other
similar cases, and why?

I guess I misunderstood your message last year. I was under the
impression that you were only concerned about the handling of intervals,
which I replied here [2]. Basically I said that XMLTable is doing pretty
much the same ...

WITH j (val) AS (
 SELECT
  '<foo>
    <interval>P1Y2M3DT4H5M6S</interval>
    <timestamp>2002-05-30T09:30:10</timestamp>
    <integer>42</integer>
    <numeric>-42.73</numeric>
    <text>foo &amp; &lt;&quot;bar&quot;&gt;</text>
    <boolean>false</boolean>
  </foo>'::xml
)
SELECT a, b, c, d, e, f
FROM j,
  XMLTABLE(
    '/foo'
    PASSING val
    COLUMNS
      a interval PATH 'interval',
      b timestamp PATH 'timestamp',
      c integer PATH 'integer',
      d numeric PATH 'numeric',
      e text PATH 'text',
      f boolean PATH 'boolean');
               a               |          b          | c  |   d   
|       e       | f
-------------------------------+---------------------+----+--------+---------------+---
 1 year 2 mons 3 days 04:05:06 | 2002-05-30 09:30:10 | 42 | -42.73 | foo
& <"bar"> | f
(1 row)

... and cited the spec:

6.7 <XML cast specification>: Syntax Rules
...
15 e)
 * i)   If the type designator of SQLT is DATE, then let XT be xs:date.
 * ii)  If the type designator of SQLT is TIME WITH TIME ZONE, then let
XT be xs:time.
 * iii) If the type designator of SQLT is TIME WITHOUT TIME ZONE, then
let XT be xs:time.
 * iv)  If the type designator of SQLT is TIMESTAMP WITH TIME ZONE, then
let XT be xs:dateTime.
 * v)   If the type designator of SQLT is TIMESTAMP WITHOUT TIME ZONE,
then let XT be xs:dateTime.

and since you didn't reply, I assumed I had already addressed your
comments. But now I see it was not the case.

To make that more concrete, the patch says:

+    Another option to convert character strings into xml is the
function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>,
and vice versa.

But while it explains the behavior of this option, it does not explain
how the behavior is the same or different from other options, or why.

I'm not entirely sure what you mean by "other options". Similar
alternatives are

* CAST: simply treats the input as a textual XML value and does not
perform type-aware formatting.
* XMLTABLE: extracts typed values from an XML document using
XQuery/XPath expressions, but does not itself convert SQL types into XML.

SELECT xmlcast('2 years 1 day'::interval AS xml);
 xmlcast
---------
 P2Y1D
(1 row)

SELECT cast('2 years 1 day'::interval AS xml);
ERROR:  cannot cast type interval to xml

SELECT xmlcast(now() AS xml);
             xmlcast             
---------------------------------
 2025-05-19T20:16:47.58815+02:00
(1 row)

SELECT cast(now() AS xml);
ERROR:  cannot cast type timestamp with time zone to xml

Is it what you meant?

In the comments it says:

+ /* These data types must be converted to their ISO 8601 representations */

To me this just begs the question "says who?".

Says the SQL/XML:2023 standard :)

SQL/XML:2023 (ISO/IEC 9075-14:2023) - “General Rules” of §6.7.3 (d.ii.1
and d.ii.2):

If SD is a year-month interval type, then let XSBT be the XQuery simple
type xs:yearMonthDuration.
If SD is a day-time interval type, then let XSBT be the XQuery simple
type xs:dayTimeDuration.

... and since xs:yearMonthDuration and xs:dayTimeDuration are subsets of
xs:duration, and the lexical representation of this type is ISO 8601, I
inferred that it is the expected behaviour.

I think there should be
a bunch of comments in this referencing whatever document specifies
the behavior of XMLCAST, so that someone who is good at reading
specification documents (not me) can compare the implementation with
the spec and see if they agree with the decisions that were made.

I re-wrote the commit message and some the code comments to try to make
things clearer.

+ default:
+ *op->resvalue = PointerGetDatum(DatumGetTextP(value));
+ break;

This doesn't seem very safe at all. If we know what type OIDs we
intend this to handle, then we could list them out explicitly as is
already done for TEXTOID, VARCHAROID, etc. If we don't, then why
should we believe that it's a data type for which DatumGetTextP will
produce a non-garbage return value? Maybe there's an answer to that
question, but there's no comment spelling it out; or maybe it's
actually just broken.

Given that XMLCast converts values between SQL and XML and vice versa,
my rationale was that if the target type is not a text type (such as
TEXTOID, VARCHAROID, or NAMEOID), then the cast operand must be of type
xml, which makes this default: safe.

SELECT xmlcast('2 years 1 day'::interval AS interval);
ERROR:  cannot cast from 'interval' to 'interval'

SELECT xmlcast(now() AS timestamp);
ERROR:  cannot cast from 'timestamp with time zone' to 'timestamp
without time zone'
               
see "static Node *transformXmlCast(ParseState *pstate, XmlCast *xc)" in
parse_target.c

But I can see it looks unsafe. Do you have something like this in mind?

case INT2OID:
case INT4OID:
case INT8OID:
case NUMERICOID:
case FLOAT4OID:
case FLOAT8OID:
case BOOLOID:
case TIMESTAMPOID:
case TIMESTAMPTZOID:
case TIMEOID:
case TIMETZOID:
case DATEOID:
case BYTEAOID:
case INTERVALOID:
    *op->resvalue = PointerGetDatum(DatumGetTextP(value));
    break;
default:
    elog(ERROR, "unsupported target data type for XMLCast");
}

Thanks for the review. Much appreciated.

v10 attached.

Best, Jim

1 - https://wiki.postgresql.org/wiki/Todo
2 - /messages/by-id/998465cb-2fda-4497-8194-87da56748186@uni-muenster.de

Attachments:

v10-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v10-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 9c72a8e9d10d82564dc419db3f33d711878bbbb4 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Tue, 20 May 2025 00:34:51 +0200
Subject: [PATCH v10] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCAST provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as `xs:dateTime` and `xs:duration` (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCAST also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
  - SQL -> XML: boolean, numeric, character, date/time, interval
  - XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

Documentation and regression tests are included.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 123 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       |  81 ++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2249 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 09309ba039..7f91ad3aee 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4496,14 +4496,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index ebe85337c2..5f34d95d64 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 8a72b5e70a..9cc0e07cca 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,127 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * SQL date/time types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats (e.g., "2023-05-19", "14:30:00Z",
+					 * "2023-05-19T14:30:00+01:00") follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes §3.2.7 (dateTime) and §3.2.9 (date).
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitve Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 7bc823507f..88c0a53e53 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1736,6 +1736,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4468,6 +4471,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..5767a69219 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -788,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16053,6 +16053,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18106,6 +18124,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18694,6 +18713,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1f8e2d5467..6041248b6c 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,10 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC || (x) == TYPCATEGORY_STRING \
+			|| (x) == TYPCATEGORY_DATETIME || (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +71,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +279,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2462,6 +2471,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2478,6 +2491,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	/*
+	 * we make sure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * it is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as TEXT and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 4aba0d9d4d..6edc0a19c5 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 467b08198b..cd5581b6ef 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10081,6 +10081,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10091,7 +10094,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10127,6 +10130,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10204,6 +10208,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index db8d0d6a7e..24fca428f6 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2722,6 +2722,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..d3d82a6e7f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -860,6 +860,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 7d3b4198f2..8cc25f7f56 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1582,6 +1582,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1618,6 +1619,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a..65750625b1 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -506,6 +506,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..9ba5400d2b 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+02 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+02
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 11:30:10+02 | 17:30:10+02 | 05:30:10+02 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..40d642d59d 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..520329fbcb 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+02 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+02
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 11:30:10+02 | 17:30:10+02 | 05:30:10+02 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..1fae5b4b00 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9ea573fae2..ab1dc2a9bd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3355,6 +3355,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#16Robert Haas
robertmhaas@gmail.com
In reply to: Jim Jones (#15)
Re: [PoC] XMLCast (SQL/XML X025)

On Mon, May 19, 2025 at 7:11 PM Jim Jones <jim.jones@uni-muenster.de> wrote:

Not quite yet -- unless there is an expiration date that I am not aware
of :). If we decide we don't need XMLCast on Postgres after all, I'd
suggest to delete it from the todo list on the wiki [1] - I've already
added a link to this thread there.

Yeah. Just to be clear, I can't really think of committing a patch in
this area because I don't know the topic well enough. I can make some
general comments on what I see as issues with this patch but serious
review would really need to come from a committer who is more familiar
with the XML specifications than I am. If nobody like that shows up,
this proposal won't be able to advance.

and since you didn't reply, I assumed I had already addressed your
comments. But now I see it was not the case.

Hmm, sorry if I wasn't clear enough. I think there needs to be more
explanation of quite a few things in the patch itself.

To make that more concrete, the patch says:

+    Another option to convert character strings into xml is the
function <function>xmlcast</function>,
+    which is designed to cast SQL data types into <type>xml</type>,
and vice versa.

But while it explains the behavior of this option, it does not explain
how the behavior is the same or different from other options, or why.

I'm not entirely sure what you mean by "other options".

Well, the sentence begins with "Another option". Let's say we were
talking about making cookies. I could say "Another option, if you
don't have butter, is to substitute Crisco." But if I do that, I
should then go on to explain further: "However, if you do this, it may
affect the flavor of the cookies and they may brown differently in the
oven. Nevertheless, it's better than not having cookies." Your patch
seemed to me to be lacking any further explanation of this kind. When
we document that there are multiple options, we should try to give
some context to help the user choose between them. In my cookie-based
example, the additional text makes it clear why I would select the
Crisco option: I might be out of butter, and something is better than
nothing. In your case, it was not clear to me why someone should
choose XMLCAST over options or the other way around.

To be clear, I don't want you to explain it *to me*. I want you to
explain it to the reader of the documentation.

In the comments it says:

+ /* These data types must be converted to their ISO 8601 representations */

To me this just begs the question "says who?".

Says the SQL/XML:2023 standard :)

SQL/XML:2023 (ISO/IEC 9075-14:2023) - “General Rules” of §6.7.3 (d.ii.1
and d.ii.2):

Cool. You should put that in the patch.

+ default:
+ *op->resvalue = PointerGetDatum(DatumGetTextP(value));
+ break;

This doesn't seem very safe at all. If we know what type OIDs we
intend this to handle, then we could list them out explicitly as is
already done for TEXTOID, VARCHAROID, etc. If we don't, then why
should we believe that it's a data type for which DatumGetTextP will
produce a non-garbage return value? Maybe there's an answer to that
question, but there's no comment spelling it out; or maybe it's
actually just broken.

Given that XMLCast converts values between SQL and XML and vice versa,
my rationale was that if the target type is not a text type (such as
TEXTOID, VARCHAROID, or NAMEOID), then the cast operand must be of type
xml, which makes this default: safe.
[...]
But I can see it looks unsafe. Do you have something like this in mind?
[...]
default:
elog(ERROR, "unsupported target data type for XMLCast");
}

Yes, exactly.

--
Robert Haas
EDB: http://www.enterprisedb.com

#17Jim Jones
jim.jones@uni-muenster.de
In reply to: Robert Haas (#16)
Re: [PoC] XMLCast (SQL/XML X025)

Hi Robert

On 21.05.25 19:10, Robert Haas wrote:

Yeah. Just to be clear, I can't really think of committing a patch in
this area because I don't know the topic well enough. I can make some
general comments on what I see as issues with this patch but serious
review would really need to come from a committer who is more familiar
with the XML specifications than I am.

I understand. And I really do appreciate that you take the time to take
a look at it nevertheless.

If nobody like that shows up,
this proposal won't be able to advance.

So I'll keep my fingers crossed that somebody shows up :)

Well, the sentence begins with "Another option". Let's say we were
talking about making cookies. I could say "Another option, if you
don't have butter, is to substitute Crisco." But if I do that, I
should then go on to explain further: "However, if you do this, it may
affect the flavor of the cookies and they may brown differently in the
oven. Nevertheless, it's better than not having cookies." Your patch
seemed to me to be lacking any further explanation of this kind. When
we document that there are multiple options, we should try to give
some context to help the user choose between them. In my cookie-based
example, the additional text makes it clear why I would select the
Crisco option: I might be out of butter, and something is better than
nothing. In your case, it was not clear to me why someone should
choose XMLCAST over options or the other way around.

To be clear, I don't want you to explain it *to me*. I want you to
explain it to the reader of the documentation.

Got it.

In v10 I added this to the documentation to make the difference to CAST
clearer:

Similar to the SQL function <function>CAST</function>, this function
converts an <replaceable>expression into the specified
<replaceable>type</replaceable>. It is primarily used for converting
between SQL values and <type>xml</type> values in a standards-compliant way.

Unlike <function>CAST</function>, which may coerce SQL values into text
or XML without enforcing a specific lexical representation,
<function>xmlcast</function> ensures that the conversion produces or
expects a canonical XML Schema lexical form appropriate for the target
type. For example, an <type>interval</type> value is rendered as
<literal>P1Y2M</literal> (<type>xs:duration</type>), and a
<type>timestamp</type> as  <literal>2023-05-19T14:30:00Z</literal>
(xs:dateTime). Similarly, when converting from XML to SQL types,
<function>xmlcast</function> validates that the input string conforms to
the lexical format required by the corresponding SQL type.

Says the SQL/XML:2023 standard :)

SQL/XML:2023 (ISO/IEC 9075-14:2023) - “General Rules” of §6.7.3 (d.ii.1
and d.ii.2):

Cool. You should put that in the patch.

In v10 I changed these comments to:

/*
 * SQL date/time types must be mapped to XML Schema types when casting
to XML:
 *   - DATE                        -> xs:date
 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
 *
 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
 * Subclause 6.7 "<XML cast specification>", item 15.e.i–v.
 *
 * The corresponding XML Schema lexical formats (e.g., "2023-05-19",
"14:30:00Z",
 * "2023-05-19T14:30:00+01:00") follow ISO 8601 and are specified in
 * W3C XML Schema Part 2: Primitive Datatypes §3.2.7 (dateTime) and
§3.2.9 (date).
 */

and

/*
 * SQL interval types must be mapped to XML Schema types when casting to
XML:
 *   - Year-month intervals -> xs:yearMonthDuration
 *   - Day-time intervals    -> xs:dayTimeDuration
 *
 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
 *
 * These XML Schema types require ISO 8601-compatible lexical
representations,
 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
 * W3C XML Schema Part 2: Primitve Datatypes, §3.2.6 (duration)
 */

Given that XMLCast converts values between SQL and XML and vice versa,
my rationale was that if the target type is not a text type (such as
TEXTOID, VARCHAROID, or NAMEOID), then the cast operand must be of type
xml, which makes this default: safe.
[...]
But I can see it looks unsafe. Do you have something like this in mind?
[...]
default:
elog(ERROR, "unsupported target data type for XMLCast");
}

Yes, exactly.

Done in v10.

Thanks!

Jim

#18Robert Haas
robertmhaas@gmail.com
In reply to: Jim Jones (#17)
Re: [PoC] XMLCast (SQL/XML X025)

On Wed, May 21, 2025 at 2:22 PM Jim Jones <jim.jones@uni-muenster.de> wrote:

In v10 I added this to the documentation to make the difference to CAST
clearer:

Yes, that looks very helpful.

In v10 I changed these comments to:

That, too.

I don't have time to re-review this right now, but I encourage you to
look through the patch for other, similar places that could benefit
from a fuller explanation. And I hope somebody else shows up to
express interest in this so that your work is not wasted...

--
Robert Haas
EDB: http://www.enterprisedb.com

#19Jim Jones
jim.jones@uni-muenster.de
In reply to: Robert Haas (#18)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

On 22.05.25 16:02, Robert Haas wrote:

I don't have time to re-review this right now, but I encourage you to
look through the patch for other, similar places that could benefit
from a fuller explanation. And I hope somebody else shows up to
express interest in this so that your work is not wasted...

Took another look at the code and added more references to the SQL/XML
spec where it made sense -- hope it's not too verbose now :)

v11 attached.

Best regards, Jim

Attachments:

v11-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v11-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 2b842d723aefd5b8bed976a0d774b2bc9aacb2db Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 23 May 2025 11:43:44 +0200
Subject: [PATCH v11] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as `xs:dateTime` and `xs:duration` (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
  - SQL -> XML: boolean, numeric, character, date/time, interval
  - XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

Documentation and regression tests are included.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 123 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 108 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2276 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 09309ba039..7f91ad3aee 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4496,14 +4496,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index ebe85337c2..5f34d95d64 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 8a72b5e70a..9cc0e07cca 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,127 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * SQL date/time types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats (e.g., "2023-05-19", "14:30:00Z",
+					 * "2023-05-19T14:30:00+01:00") follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes §3.2.7 (dateTime) and §3.2.9 (date).
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitve Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 7bc823507f..88c0a53e53 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1736,6 +1736,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4468,6 +4471,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 0b5652071d..5767a69219 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -788,7 +788,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16053,6 +16053,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18106,6 +18124,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18694,6 +18713,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 1f8e2d5467..93ededc6b4 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -274,6 +306,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2462,6 +2498,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2478,6 +2518,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 4aba0d9d4d..6edc0a19c5 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1956,6 +1956,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1982,6 +1985,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 3d6e6bdbfd..5894b892c9 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10091,6 +10091,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10101,7 +10104,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10137,6 +10140,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10214,6 +10218,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index a4150bff2e..20bfedc503 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2735,6 +2735,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 4610fc6129..d3d82a6e7f 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -860,6 +860,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 7d3b4198f2..8cc25f7f56 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1582,6 +1582,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1618,6 +1619,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index a4af3f717a..65750625b1 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -506,6 +506,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..9ba5400d2b 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+02 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+02
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 11:30:10+02 | 17:30:10+02 | 05:30:10+02 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..40d642d59d 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..520329fbcb 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+02 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+02
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 11:30:10+02 | 17:30:10+02 | 05:30:10+02 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..1fae5b4b00 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 9ea573fae2..ab1dc2a9bd 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3355,6 +3355,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.34.1

#20Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#19)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebased

Jim

Attachments:

v12-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v12-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From f9df728500dd281b6651b22fd62ef6586b58453a Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Mon, 27 Oct 2025 13:19:14 +0100
Subject: [PATCH v12] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as `xs:dateTime` and `xs:duration` (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
  - SQL -> XML: boolean, numeric, character, date/time, interval
  - XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

Documentation and regression tests are included.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 123 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 108 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2276 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index b81d89e260..bff8082160 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4494,14 +4494,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 3a8ad20160..412e1a4e37 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0e1a74976f..246abaf544 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,127 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * SQL date/time types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats (e.g., "2023-05-19", "14:30:00Z",
+					 * "2023-05-19T14:30:00+01:00") follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes §3.2.7 (dateTime) and §3.2.9 (date).
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitve Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ede838cd40..8994bdda8e 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4464,6 +4467,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a4b29c822e..8a599f9641 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -794,7 +794,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16144,6 +16144,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18195,6 +18213,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18783,6 +18802,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 12119f147f..34a2925e0e 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -275,6 +307,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2467,6 +2503,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2483,6 +2523,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 905c975d83..4b2fee64cb 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1955,6 +1955,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1981,6 +1984,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 79ec136231..c708be1ebd 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10115,6 +10115,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10125,7 +10128,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10161,6 +10164,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10238,6 +10242,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 66b4418369..918f88397d 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2762,6 +2762,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ecbddd12e1..4da08cd152 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -877,6 +877,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1b4436f2ff..77c1be8ff0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1602,6 +1602,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1638,6 +1639,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 84182eaaae..25306eddf0 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -508,6 +508,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 0d7a816b9f..60bb464bd3 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..a425109f71 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 19:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 19:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..40d642d59d 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..adb0ac0ab2 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 19:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-07'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 19:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..1fae5b4b00 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 43fe3bcd59..2e481cd8d7 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3383,6 +3383,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.43.0

#21Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#20)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebased

Jim

Attachments:

v13-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v13-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From cf3e2c7f1ba28049d3912b8ef4b3f79ae1ef83bd Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Mon, 3 Nov 2025 09:03:40 +0100
Subject: [PATCH v13] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as `xs:dateTime` and `xs:duration` (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
  - SQL -> XML: boolean, numeric, character, date/time, interval
  - XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

Documentation and regression tests are included.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 123 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 108 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2276 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index b81d89e260..bff8082160 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4494,14 +4494,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 3a8ad20160..412e1a4e37 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0e1a74976f..246abaf544 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,127 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * SQL date/time types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats (e.g., "2023-05-19", "14:30:00Z",
+					 * "2023-05-19T14:30:00+01:00") follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes §3.2.7 (dateTime) and §3.2.9 (date).
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitve Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ede838cd40..8994bdda8e 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4464,6 +4467,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a4b29c822e..8a599f9641 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -794,7 +794,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16144,6 +16144,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18195,6 +18213,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18783,6 +18802,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 12119f147f..34a2925e0e 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -275,6 +307,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2467,6 +2503,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2483,6 +2523,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 905c975d83..4b2fee64cb 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1955,6 +1955,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1981,6 +1984,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 79ec136231..c708be1ebd 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10115,6 +10115,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10125,7 +10128,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10161,6 +10164,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10238,6 +10242,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 35c915573a..d9eae5ed4f 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2762,6 +2762,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ecbddd12e1..4da08cd152 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -877,6 +877,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1b4436f2ff..77c1be8ff0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1602,6 +1602,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1638,6 +1639,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 84182eaaae..25306eddf0 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -508,6 +508,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 732dac47bc..7be87e3671 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..fd026305b7 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..40d642d59d 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..8c5488b9b8 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..1fae5b4b00 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 018b5919cf..a93b269af1 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3383,6 +3383,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.43.0

#22Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#21)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebased

Jim

Attachments:

v14-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v14-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From d5e9c5afbae9243b8c0bb042fda6ef41a6c70f4f Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Thu, 6 Nov 2025 17:30:04 +0100
Subject: [PATCH v14] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as `xs:dateTime` and `xs:duration` (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
  - SQL -> XML: boolean, numeric, character, date/time, interval
  - XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

Documentation and regression tests are included.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 123 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 108 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           |  61 +++
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 565 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 429 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 567 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 278 +++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 18 files changed, 2276 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 1f2829e56a..12b66da7a4 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4494,14 +4494,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 3a8ad20160..412e1a4e37 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0e1a74976f..246abaf544 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,127 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * SQL date/time types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats (e.g., "2023-05-19", "14:30:00Z",
+					 * "2023-05-19T14:30:00+01:00") follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes §3.2.7 (dateTime) and §3.2.9 (date).
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID)
+					{
+						text *mapped_value = cstring_to_text(
+							map_sql_value_to_xml_value(value, xexpr->type, false));
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitve Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					*op->resvalue = PointerGetDatum(
+						cstring_to_text(unescape_xml(str)));
+
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index ede838cd40..8994bdda8e 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4464,6 +4467,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 57fe018654..86c9a2b11d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -794,7 +794,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WAIT WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16165,6 +16165,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18238,6 +18256,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18828,6 +18847,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 32d6ae918c..b61e24ad54 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -275,6 +307,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2467,6 +2503,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2483,6 +2523,74 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if (inputTypcategory == TYPCATEGORY_NUMERIC || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 905c975d83..4b2fee64cb 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1955,6 +1955,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1981,6 +1984,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 556ab057e5..b69ad29caf 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10119,6 +10119,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10129,7 +10132,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10165,6 +10168,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10242,6 +10246,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 41e775570e..af7b20938a 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -2762,6 +2762,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ec..c9d097e097 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -877,6 +877,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1b4436f2ff..77c1be8ff0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1602,6 +1602,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1638,6 +1639,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 5d4fe27ef9..42f98cb7b2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -510,6 +510,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 732dac47bc..7be87e3671 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..fd026305b7 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,568 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..40d642d59d 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,432 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..8c5488b9b8 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,570 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910::text AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision::text AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..1fae5b4b00 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,281 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 432509277c..5248283a05 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3390,6 +3390,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.43.0

#23Jim Jones
jim.jones@uni-muenster.de
In reply to: Jim Jones (#22)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

rebased

Jim

Attachments:

v15-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v15-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 2fead54c86ba1fcc4db25b2f207eea86035bf80e Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 28 Nov 2025 11:11:19 +0100
Subject: [PATCH v15] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as xs:dateTime and xs:duration (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
  - SQL -> XML: boolean, numeric, character, date/time, interval
  - XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

To support proper handling of infinity values in numeric types during
XML casting (as required by XML Schema specifications), two helper
functions (numeric_is_inf and numeric_is_positive_inf) have been
added to numeric.c.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 135 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 109 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/numeric.c       |  22 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           | 121 ++++-
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/numeric.h           |   2 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 607 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 453 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 609 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 290 ++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 20 files changed, 2490 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 1f2829e56a..12b66da7a4 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4494,14 +4494,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 3a8ad20160..412e1a4e37 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0e1a74976f..a21750e8c9 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,139 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * Certain SQL data types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *   - BOOLEAN                     -> xs:boolean ("true"/"false")
+					 *   - BYTEA                       -> xs:base64Binary or xs:hexBinary
+					 *   - FLOAT/DOUBLE/NUMERIC        -> xs:float/double/decimal (with INF/-INF handling)
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", Syntax Rules, item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes:
+					 *   - §3.2.7 (dateTime): "2023-05-19T14:30:00+01:00"
+					 *   - §3.2.8 (time): "14:30:00Z"
+					 *   - §3.2.9 (date): "2023-05-19"
+					 *   - §3.2.2 (boolean): "true"/"false"
+					 *   - §3.2.16 (base64Binary/hexBinary): base64/hex encoded strings
+					 *   - §3.2.4 (float) and §3.2.5 (double): with "INF"/"-INF" for infinity
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID ||
+						xexpr->type == FLOAT4OID || xexpr->type == FLOAT8OID || xexpr->type == NUMERICOID)
+					{
+						char *strdt = map_sql_value_to_xml_value(value, xexpr->type, false);
+						text *mapped_value = cstring_to_text(strdt);
+						pfree(strdt);
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitive Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					{
+						char *unescaped = unescape_xml(str);
+						*op->resvalue = PointerGetDatum(cstring_to_text(unescaped));
+						pfree(unescaped);
+					}
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index d228318dc7..0e4f0cdc51 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4464,6 +4467,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3a0a354a9..a615a7b1ba 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -794,7 +794,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WAIT WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16164,6 +16164,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18237,6 +18255,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18827,6 +18846,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 44fd1385f8..b7f9ba4abb 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -275,6 +307,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2467,6 +2503,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2483,6 +2523,75 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if ((inputTypcategory == TYPCATEGORY_NUMERIC && inputType != FLOAT4OID &&
+		inputType != FLOAT8OID && inputType != NUMERICOID) || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 905c975d83..4b2fee64cb 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1955,6 +1955,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1981,6 +1984,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/numeric.c b/src/backend/utils/adt/numeric.c
index 2501007d98..2278d8154e 100644
--- a/src/backend/utils/adt/numeric.c
+++ b/src/backend/utils/adt/numeric.c
@@ -847,6 +847,28 @@ numeric_is_inf(Numeric num)
 	return NUMERIC_IS_INF(num);
 }
 
+/*
+ * numeric_is_positive_inf() -
+ *
+ *	Is Numeric value positive infinity?
+ */
+bool
+numeric_is_positive_inf(Numeric num)
+{
+	return NUMERIC_IS_PINF(num);
+}
+
+/*
+ * numeric_is_negative_inf() -
+ *
+ *	Is Numeric value negative infinity?
+ */
+bool
+numeric_is_negative_inf(Numeric num)
+{
+	return NUMERIC_IS_NINF(num);
+}
+
 /*
  * numeric_is_integral() -
  *
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 556ab057e5..b69ad29caf 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10119,6 +10119,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10129,7 +10132,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10165,6 +10168,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10242,6 +10246,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 41e775570e..4285164891 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -99,6 +99,7 @@
 #include "utils/date.h"
 #include "utils/datetime.h"
 #include "utils/lsyscache.h"
+#include "utils/numeric.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/xml.h"
@@ -2574,9 +2575,9 @@ map_sql_value_to_xml_value(Datum value, Oid type, bool xml_escape_strings)
 		{
 			case BOOLOID:
 				if (DatumGetBool(value))
-					return "true";
+					return pstrdup("true");
 				else
-					return "false";
+					return pstrdup("false");
 
 			case DATEOID:
 				{
@@ -2706,8 +2707,60 @@ map_sql_value_to_xml_value(Datum value, Oid type, bool xml_escape_strings)
 				}
 #endif							/* USE_LIBXML */
 
-		}
+			case FLOAT4OID:
+				/*
+				 * Special handling for infinity values in floating-point and
+				 * numeric types. The XML Schema specification requires that
+				 * positive infinity be represented as "INF" and negative
+				 * infinity as "-INF" in XML documents for float and double
+				 * types. While decimal types in XML Schema do not support
+				 * infinity, PostgreSQL's NUMERIC type can represent it, so
+				 * we use the same representation for consistency.
+				 *
+				 * See: XML Schema Part 2: Datatypes Second Edition, sections
+				 * 3.2.4 (float) and 3.2.5 (double).
+				 */
+				{
+					float4		val = DatumGetFloat4(value);
+
+					if (isinf(val))
+					{
+						if (val < 0)
+							return pstrdup("-INF");
+						else
+							return pstrdup("INF");
+					}
+				}
+				break;
 
+			case FLOAT8OID:
+				{
+					float8		val = DatumGetFloat8(value);
+
+					if (isinf(val))
+					{
+						if (val < 0)
+							return pstrdup("-INF");
+						else
+							return pstrdup("INF");
+					}
+				}
+				break;
+
+			case NUMERICOID:
+				{
+					Numeric		num = DatumGetNumeric(value);
+
+					if (numeric_is_inf(num))
+					{
+						if (numeric_is_positive_inf(num))
+							return pstrdup("INF");
+						else
+							return pstrdup("-INF");
+					}
+				}
+				break;
+		}
 		/*
 		 * otherwise, just use the type's native text representation
 		 */
@@ -2762,6 +2815,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
@@ -4350,6 +4464,7 @@ xml_xpathobjtoxmlarray(xmlXPathObjectPtr xpathobj,
 	datum = PointerGetDatum(cstring_to_xmltype(result_str));
 	(void) accumArrayResult(astate, datum, false,
 							XMLOID, CurrentMemoryContext);
+	pfree(result_str);
 	return 1;
 }
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ec..c9d097e097 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -877,6 +877,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1b4436f2ff..77c1be8ff0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1602,6 +1602,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1638,6 +1639,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 5d4fe27ef9..42f98cb7b2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -510,6 +510,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/numeric.h b/src/include/utils/numeric.h
index 215f1ea4f5..c57432507e 100644
--- a/src/include/utils/numeric.h
+++ b/src/include/utils/numeric.h
@@ -87,6 +87,8 @@ NumericGetDatum(Numeric X)
  */
 extern bool numeric_is_nan(Numeric num);
 extern bool numeric_is_inf(Numeric num);
+extern bool numeric_is_positive_inf(Numeric num);
+extern bool numeric_is_negative_inf(Numeric num);
 extern int32 numeric_maximum_size(int32 typmod);
 extern char *numeric_out_sci(Numeric num, int scale);
 extern char *numeric_normalize(Numeric num);
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 732dac47bc..7be87e3671 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..a5a56c5b74 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,610 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof | xmlcast  | pg_typeof |  xmlcast  | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------+----------+-----------+-----------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric   | Infinity | numeric   | -Infinity | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     | xmlcast  |    pg_typeof     |  xmlcast  |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------+----------+------------------+-----------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision | Infinity | double precision | -Infinity | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910 AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..98b2a2878e 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,456 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..5ec57ae5ef 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,612 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof | xmlcast  | pg_typeof |  xmlcast  | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------+----------+-----------+-----------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric   | Infinity | numeric   | -Infinity | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     | xmlcast  |    pg_typeof     |  xmlcast  |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------+----------+------------------+-----------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision | Infinity | double precision | -Infinity | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910 AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..648751d212 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,293 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e3c3523b5b..a33bda3416 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3400,6 +3400,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.43.0

#24Marcos Pegoraro
marcos@f10.com.br
In reply to: Jim Jones (#23)
Re: [PoC] XMLCast (SQL/XML X025)

Em sex., 28 de nov. de 2025 às 07:48, Jim Jones <jim.jones@uni-muenster.de>
escreveu:

rebased

+        <para>
+          It supports casting between <type>xml</type> and character,
numeric, date/time, and boolean data types.
+        </para>

Did you forget the interval and bytea types here ?
Why are saying character instead of text ? I found it only on SGML part.
Are you planning to add casting INF/-INF for Date type too ?

regards
Marcos

#25Jim Jones
jim.jones@uni-muenster.de
In reply to: Marcos Pegoraro (#24)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

Oi Marcos,

Thanks for the review.

On 28/11/2025 13:04, Marcos Pegoraro wrote:

Did you forget the interval and bytea types here ?

Good catch. I added "binary" to the paragraph.

Why are saying character instead of text ? I found it only on SGML part.

With "character type" I meant to include text, varchar, and char, as in
the docs[1]https://www.postgresql.org/docs/current/datatype-character.html.

Are you planning to add casting INF/-INF for Date type too ?

xsd:date does not support infinity.

v16 attached.

Best, Jim

[1]: https://www.postgresql.org/docs/current/datatype-character.html

Attachments:

v16-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v16-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 3ae6f83162d4f1c9aecba1f37946c4cda86e2ac7 Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 28 Nov 2025 11:11:19 +0100
Subject: [PATCH v16] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as xs:dateTime and xs:duration (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
* SQL -> XML: boolean, numeric, character, date/time, interval, binary
* XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

To support proper handling of infinity values in numeric types during
XML casting (as required by XML Schema specifications), two helper
functions (numeric_is_inf and numeric_is_positive_inf) have been
added to numeric.c.
---
 doc/src/sgml/datatype.sgml            |  87 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 135 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 109 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/numeric.c       |  22 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           | 121 ++++-
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/numeric.h           |   2 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 607 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 453 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 609 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 290 ++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 20 files changed, 2490 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 1f2829e56a..153e71b7e8 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4494,14 +4494,93 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          It supports casting between <type>xml</type> and character, numeric, date/time, binary, and boolean data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 3a8ad20160..412e1a4e37 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0e1a74976f..a21750e8c9 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,139 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * Certain SQL data types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *   - BOOLEAN                     -> xs:boolean ("true"/"false")
+					 *   - BYTEA                       -> xs:base64Binary or xs:hexBinary
+					 *   - FLOAT/DOUBLE/NUMERIC        -> xs:float/double/decimal (with INF/-INF handling)
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", Syntax Rules, item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes:
+					 *   - §3.2.7 (dateTime): "2023-05-19T14:30:00+01:00"
+					 *   - §3.2.8 (time): "14:30:00Z"
+					 *   - §3.2.9 (date): "2023-05-19"
+					 *   - §3.2.2 (boolean): "true"/"false"
+					 *   - §3.2.16 (base64Binary/hexBinary): base64/hex encoded strings
+					 *   - §3.2.4 (float) and §3.2.5 (double): with "INF"/"-INF" for infinity
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID ||
+						xexpr->type == FLOAT4OID || xexpr->type == FLOAT8OID || xexpr->type == NUMERICOID)
+					{
+						char *strdt = map_sql_value_to_xml_value(value, xexpr->type, false);
+						text *mapped_value = cstring_to_text(strdt);
+						pfree(strdt);
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitive Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					{
+						char *unescaped = unescape_xml(str);
+						*op->resvalue = PointerGetDatum(cstring_to_text(unescaped));
+						pfree(unescaped);
+					}
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index d228318dc7..0e4f0cdc51 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4464,6 +4467,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3a0a354a9..a615a7b1ba 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -794,7 +794,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WAIT WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16164,6 +16164,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18237,6 +18255,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18827,6 +18846,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 44fd1385f8..b7f9ba4abb 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -275,6 +307,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2467,6 +2503,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2483,6 +2523,75 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if ((inputTypcategory == TYPCATEGORY_NUMERIC && inputType != FLOAT4OID &&
+		inputType != FLOAT8OID && inputType != NUMERICOID) || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 905c975d83..4b2fee64cb 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1955,6 +1955,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1981,6 +1984,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/numeric.c b/src/backend/utils/adt/numeric.c
index 2501007d98..2278d8154e 100644
--- a/src/backend/utils/adt/numeric.c
+++ b/src/backend/utils/adt/numeric.c
@@ -847,6 +847,28 @@ numeric_is_inf(Numeric num)
 	return NUMERIC_IS_INF(num);
 }
 
+/*
+ * numeric_is_positive_inf() -
+ *
+ *	Is Numeric value positive infinity?
+ */
+bool
+numeric_is_positive_inf(Numeric num)
+{
+	return NUMERIC_IS_PINF(num);
+}
+
+/*
+ * numeric_is_negative_inf() -
+ *
+ *	Is Numeric value negative infinity?
+ */
+bool
+numeric_is_negative_inf(Numeric num)
+{
+	return NUMERIC_IS_NINF(num);
+}
+
 /*
  * numeric_is_integral() -
  *
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 556ab057e5..b69ad29caf 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10119,6 +10119,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10129,7 +10132,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10165,6 +10168,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10242,6 +10246,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 41e775570e..4285164891 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -99,6 +99,7 @@
 #include "utils/date.h"
 #include "utils/datetime.h"
 #include "utils/lsyscache.h"
+#include "utils/numeric.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/xml.h"
@@ -2574,9 +2575,9 @@ map_sql_value_to_xml_value(Datum value, Oid type, bool xml_escape_strings)
 		{
 			case BOOLOID:
 				if (DatumGetBool(value))
-					return "true";
+					return pstrdup("true");
 				else
-					return "false";
+					return pstrdup("false");
 
 			case DATEOID:
 				{
@@ -2706,8 +2707,60 @@ map_sql_value_to_xml_value(Datum value, Oid type, bool xml_escape_strings)
 				}
 #endif							/* USE_LIBXML */
 
-		}
+			case FLOAT4OID:
+				/*
+				 * Special handling for infinity values in floating-point and
+				 * numeric types. The XML Schema specification requires that
+				 * positive infinity be represented as "INF" and negative
+				 * infinity as "-INF" in XML documents for float and double
+				 * types. While decimal types in XML Schema do not support
+				 * infinity, PostgreSQL's NUMERIC type can represent it, so
+				 * we use the same representation for consistency.
+				 *
+				 * See: XML Schema Part 2: Datatypes Second Edition, sections
+				 * 3.2.4 (float) and 3.2.5 (double).
+				 */
+				{
+					float4		val = DatumGetFloat4(value);
+
+					if (isinf(val))
+					{
+						if (val < 0)
+							return pstrdup("-INF");
+						else
+							return pstrdup("INF");
+					}
+				}
+				break;
 
+			case FLOAT8OID:
+				{
+					float8		val = DatumGetFloat8(value);
+
+					if (isinf(val))
+					{
+						if (val < 0)
+							return pstrdup("-INF");
+						else
+							return pstrdup("INF");
+					}
+				}
+				break;
+
+			case NUMERICOID:
+				{
+					Numeric		num = DatumGetNumeric(value);
+
+					if (numeric_is_inf(num))
+					{
+						if (numeric_is_positive_inf(num))
+							return pstrdup("INF");
+						else
+							return pstrdup("-INF");
+					}
+				}
+				break;
+		}
 		/*
 		 * otherwise, just use the type's native text representation
 		 */
@@ -2762,6 +2815,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
@@ -4350,6 +4464,7 @@ xml_xpathobjtoxmlarray(xmlXPathObjectPtr xpathobj,
 	datum = PointerGetDatum(cstring_to_xmltype(result_str));
 	(void) accumArrayResult(astate, datum, false,
 							XMLOID, CurrentMemoryContext);
+	pfree(result_str);
 	return 1;
 }
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ec..c9d097e097 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -877,6 +877,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1b4436f2ff..77c1be8ff0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1602,6 +1602,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1638,6 +1639,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 5d4fe27ef9..42f98cb7b2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -510,6 +510,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/numeric.h b/src/include/utils/numeric.h
index 215f1ea4f5..c57432507e 100644
--- a/src/include/utils/numeric.h
+++ b/src/include/utils/numeric.h
@@ -87,6 +87,8 @@ NumericGetDatum(Numeric X)
  */
 extern bool numeric_is_nan(Numeric num);
 extern bool numeric_is_inf(Numeric num);
+extern bool numeric_is_positive_inf(Numeric num);
+extern bool numeric_is_negative_inf(Numeric num);
 extern int32 numeric_maximum_size(int32 typmod);
 extern char *numeric_out_sci(Numeric num, int scale);
 extern char *numeric_normalize(Numeric num);
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 732dac47bc..7be87e3671 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..a5a56c5b74 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,610 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof | xmlcast  | pg_typeof |  xmlcast  | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------+----------+-----------+-----------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric   | Infinity | numeric   | -Infinity | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     | xmlcast  |    pg_typeof     |  xmlcast  |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------+----------+------------------+-----------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision | Infinity | double precision | -Infinity | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910 AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..98b2a2878e 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,456 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..5ec57ae5ef 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,612 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof | xmlcast  | pg_typeof |  xmlcast  | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------+----------+-----------+-----------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric   | Infinity | numeric   | -Infinity | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     | xmlcast  |    pg_typeof     |  xmlcast  |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------+----------+------------------+-----------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision | Infinity | double precision | -Infinity | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910 AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..648751d212 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,293 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e3c3523b5b..a33bda3416 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3400,6 +3400,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.43.0

#26Marcos Pegoraro
marcos@f10.com.br
In reply to: Jim Jones (#25)
Re: [PoC] XMLCast (SQL/XML X025)

Em sex., 28 de nov. de 2025 às 12:30, Jim Jones <jim.jones@uni-muenster.de>
escreveu:

With "character type" I meant to include text, varchar, and char, as in
the docs[1]

You wrote character only on the SGML part, all others are text. When
you write numeric, the user understands that it can be bigint, integer,
numeric, etc, so users can get confused about TEXT and CHAR(N), because the
only place you wrote character is on SGML.

And interval is still not on that list. With text and interval types.

+ It supports casting between <type>xml</type> and text, numeric,
date/time, boolean, binary and interval data types.

And about domains
+ switch (xexpr->targetType)
+ {
+ case XMLOID:
...
+ case INT4OID:

Does this shape capture this type ?
CREATE DOMAIN i32 AS integer;

regards
Marcos

#27Jim Jones
jim.jones@uni-muenster.de
In reply to: Marcos Pegoraro (#26)
Re: [PoC] XMLCast (SQL/XML X025)

On 28/11/2025 19:27, Marcos Pegoraro wrote:

You wrote character only on the SGML part, all others are text. When
you write numeric, the user understands that it can be bigint, integer,
numeric, etc, so users can get confused about TEXT and CHAR(N), because
the only place you wrote character is on SGML.

Character data type in this sentence means the character types[1]https://www.postgresql.org/docs/current/datatype-character.html as a
category, not the type character or character varying.

"It supports casting between xml and character, numeric, date/time,
binary, and boolean data types."

Sorry if I'm misunderstanding your point.

And interval is still not on that list.

Interval is already part of the date/time types[1]https://www.postgresql.org/docs/current/datatype-character.html

And about domains
+ switch (xexpr->targetType)
+ {
+ case XMLOID:
...
+ case INT4OID:

Does this shape capture this type ?
CREATE DOMAIN i32 AS integer;

Not really. XMLCast implements the type-specific lexical and semantic
rules defined by SQL/XML, which apply only to base (non-domain) data
types. Although the grammar permits a domain name as a target, the
standard does not define any XML-specific semantics for domains.
Supporting them would go beyond the scope of this patch, and users
who need a domain can IMHO cast the XMLCast result afterward.

Thanks!

Best, Jim

[1]: https://www.postgresql.org/docs/current/datatype-character.html
[2]: https://www.postgresql.org/docs/current/datatype-datetime.html

#28Marcos Pegoraro
marcos@f10.com.br
In reply to: Jim Jones (#27)
Re: [PoC] XMLCast (SQL/XML X025)

Em sex., 28 de nov. de 2025 às 17:07, Jim Jones <jim.jones@uni-muenster.de>
escreveu:

Character data type in this sentence means the character types[1] as a
category, not the type character or character varying.

Yes, I understand that, but saying character confuses me a bit.

Interval is already part of the date/time types[1]

Fine.

Not really. XMLCast implements the type-specific lexical and semantic

rules defined by SQL/XML, which apply only to base (non-domain) data
types. Although the grammar permits a domain name as a target, the
standard does not define any XML-specific semantics for domains.
Supporting them would go beyond the scope of this patch, and users
who need a domain can IMHO cast the XMLCast result afterward.

Correct. So maybe would be fine to explain this on SGML part, because a
domain is sometimes used just as an alias of a base type, without checking
or any other feature.

#29Jim Jones
jim.jones@uni-muenster.de
In reply to: Marcos Pegoraro (#28)
Re: [PoC] XMLCast (SQL/XML X025)

On 29/11/2025 12:38, Marcos Pegoraro wrote:

Em sex., 28 de nov. de 2025 às 17:07, Jim Jones <jim.jones@uni-
muenster.de <mailto:jim.jones@uni-muenster.de>> escreveu:

Character data type in this sentence means the character types[1] as a
category, not the type character or character varying.

Yes, I understand that, but  saying character confuses me a bit.

Perhaps listing the data types would make things easier to understand?
Something like:

* Casting is supported between xml and the built-in character
(character, character varying, or text), numeric, boolean, binary, and
date/time types. The date/time types (date, time with time zone,
timestamp with time zone, and interval) are converted to their
corresponding XML Schema types: xs:date, xs:time, xs:dateTime, and
xs:duration.

A bit too verbose for my taste, but I could live with it.

XMLSerialize does something similar:

"type can be character, character varying, or text..."

What do you think?

Not really. XMLCast implements the type-specific lexical and semantic
rules defined by SQL/XML, which apply only to base (non-domain) data
types. Although the grammar permits a domain name as a target, the
standard does not define any XML-specific semantics for domains.
Supporting them would go beyond the scope of this patch, and users
who need a domain can IMHO cast the XMLCast result afterward.

Correct. So maybe would be fine to explain this on SGML part, because a
domain is sometimes used just as an alias of a base type, without
checking or any other feature.

If the user gets a "ERROR: unsupported target data type for XMLCast"
using a domain (being an alias for a base type or not) and the
documentation clearly lists the supported types, wouldn't that be
enough? If not, do you have anything in mind that we could add to the docs?

Thanks for the review

Best, Jim

#30Marcos Pegoraro
marcos@f10.com.br
In reply to: Jim Jones (#29)
Re: [PoC] XMLCast (SQL/XML X025)

Em sáb., 29 de nov. de 2025 às 09:38, Jim Jones <jim.jones@uni-muenster.de>
escreveu:

Perhaps listing the data types would make things easier to understand?
Something like:

* Casting is supported between xml and the built-in character
(character, character varying, or text), numeric, boolean, binary, and
date/time types. The date/time types (date, time with time zone,
timestamp with time zone, and interval) are converted to their
corresponding XML Schema types: xs:date, xs:time, xs:dateTime, and
xs:duration.

If we link to them, then the user will not have any doubts of what
datatypes we work

+ It supports casting between <type>xml</type> and <link
linkend="datatype-character-table">character</link>, <link
linkend="datatype-numeric">numeric</link>, <link
linkend="datatype-datetime">date/time</link>, <link
linkend="datatype-boolean">boolean</link> and <link
linkend="datatype-binary">binary</link> data types.

If the user gets a "ERROR: unsupported target data type for XMLCast"
using a domain (being an alias for a base type or not) and the
documentation clearly lists the supported types, wouldn't that be
enough? If not, do you have anything in mind that we could add to the docs?

I think being explicit in the previous paragraph then is fine to not
mention domains.

regards
Marcos

#31Jim Jones
jim.jones@uni-muenster.de
In reply to: Marcos Pegoraro (#30)
1 attachment(s)
Re: [PoC] XMLCast (SQL/XML X025)

On 29/11/2025 20:39, Marcos Pegoraro wrote:

If we link to them, then the user will not have any doubts of what
datatypes we work

+          It supports casting between <type>xml</type> and <link
linkend="datatype-character-table">character</link>, <link
linkend="datatype-numeric">numeric</link>, <link linkend="datatype-
datetime">date/time</link>, <link linkend="datatype-boolean">boolean</
link> and <link linkend="datatype-binary">binary</link> data types. 

LGTM.
v17 attached has now the links to each data type category.

Thanks!

Best, Jim

Attachments:

v17-0001-Add-XMLCast-function-SQL-XML-X025.patchtext/x-patch; charset=UTF-8; name=v17-0001-Add-XMLCast-function-SQL-XML-X025.patchDownload
From 9efe547245835011848506f07013a19396163fde Mon Sep 17 00:00:00 2001
From: Jim Jones <jim.jones@uni-muenster.de>
Date: Fri, 28 Nov 2025 11:11:19 +0100
Subject: [PATCH v17] Add XMLCast function (SQL/XML X025)

This patch introduces support for the XMLCAST function, as specified
in SQL/XML:2023 (ISO/IEC 9075-14:2023), Subclause 6.7 "<XML cast
specification>". It enables standards-compliant conversion between
SQL data types and XML, following the lexical rules defined by the
W3C XML Schema Part 2.

XMLCast provides an alternative to CAST when converting SQL values
into XML content, ensuring the output uses canonical XML Schema
lexical representations. For example, timestamp and interval values
are rendered as xs:dateTime and xs:duration (e.g.,
"2024-01-01T12:00:00Z" or "P1Y2M"), conforming to ISO 8601 formats.

Conversely, XMLCast also allows converting XML content back into SQL
types (e.g., boolean, numeric, date/time), validating the input string
according to XML Schema lexical forms.

Supported casts include:
* SQL -> XML: boolean, numeric, character, date/time, interval, binary
* XML -> SQL: the inverse of the above, with lexical validation

The BY REF and BY VALUE clauses are accepted for SQL/XML compatibility,
but ignored.

To support proper handling of infinity values in numeric types during
XML casting (as required by XML Schema specifications), two helper
functions (numeric_is_inf and numeric_is_positive_inf) have been
added to numeric.c.
---
 doc/src/sgml/datatype.sgml            |  89 +++-
 src/backend/catalog/sql_features.txt  |   2 +-
 src/backend/executor/execExprInterp.c | 135 +++++-
 src/backend/nodes/nodeFuncs.c         |  13 +
 src/backend/parser/gram.y             |  22 +-
 src/backend/parser/parse_expr.c       | 109 +++++
 src/backend/parser/parse_target.c     |   7 +
 src/backend/utils/adt/numeric.c       |  22 +
 src/backend/utils/adt/ruleutils.c     |  10 +-
 src/backend/utils/adt/xml.c           | 121 ++++-
 src/include/nodes/parsenodes.h        |   8 +
 src/include/nodes/primnodes.h         |   3 +
 src/include/parser/kwlist.h           |   1 +
 src/include/utils/numeric.h           |   2 +
 src/include/utils/xml.h               |   1 +
 src/test/regress/expected/xml.out     | 607 +++++++++++++++++++++++++
 src/test/regress/expected/xml_1.out   | 453 +++++++++++++++++++
 src/test/regress/expected/xml_2.out   | 609 ++++++++++++++++++++++++++
 src/test/regress/sql/xml.sql          | 290 ++++++++++++
 src/tools/pgindent/typedefs.list      |   1 +
 20 files changed, 2492 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml
index 1f2829e56a..df35424e7d 100644
--- a/doc/src/sgml/datatype.sgml
+++ b/doc/src/sgml/datatype.sgml
@@ -4494,14 +4494,95 @@ XMLPARSE ( { DOCUMENT | CONTENT } <replaceable>value</replaceable>)
 XMLPARSE (DOCUMENT '<?xml version="1.0"?><book><title>Manual</title><chapter>...</chapter></book>')
 XMLPARSE (CONTENT 'abc<foo>bar</foo><bar>foo</bar>')
 ]]></programlisting>
-    While this is the only way to convert character strings into XML
-    values according to the SQL standard, the PostgreSQL-specific
-    syntaxes:
+
+    Another option for converting values to or from <type>xml</type> is the <function>xmlcast</function> function,
+    which is designed to cast SQL data types into <type>xml</type>, and vice versa, in a standards-compliant way.
+<synopsis>
+XMLCAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> [ BY REF | BY VALUE ] )
+</synopsis>
+    Similar to the SQL function <function>CAST</function>, this function converts an <replaceable>expression</replaceable>
+    into the specified <replaceable>type</replaceable>. It is primarily used for converting between SQL values
+    and <type>xml</type> values in a standards-compliant way.
+
+    Unlike <function>CAST</function>, which may coerce SQL values into text or XML without enforcing a specific
+    lexical representation, <function>xmlcast</function> ensures that the conversion produces or expects a
+    canonical XML Schema lexical form appropriate for the target type. For example, an <type>interval</type>
+    value is rendered as <literal>P1Y2M</literal> (<type>xs:duration</type>), and a <type>timestamp</type> as
+    <literal>2023-05-19T14:30:00Z</literal> (xs:dateTime). Similarly, when converting from XML to SQL types,
+    <function>xmlcast</function> validates that the input string conforms to the lexical format required by the
+    corresponding SQL type.
+
+    The function <function>xmlcast</function> follows these rules:
+
+     <itemizedlist>
+      <listitem>
+        <para>
+          Either <replaceable>expression</replaceable> or <replaceable>type</replaceable> must be of type <type>xml</type>.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Casting is supported between <type>xml</type> and <link linkend="datatype-character-table">character</link>,
+          <link linkend="datatype-numeric">numeric</link>, <link linkend="datatype-datetime">date/time</link>,
+          <link linkend="datatype-boolean">boolean</link> and <link linkend="datatype-binary">binary</link> data types.
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Similar to the function <function>xmltext</function>, <replaceable>expression</replaceable>
+          values containing XML predefined entities will be escaped (see examples below).
+        </para>
+      </listitem>
+      <listitem>
+        <para>
+          Values of type <type>date</type>, <type>time with time zone</type>, <type>timestamp with time zone</type>,
+          and <type>interval</type> are converted to their corresponding XML Schema types: <type>xs:date</type>,
+          <type>xs:time</type>, <type>xs:dateTime</type>, and <type>xs:duration</type>, respectively.
+        </para>
+      </listitem>
+       <listitem>
+        <para>
+          The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
+          are accepted but ignored, as discussed in
+          <xref linkend="functions-xml-limits-postgresql"/>.
+        </para>
+      </listitem>
+    </itemizedlist>
+
+     Examples:
+<screen><![CDATA[
+SELECT xmlcast('<foo&bar>'::text AS xml);
+       xmlcast
+---------------------
+ &lt;foo&amp;bar&gt;
+
+SELECT xmlcast('&lt;foo&amp;bar&gt;'::xml AS text);
+  xmlcast
+-----------
+ <foo&bar>
+
+SELECT xmlcast(CURRENT_TIMESTAMP AS xml);
+             xmlcast
+---------------------------------
+ 2024-06-02T00:29:40.92397+02:00
+
+SELECT xmlcast('P1Y2M3W4DT5H6M7S'::xml AS interval);
+            xmlcast
+--------------------------------
+ 1 year 2 mons 25 days 05:06:07
+
+SELECT xmlcast('1 year 2 months 3 weeks 4 days 5 hours 6 minutes 7 seconds'::interval AS xml);
+     xmlcast
+-----------------
+ P1Y2M25DT5H6M7S
+]]></screen>
+
+    Alternatively, it is also possible to convert character strings into XML using PostgreSQL-specific cast syntaxes:
 <programlisting><![CDATA[
 xml '<foo>bar</foo>'
 '<foo>bar</foo>'::xml
 ]]></programlisting>
-    can also be used.
+
    </para>
 
    <para>
diff --git a/src/backend/catalog/sql_features.txt b/src/backend/catalog/sql_features.txt
index 3a8ad20160..412e1a4e37 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -624,7 +624,7 @@ X014	Attributes of XML type			YES
 X015	Fields of XML type			NO	
 X016	Persistent XML values			YES	
 X020	XMLConcat			YES	
-X025	XMLCast			NO	
+X025	XMLCast			YES	
 X030	XMLDocument			NO	
 X031	XMLElement			YES	
 X032	XMLForest			YES	
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 0e1a74976f..a21750e8c9 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -69,6 +69,7 @@
 #include "utils/array.h"
 #include "utils/builtins.h"
 #include "utils/date.h"
+#include "utils/datetime.h"
 #include "utils/datum.h"
 #include "utils/expandedrecord.h"
 #include "utils/json.h"
@@ -4643,11 +4644,139 @@ ExecEvalXmlExpr(ExprState *state, ExprEvalStep *op)
 				*op->resnull = false;
 			}
 			break;
+			case IS_XMLCAST:
+			{
+				Datum *argvalue = op->d.xmlexpr.argvalue;
+				bool *argnull = op->d.xmlexpr.argnull;
+				char *str;
 
-		default:
-			elog(ERROR, "unrecognized XML operation");
+				Assert(list_length(xexpr->args) == 1);
+
+				if (argnull[0])
+					return;
+
+				value = argvalue[0];
+
+				switch (xexpr->targetType)
+				{
+				case XMLOID:
+					/*
+					 * Certain SQL data types must be mapped to XML Schema types when casting to XML:
+					 *   - DATE                        -> xs:date
+					 *   - TIME [WITH/WITHOUT TZ]      -> xs:time
+					 *   - TIMESTAMP [WITH/WITHOUT TZ] -> xs:dateTime
+					 *   - BOOLEAN                     -> xs:boolean ("true"/"false")
+					 *   - BYTEA                       -> xs:base64Binary or xs:hexBinary
+					 *   - FLOAT/DOUBLE/NUMERIC        -> xs:float/double/decimal (with INF/-INF handling)
+					 *
+					 * These mappings are defined in SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", Syntax Rules, item 15.e.i–v.
+					 *
+					 * The corresponding XML Schema lexical formats follow ISO 8601 and are specified in
+					 * W3C XML Schema Part 2: Primitive Datatypes:
+					 *   - §3.2.7 (dateTime): "2023-05-19T14:30:00+01:00"
+					 *   - §3.2.8 (time): "14:30:00Z"
+					 *   - §3.2.9 (date): "2023-05-19"
+					 *   - §3.2.2 (boolean): "true"/"false"
+					 *   - §3.2.16 (base64Binary/hexBinary): base64/hex encoded strings
+					 *   - §3.2.4 (float) and §3.2.5 (double): with "INF"/"-INF" for infinity
+					 */
+					if (xexpr->type == TIMESTAMPOID || xexpr->type == TIMESTAMPTZOID ||
+						xexpr->type == DATEOID || xexpr->type == BYTEAOID || xexpr->type == BOOLOID ||
+						xexpr->type == FLOAT4OID || xexpr->type == FLOAT8OID || xexpr->type == NUMERICOID)
+					{
+						char *strdt = map_sql_value_to_xml_value(value, xexpr->type, false);
+						text *mapped_value = cstring_to_text(strdt);
+						pfree(strdt);
+						*op->resvalue = PointerGetDatum(mapped_value);
+					}
+					/*
+					 * SQL interval types must be mapped to XML Schema types when casting to XML:
+					 *   - Year-month intervals → xs:yearMonthDuration
+					 *   - Day-time intervals   → xs:dayTimeDuration
+					 *
+					 * This behavior is required by SQL/XML:2023 (ISO/IEC 9075-14:2023),
+					 * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii.1–2.
+					 *
+					 * These XML Schema types require ISO 8601-compatible lexical representations,
+					 * such as: "P1Y2M", "P3DT4H5M", or "P1Y2M3DT4H5M6S", as defined in
+					 * W3C XML Schema Part 2: Primitive Datatypes, §3.2.6 (duration)
+					 */
+					else if (xexpr->type == INTERVALOID)
+					{
+						Interval *in = DatumGetIntervalP(value);
+
+						struct pg_itm tt, *itm = &tt;
+						char buf[MAXDATELEN + 1];
+
+						if (INTERVAL_NOT_FINITE(in))
+						{
+							if (INTERVAL_IS_NOBEGIN(in))
+								strcpy(buf, EARLY);
+							else if (INTERVAL_IS_NOEND(in))
+								strcpy(buf, LATE);
+							else
+								elog(ERROR, "invalid interval argument");
+						}
+						else
+						{
+							interval2itm(*in, itm);
+							EncodeInterval(itm, INTSTYLE_ISO_8601, buf);
+						}
+
+						*op->resvalue = PointerGetDatum(cstring_to_text(buf));
+					}
+					/* no need to escape the result, as the origin is also an XML */
+					else if (xexpr->type == XMLOID)
+						*op->resvalue = PointerGetDatum(DatumGetXmlP(value));
+					/* we  make sure that potential predifined entitties are escaped */
+					else
+						*op->resvalue = PointerGetDatum(
+							DatumGetXmlP((DirectFunctionCall1(xmltext, value))));
+					break;
+				case TEXTOID:
+				case VARCHAROID:
+				case NAMEOID:
+				case BPCHAROID:
+					/*
+					 * when casting from XML to a character string we make sure that
+					 * all escaped xml characters are unescaped.
+					 */
+					str = text_to_cstring(DatumGetTextPP(value));
+					{
+						char *unescaped = unescape_xml(str);
+						*op->resvalue = PointerGetDatum(cstring_to_text(unescaped));
+						pfree(unescaped);
+					}
+					pfree(str);
+					break;
+				case INT2OID:
+				case INT4OID:
+				case INT8OID:
+				case NUMERICOID:
+				case FLOAT4OID:
+				case FLOAT8OID:
+				case BOOLOID:
+				case TIMESTAMPOID:
+				case TIMESTAMPTZOID:
+				case TIMEOID:
+				case TIMETZOID:
+				case DATEOID:
+				case BYTEAOID:
+				case INTERVALOID:
+					*op->resvalue = PointerGetDatum(DatumGetTextP(value));
+					break;
+				default:
+					elog(ERROR, "unsupported target data type for XMLCast");
+				}
+
+				*op->resnull = false;
+			}
 			break;
-	}
+			default:
+				elog(ERROR, "unrecognized XML operation");
+				break;
+			}
 }
 
 /*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index d228318dc7..0e4f0cdc51 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1732,6 +1732,9 @@ exprLocation(const Node *expr)
 		case T_FunctionParameter:
 			loc = ((const FunctionParameter *) expr)->location;
 			break;
+		case T_XmlCast:
+			loc = ((const XmlCast *) expr)->location;
+			break;
 		case T_XmlSerialize:
 			/* XMLSERIALIZE keyword should always be the first thing */
 			loc = ((const XmlSerialize *) expr)->location;
@@ -4464,6 +4467,16 @@ raw_expression_tree_walker_impl(Node *node,
 					return true;
 			}
 			break;
+		case T_XmlCast:
+			{
+				XmlCast   *xc = (XmlCast *) node;
+
+				if (WALK(xc->expr))
+					return true;
+				if (WALK(xc->targetType))
+					return true;
+			}
+			break;
 		case T_CollateClause:
 			return WALK(((CollateClause *) node)->arg);
 		case T_SortBy:
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c3a0a354a9..a615a7b1ba 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -794,7 +794,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 
 	WAIT WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
 
-	XML_P XMLATTRIBUTES XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
+	XML_P XMLATTRIBUTES XMLCAST XMLCONCAT XMLELEMENT XMLEXISTS XMLFOREST XMLNAMESPACES
 	XMLPARSE XMLPI XMLROOT XMLSERIALIZE XMLTABLE
 
 	YEAR_P YES_P
@@ -16164,6 +16164,24 @@ func_expr_common_subexpr:
 					v->location = @1;
 					$$ = (Node *) v;
 				}
+			| XMLCAST '(' a_expr AS Typename ')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
+			| XMLCAST '(' a_expr AS Typename xml_passing_mech')'
+				{
+					XmlCast *n = makeNode(XmlCast);
+
+					n->expr = $3;
+					n->targetType = $5;
+					n->location = @1;
+					$$ = (Node *) n;
+				}
 			| XMLCONCAT '(' expr_list ')'
 				{
 					$$ = makeXmlExpr(IS_XMLCONCAT, NULL, NIL, $3, @1);
@@ -18237,6 +18255,7 @@ col_name_keyword:
 			| VALUES
 			| VARCHAR
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
@@ -18827,6 +18846,7 @@ bare_label_keyword:
 			| WRITE
 			| XML_P
 			| XMLATTRIBUTES
+			| XMLCAST
 			| XMLCONCAT
 			| XMLELEMENT
 			| XMLEXISTS
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 44fd1385f8..b7f9ba4abb 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -40,6 +40,37 @@
 #include "utils/timestamp.h"
 #include "utils/xml.h"
 
+/*
+ * Determines whether a type category is allowed in XMLCAST conversions,
+ * either as a source (SQL -> XML) or target (XML -> SQL) type.
+ *
+ * Based on SQL/XML:2023 (ISO/IEC 9075-14:2023),
+ * Subclause 6.7 "<XML cast specification>", General Rules, item 3.d.ii:
+ *
+ * - Items 1–2 explicitly describe interval mappings:
+ *     1) Year-month intervals -> xs:yearMonthDuration
+ *     2) Day-time intervals   -> xs:dayTimeDuration
+ *
+ * - Items 3–4 describe the general case:
+ *     3) If the target XML type is an XML Schema built-in data type,
+ *     or
+ *     4) If it is derived from a built-in atomic type,
+ *     then that type (or its base type) governs the conversion.
+ *
+ * These built-in and atomic types are defined in "W3C XML Schema Part 2:
+ * Datatypes", and include types such as xs:boolean, xs:decimal, xs:date,
+ * xs:dateTime, and xs:string. While SQL/XML does not enumerate mappings
+ * for all these types, it relies on their existence and semantics to
+ * support conversions.
+ *
+ * As such, PostgreSQL allows casting to and from types in the following
+ * categories: numeric, string, datetime, boolean, and timespan.
+ */
+#define type_is_xmlcast_supported(x) ((x) == TYPCATEGORY_NUMERIC \
+			|| (x) == TYPCATEGORY_STRING || (x) == TYPCATEGORY_DATETIME \
+			|| (x) == TYPCATEGORY_BOOLEAN || (x) == TYPCATEGORY_UNKNOWN \
+			|| (x) == TYPCATEGORY_TIMESPAN)
+
 /* GUC parameters */
 bool		Transform_null_equals = false;
 
@@ -67,6 +98,7 @@ static Node *transformMinMaxExpr(ParseState *pstate, MinMaxExpr *m);
 static Node *transformSQLValueFunction(ParseState *pstate,
 									   SQLValueFunction *svf);
 static Node *transformXmlExpr(ParseState *pstate, XmlExpr *x);
+static Node *transformXmlCast(ParseState *pstate, XmlCast *xc);
 static Node *transformXmlSerialize(ParseState *pstate, XmlSerialize *xs);
 static Node *transformBooleanTest(ParseState *pstate, BooleanTest *b);
 static Node *transformCurrentOfExpr(ParseState *pstate, CurrentOfExpr *cexpr);
@@ -275,6 +307,10 @@ transformExprRecurse(ParseState *pstate, Node *expr)
 											   (SQLValueFunction *) expr);
 			break;
 
+		case T_XmlCast:
+			result = transformXmlCast(pstate, (XmlCast *) expr);
+			break;
+
 		case T_XmlExpr:
 			result = transformXmlExpr(pstate, (XmlExpr *) expr);
 			break;
@@ -2467,6 +2503,10 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 					newe = coerce_to_specific_type(pstate, newe, INT4OID,
 												   "XMLROOT");
 				break;
+			case IS_XMLCAST:
+				/* not handled here */
+				Assert(false);
+				break;
 			case IS_XMLSERIALIZE:
 				/* not handled here */
 				Assert(false);
@@ -2483,6 +2523,75 @@ transformXmlExpr(ParseState *pstate, XmlExpr *x)
 	return (Node *) newx;
 }
 
+static Node *
+transformXmlCast(ParseState *pstate, XmlCast *xc)
+{
+	Node *result;
+	XmlExpr *xexpr;
+	int32 targetTypmod;
+	Oid targetType;
+	Oid inputType;
+	char inputTypcategory;
+	char targetTypcategory;
+	bool inputTypispreferred;
+	bool targetTypispreferred;
+
+	inputType = exprType(transformExprRecurse(pstate, xc->expr));
+	get_type_category_preferred(inputType, &inputTypcategory, &inputTypispreferred);
+
+	typenameTypeIdAndMod(pstate, xc->targetType, &targetType, &targetTypmod);
+	get_type_category_preferred(targetType, &targetTypcategory, &targetTypispreferred);
+
+	/*
+	 * Ensure that either the cast operand or the data type is an XML,
+	 * and check if the data types are supported.
+	 */
+	if ((inputType != XMLOID && targetType != XMLOID) ||
+		(!type_is_xmlcast_supported(inputTypcategory) && inputType != XMLOID && inputType != BYTEAOID) ||
+		(!type_is_xmlcast_supported(targetTypcategory) && targetType != XMLOID && targetType != BYTEAOID))
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast from '%s' to '%s'",
+						format_type_be(inputType), format_type_be(targetType)),
+				 parser_errposition(pstate, xc->location)));
+
+	/*
+	 * It is not possible to cast some supported data types directly to XML,
+	 * so we first handle them as text and later on return them as XML.
+	 */
+	if ((inputTypcategory == TYPCATEGORY_NUMERIC && inputType != FLOAT4OID &&
+		inputType != FLOAT8OID && inputType != NUMERICOID) || inputType == TIMEOID ||
+		inputType == TIMETZOID || inputType == UNKNOWNOID || inputType == NAMEOID)
+		inputType = TEXTOID;
+
+	xexpr = makeNode(XmlExpr);
+	xexpr->op = IS_XMLCAST;
+	xexpr->location = xc->location;
+	xexpr->type = inputType;
+	xexpr->targetType = targetType;
+	xexpr->name = "xmlcast";
+	xexpr->args = list_make1(coerce_to_specific_type(pstate,
+													 transformExprRecurse(pstate, xc->expr),
+													 inputType,
+													 "XMLCAST"));
+
+	result = coerce_to_target_type(pstate, (Node *) xexpr,
+								   targetType == TEXTOID ? XMLOID : TEXTOID,
+								   targetType, targetTypmod,
+								   COERCION_EXPLICIT,
+								   COERCE_EXPLICIT_CAST,
+								   -1);
+
+	if (result == NULL)
+		ereport(ERROR,
+				(errcode(ERRCODE_CANNOT_COERCE),
+				 errmsg("cannot cast XMLCAST result to %s",
+						format_type_be(targetType)),
+				 parser_errposition(pstate, xexpr->location)));
+
+	return result;
+}
+
 static Node *
 transformXmlSerialize(ParseState *pstate, XmlSerialize *xs)
 {
diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c
index 905c975d83..4b2fee64cb 100644
--- a/src/backend/parser/parse_target.c
+++ b/src/backend/parser/parse_target.c
@@ -1955,6 +1955,9 @@ FigureColnameInternal(Node *node, char **name)
 			/* make SQL/XML functions act like a regular function */
 			switch (((XmlExpr *) node)->op)
 			{
+				case IS_XMLCAST:
+					*name = "xmlcast";
+					return 2;
 				case IS_XMLCONCAT:
 					*name = "xmlconcat";
 					return 2;
@@ -1981,6 +1984,10 @@ FigureColnameInternal(Node *node, char **name)
 					break;
 			}
 			break;
+		case T_XmlCast:
+			/* make XMLCAST act like a regular function */
+			*name = "xmlcast";
+			return 2;
 		case T_XmlSerialize:
 			/* make XMLSERIALIZE act like a regular function */
 			*name = "xmlserialize";
diff --git a/src/backend/utils/adt/numeric.c b/src/backend/utils/adt/numeric.c
index 2501007d98..2278d8154e 100644
--- a/src/backend/utils/adt/numeric.c
+++ b/src/backend/utils/adt/numeric.c
@@ -847,6 +847,28 @@ numeric_is_inf(Numeric num)
 	return NUMERIC_IS_INF(num);
 }
 
+/*
+ * numeric_is_positive_inf() -
+ *
+ *	Is Numeric value positive infinity?
+ */
+bool
+numeric_is_positive_inf(Numeric num)
+{
+	return NUMERIC_IS_PINF(num);
+}
+
+/*
+ * numeric_is_negative_inf() -
+ *
+ *	Is Numeric value negative infinity?
+ */
+bool
+numeric_is_negative_inf(Numeric num)
+{
+	return NUMERIC_IS_NINF(num);
+}
+
 /*
  * numeric_is_integral() -
  *
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 556ab057e5..b69ad29caf 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10119,6 +10119,9 @@ get_rule_expr(Node *node, deparse_context *context,
 					case IS_XMLSERIALIZE:
 						appendStringInfoString(buf, "XMLSERIALIZE(");
 						break;
+					case IS_XMLCAST:
+						appendStringInfoString(buf, "XMLCAST(");
+						break;
 					case IS_DOCUMENT:
 						break;
 				}
@@ -10129,7 +10132,7 @@ get_rule_expr(Node *node, deparse_context *context,
 					else
 						appendStringInfoString(buf, "CONTENT ");
 				}
-				if (xexpr->name)
+				if (xexpr->name && xexpr->op != IS_XMLCAST)
 				{
 					appendStringInfo(buf, "NAME %s",
 									 quote_identifier(map_xml_name_to_sql_identifier(xexpr->name)));
@@ -10165,6 +10168,7 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, ", ");
 					switch (xexpr->op)
 					{
+						case IS_XMLCAST:
 						case IS_XMLCONCAT:
 						case IS_XMLELEMENT:
 						case IS_XMLFOREST:
@@ -10242,6 +10246,10 @@ get_rule_expr(Node *node, deparse_context *context,
 						appendStringInfoString(buf, " NO INDENT");
 				}
 
+				if (xexpr->op == IS_XMLCAST)
+					appendStringInfo(buf, " AS %s",
+									 format_type_be(xexpr->targetType));
+
 				if (xexpr->op == IS_DOCUMENT)
 					appendStringInfoString(buf, " IS DOCUMENT");
 				else
diff --git a/src/backend/utils/adt/xml.c b/src/backend/utils/adt/xml.c
index 41e775570e..4285164891 100644
--- a/src/backend/utils/adt/xml.c
+++ b/src/backend/utils/adt/xml.c
@@ -99,6 +99,7 @@
 #include "utils/date.h"
 #include "utils/datetime.h"
 #include "utils/lsyscache.h"
+#include "utils/numeric.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/xml.h"
@@ -2574,9 +2575,9 @@ map_sql_value_to_xml_value(Datum value, Oid type, bool xml_escape_strings)
 		{
 			case BOOLOID:
 				if (DatumGetBool(value))
-					return "true";
+					return pstrdup("true");
 				else
-					return "false";
+					return pstrdup("false");
 
 			case DATEOID:
 				{
@@ -2706,8 +2707,60 @@ map_sql_value_to_xml_value(Datum value, Oid type, bool xml_escape_strings)
 				}
 #endif							/* USE_LIBXML */
 
-		}
+			case FLOAT4OID:
+				/*
+				 * Special handling for infinity values in floating-point and
+				 * numeric types. The XML Schema specification requires that
+				 * positive infinity be represented as "INF" and negative
+				 * infinity as "-INF" in XML documents for float and double
+				 * types. While decimal types in XML Schema do not support
+				 * infinity, PostgreSQL's NUMERIC type can represent it, so
+				 * we use the same representation for consistency.
+				 *
+				 * See: XML Schema Part 2: Datatypes Second Edition, sections
+				 * 3.2.4 (float) and 3.2.5 (double).
+				 */
+				{
+					float4		val = DatumGetFloat4(value);
+
+					if (isinf(val))
+					{
+						if (val < 0)
+							return pstrdup("-INF");
+						else
+							return pstrdup("INF");
+					}
+				}
+				break;
 
+			case FLOAT8OID:
+				{
+					float8		val = DatumGetFloat8(value);
+
+					if (isinf(val))
+					{
+						if (val < 0)
+							return pstrdup("-INF");
+						else
+							return pstrdup("INF");
+					}
+				}
+				break;
+
+			case NUMERICOID:
+				{
+					Numeric		num = DatumGetNumeric(value);
+
+					if (numeric_is_inf(num))
+					{
+						if (numeric_is_positive_inf(num))
+							return pstrdup("INF");
+						else
+							return pstrdup("-INF");
+					}
+				}
+				break;
+		}
 		/*
 		 * otherwise, just use the type's native text representation
 		 */
@@ -2762,6 +2815,67 @@ escape_xml(const char *str)
 	return buf.data;
 }
 
+/*
+ * Unescape XML escaped characters.
+ *
+ * In order to keep it consistent with "escape_xml(const char*)",
+ * this function intentionally does not depend on libxml2.
+ */
+char *
+unescape_xml(const char *str)
+{
+	StringInfoData buf;
+	size_t p = 0;
+	size_t len;
+
+	if (!str)
+		return NULL;
+
+	len = strlen(str);
+
+	initStringInfo(&buf);
+
+	while (p < len)
+	{
+		if (p + 4 <= len && strncmp(str + p, "&lt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '<');
+			p += 4;
+		}
+		else if (p + 4 <= len && strncmp(str + p, "&gt;", 4) == 0)
+		{
+			appendStringInfoChar(&buf, '>');
+			p += 4;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&amp;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '&');
+			p += 5;
+		}
+		else if (p + 5 <= len && strncmp(str + p, "&#13;", 5) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 5;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&quot;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '"');
+			p += 6;
+		}
+		else if (p + 6 <= len && strncmp(str + p, "&#x0D;", 6) == 0)
+		{
+			appendStringInfoChar(&buf, '\r');
+			p += 6;
+		}
+		else
+		{
+			appendStringInfoChar(&buf, *(str + p));
+			p++;
+		}
+	}
+
+	return buf.data;
+}
 
 static char *
 _SPI_strdup(const char *s)
@@ -4350,6 +4464,7 @@ xml_xpathobjtoxmlarray(xmlXPathObjectPtr xpathobj,
 	datum = PointerGetDatum(cstring_to_xmltype(result_str));
 	(void) accumArrayResult(astate, datum, false,
 							XMLOID, CurrentMemoryContext);
+	pfree(result_str);
 	return 1;
 }
 
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d14294a4ec..c9d097e097 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -877,6 +877,14 @@ typedef struct XmlSerialize
 	ParseLoc	location;		/* token location, or -1 if unknown */
 } XmlSerialize;
 
+typedef struct XmlCast
+{
+	NodeTag		type;
+	Node	   *expr;
+	TypeName   *targetType;
+	ParseLoc	location;		/* token location, or -1 if unknown */
+} XmlCast;
+
 /* Partitioning related definitions */
 
 /*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 1b4436f2ff..77c1be8ff0 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1602,6 +1602,7 @@ typedef struct SQLValueFunction
  */
 typedef enum XmlExprOp
 {
+	IS_XMLCAST,					/* XMLCAST(op AS datatype) */
 	IS_XMLCONCAT,				/* XMLCONCAT(args) */
 	IS_XMLELEMENT,				/* XMLELEMENT(name, xml_attributes, args) */
 	IS_XMLFOREST,				/* XMLFOREST(xml_attributes) */
@@ -1638,6 +1639,8 @@ typedef struct XmlExpr
 	/* target type/typmod for XMLSERIALIZE */
 	Oid			type pg_node_attr(query_jumble_ignore);
 	int32		typmod pg_node_attr(query_jumble_ignore);
+	/* option for XMLCAST */
+	Oid 		targetType;
 	/* token location, or -1 if unknown */
 	ParseLoc	location;
 } XmlExpr;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 5d4fe27ef9..42f98cb7b2 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -510,6 +510,7 @@ PG_KEYWORD("wrapper", WRAPPER, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("write", WRITE, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xml", XML_P, UNRESERVED_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlattributes", XMLATTRIBUTES, COL_NAME_KEYWORD, BARE_LABEL)
+PG_KEYWORD("xmlcast", XMLCAST, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlconcat", XMLCONCAT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlelement", XMLELEMENT, COL_NAME_KEYWORD, BARE_LABEL)
 PG_KEYWORD("xmlexists", XMLEXISTS, COL_NAME_KEYWORD, BARE_LABEL)
diff --git a/src/include/utils/numeric.h b/src/include/utils/numeric.h
index 215f1ea4f5..c57432507e 100644
--- a/src/include/utils/numeric.h
+++ b/src/include/utils/numeric.h
@@ -87,6 +87,8 @@ NumericGetDatum(Numeric X)
  */
 extern bool numeric_is_nan(Numeric num);
 extern bool numeric_is_inf(Numeric num);
+extern bool numeric_is_positive_inf(Numeric num);
+extern bool numeric_is_negative_inf(Numeric num);
 extern int32 numeric_maximum_size(int32 typmod);
 extern char *numeric_out_sci(Numeric num, int scale);
 extern char *numeric_normalize(Numeric num);
diff --git a/src/include/utils/xml.h b/src/include/utils/xml.h
index 732dac47bc..7be87e3671 100644
--- a/src/include/utils/xml.h
+++ b/src/include/utils/xml.h
@@ -80,6 +80,7 @@ extern bool xml_is_document(xmltype *arg);
 extern text *xmltotext_with_options(xmltype *data, XmlOptionType xmloption_arg,
 									bool indent);
 extern char *escape_xml(const char *str);
+extern char *unescape_xml(const char *str);
 
 extern char *map_sql_identifier_to_xml_name(const char *ident, bool fully_escaped, bool escape_period);
 extern char *map_xml_name_to_sql_identifier(const char *name);
diff --git a/src/test/regress/expected/xml.out b/src/test/regress/expected/xml.out
index 103a22a3b1..a5a56c5b74 100644
--- a/src/test/regress/expected/xml.out
+++ b/src/test/regress/expected/xml.out
@@ -1881,3 +1881,610 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof | xmlcast  | pg_typeof |  xmlcast  | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------+----------+-----------+-----------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric   | Infinity | numeric   | -Infinity | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     | xmlcast  |    pg_typeof     |  xmlcast  |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------+----------+------------------+-----------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision | Infinity | double precision | -Infinity | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910 AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/expected/xml_1.out b/src/test/regress/expected/xml_1.out
index 73c411118a..98b2a2878e 100644
--- a/src/test/regress/expected/xml_1.out
+++ b/src/test/regress/expected/xml_1.out
@@ -1496,3 +1496,456 @@ ERROR:  unsupported XML feature
 LINE 1: SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j':...
                              ^
 DETAIL:  This functionality requires the server to be built with libxml support.
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+ERROR:  unsupported XML feature
+LINE 3: '<?xml version="1.0" encoding="utf-8"?>
+        ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+(0 rows)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+(0 rows)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ERROR:  unsupported XML feature
+LINE 1: SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+ERROR:  unsupported XML feature
+LINE 1: SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&q...
+                                            ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ERROR:  unsupported XML feature
+DETAIL:  This functionality requires the server to be built with libxml support.
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text B...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY RE...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14':...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('12:30:45'::xml AS time without time zone) = xmlca...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('09:30:10+06:00'::xml AS time with time zone) = xm...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ERROR:  unsupported XML feature
+LINE 4:   xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 yea...
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+ERROR:  unsupported XML feature
+LINE 7:   xmlcast(''::xml AS text) AS c5,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_to_xml
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+SELECT * FROM view_xmlcast_to_xml;
+ERROR:  relation "view_xmlcast_to_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_to_xml;
+                      ^
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+ERROR:  unsupported XML feature
+LINE 3:   xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+                  ^
+DETAIL:  This functionality requires the server to be built with libxml support.
+\sv view_xmlcast_from_xml
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+SELECT * FROM view_xmlcast_from_xml;
+ERROR:  relation "view_xmlcast_from_xml" does not exist
+LINE 1: SELECT * FROM view_xmlcast_from_xml;
+                      ^
diff --git a/src/test/regress/expected/xml_2.out b/src/test/regress/expected/xml_2.out
index a85d95358d..5ec57ae5ef 100644
--- a/src/test/regress/expected/xml_2.out
+++ b/src/test/regress/expected/xml_2.out
@@ -1867,3 +1867,612 @@ SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
  x&lt;P&gt;73&lt;/P&gt;0.42truej
 (1 row)
 
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'text[]' at character 8
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+ERROR:  cannot cast from 'xml' to 'integer[]' at character 8
+SELECT xmlcast(NULL AS text);
+ERROR:  cannot cast from 'unknown' to 'text' at character 8
+SELECT xmlcast('foo'::text AS varchar);
+ERROR:  cannot cast from 'text' to 'character varying' at character 8
+SELECT xmlcast(42 AS text);
+ERROR:  cannot cast from 'integer' to 'text' at character 8
+SELECT xmlcast(array['foo','bar'] AS xml);
+ERROR:  cannot cast from 'text[]' to 'xml' at character 8
+\set VERBOSITY default
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+  xmlcast   | pg_typeof |  xmlcast   | pg_typeof 
+------------+-----------+------------+-----------
+ 09-24-2002 | date      | 09-24-2002 | date
+(1 row)
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+                   xmlcast                    | pg_typeof |                   xmlcast                    | pg_typeof 
+----------------------------------------------+-----------+----------------------------------------------+-----------
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval  | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | interval
+(1 row)
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+  xmlcast   |       pg_typeof        |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      |   xmlcast   |      pg_typeof      
+------------+------------------------+-------------+---------------------+-------------+---------------------+-------------+---------------------
+ 09:30:10.5 | time without time zone | 09:30:10+00 | time with time zone | 09:30:10-06 | time with time zone | 09:30:10+06 | time with time zone
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | text      |        foo bar      | text      | foo & <"bar"> | text
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+ xmlcast |     pg_typeof     |       xmlcast       |     pg_typeof     |    xmlcast    |     pg_typeof     
+---------+-------------------+---------------------+-------------------+---------------+-------------------
+ foo bar | character varying |        foo bar      | character varying | foo & <"bar"> | character varying
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | name      |        foo bar      | name      | foo & <"bar"> | name
+(1 row)
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |    xmlcast    | pg_typeof 
+---------+-----------+---------------------+-----------+---------------+-----------
+ foo bar | character |        foo bar      | character | foo & <"bar"> | character
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof | xmlcast  | pg_typeof |  xmlcast  | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------+----------+-----------+-----------+-----------
+ 42.7312345678910 | numeric   | 42.7312345678910 | numeric   | -42.7312345678910 | numeric   | Infinity | numeric   | -Infinity | numeric
+(1 row)
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+     xmlcast     |    pg_typeof     |     xmlcast     |    pg_typeof     |     xmlcast      |    pg_typeof     | xmlcast  |    pg_typeof     |  xmlcast  |    pg_typeof     
+-----------------+------------------+-----------------+------------------+------------------+------------------+----------+------------------+-----------+------------------
+ 42.731234567891 | double precision | 42.731234567891 | double precision | -42.731234567891 | double precision | Infinity | double precision | -Infinity | double precision
+(1 row)
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------+---------+-----------
+      42 | integer   |      42 | integer   |     -42 | integer
+(1 row)
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+     xmlcast      | pg_typeof |     xmlcast      | pg_typeof |      xmlcast      | pg_typeof 
+------------------+-----------+------------------+-----------+-------------------+-----------
+ 4273535420162021 | bigint    | 4273535420162021 | bigint    | -4273535420162021 | bigint
+(1 row)
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof | xmlcast | pg_typeof 
+---------+-----------+---------+-----------
+ t       | boolean   | f       | boolean
+(1 row)
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof 
+---------+-----------
+         | text
+(1 row)
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+ xmlcast | pg_typeof |       xmlcast       | pg_typeof |         xmlcast         | pg_typeof 
+---------+-----------+---------------------+-----------+-------------------------+-----------
+ foo bar | xml       |        foo bar      | xml       | foo &amp; &lt;"bar"&gt; | xml
+(1 row)
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ foo | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+ j | pg_typeof 
+---+-----------
+   | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+ j | pg_typeof 
+---+-----------
+   | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+                 j                 | pg_typeof 
+-----------------------------------+-----------
+ foo &amp; &lt;&quot;bar&quot;&gt; | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+        j        | pg_typeof 
+-----------------+-----------
+ foo & <"bar">\r | text
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 2024-05-29 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+             j              | pg_typeof 
+----------------------------+-----------
+ 2024-05-29T12:04:10.703585 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+       j        | pg_typeof 
+----------------+-----------
+ P1Y2M3DT4H5M6S | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+     j     | pg_typeof 
+-----------+-----------
+ 427353542 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+        j         | pg_typeof 
+------------------+-----------
+ 4273535420162021 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+         j          | pg_typeof 
+--------------------+-----------
+ 42.007312345678910 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+         j         | pg_typeof 
+-------------------+-----------
+ 42.00731234567891 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ -INF | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+  j  | pg_typeof 
+-----+-----------
+ NaN | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+   j   | pg_typeof 
+-------+-----------
+ false | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+  j   | pg_typeof 
+------+-----------
+ true | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+     j      | pg_typeof 
+------------+-----------
+ 11:11:11.5 | xml
+(1 row)
+
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+       j       | pg_typeof 
+---------------+-----------
+ 20:11:11.5+01 | xml
+(1 row)
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+   xmlcast   
+-------------
+ <"foo&bar">
+(1 row)
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ DEADBEEF
+(1 row)
+
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+ xmlcast  
+----------
+ 3q2+7w==
+(1 row)
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+ ?column? | ?column? | ?column? | ?column? 
+----------+----------+----------+----------
+ t        | t        | t        | t
+(1 row)
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+\sv view_xmlcast_to_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_to_xml AS
+ SELECT XMLCAST(NULL::text AS xml)::xml AS c1,
+    XMLCAST('foo'::text AS xml)::xml AS c2,
+    XMLCAST(''::text AS xml)::xml AS c3,
+    XMLCAST(NULL::text AS xml)::xml AS c4,
+    XMLCAST(''::xml AS text)::text AS c5,
+    XMLCAST(NULL::xml AS text)::text AS c6,
+    XMLCAST('foo & <"bar">'::text AS xml)::xml AS c7,
+    XMLCAST('foo & <"bar">'::character varying AS xml)::xml AS c8,
+    XMLCAST('foo & <"bar">'::name::text AS xml)::xml AS c9,
+    XMLCAST(xmltext('foo & <"bar">
+'::text) AS text)::text AS c10,
+    XMLCAST(XMLCAST('foo & <"bar">
+'::text AS xml)::xml AS text)::text AS c11,
+    XMLCAST(to_date('29/05/2024'::text, 'dd/mm/yyyy'::text) AS xml)::xml AS c12,
+    XMLCAST(('Wed May 29 03:04:10.703585 2024 PDT'::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS xml)::xml AS c13,
+    XMLCAST('Wed May 29 12:04:10.703585 2024'::timestamp without time zone AS xml)::xml AS c14,
+    XMLCAST('@ 1 year 2 mons 3 days 4 hours 5 mins 6 secs'::interval AS xml)::xml AS c15,
+    XMLCAST(427353542::text AS xml)::xml AS c16,
+    XMLCAST('4273535420162021'::bigint::text AS xml)::xml AS c17,
+    XMLCAST(42.007312345678910 AS xml)::xml AS c18,
+    XMLCAST(42.007312345678910::double precision AS xml)::xml AS c19,
+    XMLCAST(true AS xml)::xml AS c20,
+    XMLCAST(false AS xml)::xml AS c21,
+    XMLCAST(42 = 73 AS xml)::xml AS c22,
+    XMLCAST(42 <> 73 AS xml)::xml AS c23,
+    XMLCAST('11:11:11.5'::time without time zone::text AS xml)::xml AS c24,
+    XMLCAST(('11:11:11.5-08'::time with time zone AT TIME ZONE 'Europe/Berlin'::text)::text AS xml)::xml AS c25
+SELECT * FROM view_xmlcast_to_xml;
+ c1 | c2  | c3 | c4 | c5 | c6 |                c7                 |                c8                 |                c9                 |       c10       |       c11       |    c12     |            c13             |            c14             |      c15       |    c16    |       c17        |        c18         |        c19        | c20  |  c21  |  c22  | c23  |    c24     |      c25      
+----+-----+----+----+----+----+-----------------------------------+-----------------------------------+-----------------------------------+-----------------+-----------------+------------+----------------------------+----------------------------+----------------+-----------+------------------+--------------------+-------------------+------+-------+-------+------+------------+---------------
+    | foo |    |    |    |    | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo &amp; &lt;&quot;bar&quot;&gt; | foo & <"bar">\r | foo & <"bar">\r | 2024-05-29 | 2024-05-29T12:04:10.703585 | 2024-05-29T12:04:10.703585 | P1Y2M3DT4H5M6S | 427353542 | 4273535420162021 | 42.007312345678910 | 42.00731234567891 | true | false | false | true | 11:11:11.5 | 20:11:11.5+01
+(1 row)
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+\sv view_xmlcast_from_xml
+CREATE OR REPLACE VIEW public.view_xmlcast_from_xml AS
+ SELECT XMLCAST('P1Y2M3DT4H5M6S'::xml AS interval)::interval AS c1,
+    XMLCAST('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval)::interval AS c2,
+    XMLCAST('2002-09-24'::xml AS date)::date AS c3,
+    XMLCAST('2002-09-24+06:00'::xml AS date)::date AS c4,
+    (XMLCAST('09:30:10Z'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c5,
+    (XMLCAST('09:30:10-06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c6,
+    (XMLCAST('09:30:10+06:00'::xml AS time with time zone)::time with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c7,
+    (XMLCAST('2002-05-30T09:30:10Z'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c8,
+    (XMLCAST('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c9,
+    (XMLCAST('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone)::timestamp with time zone AT TIME ZONE 'Europe/Berlin'::text) AS c10,
+    XMLCAST('foo bar'::xml AS text)::text AS c11,
+    XMLCAST('       foo bar     '::xml AS character varying)::character varying AS c12,
+    XMLCAST('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text)::text AS c13,
+    XMLCAST('42.7312345678910'::xml AS numeric)::numeric AS c14,
+    XMLCAST('+42.7312345678910'::xml AS numeric)::numeric AS c15,
+    XMLCAST('-42.7312345678910'::xml AS numeric)::numeric AS c16,
+    XMLCAST('42'::xml AS integer)::integer AS c17,
+    XMLCAST('+42'::xml AS integer)::integer AS c18,
+    XMLCAST('-42'::xml AS integer)::integer AS c19,
+    XMLCAST('4273535420162021'::xml AS bigint)::bigint AS c20,
+    XMLCAST('+4273535420162021'::xml AS bigint)::bigint AS c21,
+    XMLCAST('-4273535420162021'::xml AS bigint)::bigint AS c22,
+    XMLCAST('true'::xml AS boolean)::boolean AS c23,
+    XMLCAST('false'::xml AS boolean)::boolean AS c24,
+    XMLCAST(''::xml AS character varying)::character varying AS c25,
+    XMLCAST(NULL::xml AS character varying)::character varying AS c26
+SELECT * FROM view_xmlcast_from_xml;
+                      c1                      |                      c2                      |     c3     |     c4     |     c5      |     c6      |     c7      |            c8            |            c9            |           c10            |   c11   |         c12         |      c13      |       c14        |       c15        |        c16        | c17 | c18 | c19 |       c20        |       c21        |        c22        | c23 | c24 | c25 | c26 
+----------------------------------------------+----------------------------------------------+------------+------------+-------------+-------------+-------------+--------------------------+--------------------------+--------------------------+---------+---------------------+---------------+------------------+------------------+-------------------+-----+-----+-----+------------------+------------------+-------------------+-----+-----+-----+-----
+ @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | @ 1 year 2 mons 3 days 4 hours 5 mins 6 secs | 09-24-2002 | 09-24-2002 | 10:30:10+01 | 16:30:10+01 | 04:30:10+01 | Thu May 30 11:30:10 2002 | Thu May 30 17:30:10 2002 | Thu May 30 05:30:10 2002 | foo bar |        foo bar      | foo & <"bar"> | 42.7312345678910 | 42.7312345678910 | -42.7312345678910 |  42 |  42 | -42 | 4273535420162021 | 4273535420162021 | -4273535420162021 | t   | f   |     | 
+(1 row)
+
diff --git a/src/test/regress/sql/xml.sql b/src/test/regress/sql/xml.sql
index 0ea4f50883..648751d212 100644
--- a/src/test/regress/sql/xml.sql
+++ b/src/test/regress/sql/xml.sql
@@ -679,3 +679,293 @@ SELECT xmltext('  ');
 SELECT xmltext('foo `$_-+?=*^%!|/\()[]{}');
 SELECT xmltext('foo & <"bar">');
 SELECT xmltext('x'|| '<P>73</P>'::xml || .42 || true || 'j'::char);
+
+-- for xmlcast() tests
+INSERT INTO xmltest
+ VALUES (42,
+'<?xml version="1.0" encoding="utf-8"?>
+ <xmlcast>
+  <period1>P1Y2M3DT4H5M6S</period1>
+  <period2>1 year 2 mons 3 days 4 hours 5 minutes 6 seconds</period2>
+  <date1>2002-09-24</date1>
+  <date2>2002-09-24+06:00</date2>
+  <time>09:30:10.5</time>
+  <time_tz1>09:30:10Z</time_tz1>
+  <time_tz2>09:30:10-06:00</time_tz2>
+  <time_tz3>09:30:10+06:00</time_tz3>
+  <timestamp1>2002-05-30T09:00:00</timestamp1>
+  <timestamp2>2002-05-30T09:30:10.5</timestamp2>
+  <timestamp_tz1>2002-05-30T09:30:10Z</timestamp_tz1>
+  <timestamp_tz2>2002-05-30T09:30:10-06:00</timestamp_tz2>
+  <timestamp_tz3>2002-05-30T09:30:10+06:00</timestamp_tz3>
+  <text1>foo bar</text1>
+  <text2>       foo bar     </text2>
+  <text3>foo &amp; &lt;&quot;bar&quot;&gt;</text3>
+  <decimal1>42.7312345678910</decimal1>
+  <decimal2>+42.7312345678910</decimal2>
+  <decimal3>-42.7312345678910</decimal3>
+  <decimal4>INF</decimal4>
+  <decimal5>-INF</decimal5>
+  <integer1>42</integer1>
+  <integer2>+42</integer2>
+  <integer3>-42</integer3>
+  <long1>4273535420162021</long1>
+  <long2>+4273535420162021</long2>
+  <long3>-4273535420162021</long3>
+  <bool1 att="true">42</bool1>
+  <bool2 att="false">73</bool2>
+  <empty></empty>
+ </xmlcast>'::xml
+);
+
+-- This prevents the xmlcast regression tests from failing if the system's timezone has been changed.
+SET timezone TO 'America/Los_Angeles';
+
+-- xmlcast exceptions
+\set VERBOSITY terse
+SELECT xmlcast((xpath('//text1/text()', data))[1] AS text[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast((xpath('//text1/integer1()', data))[1] AS int[]) FROM xmltest WHERE id = 42;
+SELECT xmlcast(NULL AS text);
+SELECT xmlcast('foo'::text AS varchar);
+SELECT xmlcast(42 AS text);
+SELECT xmlcast(array['foo','bar'] AS xml);
+\set VERBOSITY default
+
+-- xmlcast tests for "XML to non-XML" expressions
+SELECT
+  xmlcast((xpath('//date1/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date1/text()', data))[1] AS date)),
+  xmlcast((xpath('//date2/text()', data))[1] AS date), pg_typeof(xmlcast((xpath('//date2/text()', data))[1] AS date))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//period1/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period1/text()', data))[1] AS interval)),
+  xmlcast((xpath('//period2/text()', data))[1] AS interval), pg_typeof(xmlcast((xpath('//period2/text()', data))[1] AS interval))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//time/text()', data))[1] AS time), pg_typeof(xmlcast((xpath('//time/text()', data))[1] AS time)),
+  xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz1/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz2/text()', data))[1] AS time with time zone)),
+  xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone), pg_typeof(xmlcast((xpath('//time_tz3/text()', data))[1] AS time with time zone))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS text)),
+  xmlcast((xpath('//text2/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS text)),
+  xmlcast((xpath('//text3/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS varchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS varchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS varchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS name)),
+  xmlcast((xpath('//text2/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS name)),
+  xmlcast((xpath('//text3/text()', data))[1] AS name), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS name))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text2/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS bpchar)),
+  xmlcast((xpath('//text3/text()', data))[1] AS bpchar), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS bpchar))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS numeric)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS numeric), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS numeric))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//decimal1/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal1/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal2/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal2/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal3/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal3/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal4/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal4/text()', data))[1] AS double precision)),
+  xmlcast((xpath('//decimal5/text()', data))[1] AS double precision), pg_typeof(xmlcast((xpath('//decimal5/text()', data))[1] AS double precision))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//integer1/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer1/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer2/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer2/text()', data))[1] AS int)),
+  xmlcast((xpath('//integer3/text()', data))[1] AS int), pg_typeof(xmlcast((xpath('//integer3/text()', data))[1] AS int))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//long1/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long1/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long2/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long2/text()', data))[1] AS bigint)),
+  xmlcast((xpath('//long3/text()', data))[1] AS bigint), pg_typeof(xmlcast((xpath('//long3/text()', data))[1] AS bigint))
+FROM xmltest WHERE id = 42;
+
+SELECT
+  xmlcast((xpath('//bool1/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean)),
+  xmlcast((xpath('//bool2/@att', data))[1] AS boolean), pg_typeof(xmlcast((xpath('//bool1/@att', data))[1] AS boolean))
+FROM xmltest WHERE id = 42;
+
+SELECT xmlcast((xpath('//empty/text()', data))[1] AS text), pg_typeof(xmlcast((xpath('//empty/text()', data))[1] AS text))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "XML to XML" expressions
+SELECT
+  xmlcast((xpath('//text1/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text1/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text2/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text2/text()', data))[1] AS xml)),
+  xmlcast((xpath('//text3/text()', data))[1] AS xml), pg_typeof(xmlcast((xpath('//text3/text()', data))[1] AS xml))
+FROM xmltest WHERE id = 42;
+
+-- xmlcast tests for "non-XML to XML" expressions
+SELECT j, pg_typeof(j) FROM xmlcast(NULL AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(''::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(NULL::xml AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::text AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::varchar AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('foo & <"bar">'::name AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmltext(E'foo & <"bar">\r') AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(427353542 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(4273535420162021 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42.007312345678910::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::double precision AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('infinity'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('-infinity'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('nan'::numeric AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(true AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(false AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 = 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast(42 <> 73 AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time AS xml) t(j);
+SELECT j, pg_typeof(j) FROM xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) t(j);
+
+-- Convert an XML string to bytea and back to xml
+SELECT xmlcast(convert_from(xmlcast('&lt;&quot;foo&amp;bar&quot;&gt;'::xml AS bytea),'UTF8')::xml AS text);
+
+SET xmlbinary TO hex;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+SET xmlbinary TO base64;
+SELECT xmlcast(E'\\xDEADBEEF'::bytea AS xml);
+
+-- The BY REF and BY VALUE clauses are accepted but ignored.
+-- This checks if the results are indeed the same as without the clauses.
+SELECT
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY REF)::text,
+  xmlcast('foo' AS xml)::text = xmlcast('foo' AS xml BY VALUE)::text,
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY REF),
+  xmlcast('foo'::xml AS text) = xmlcast('foo'::xml AS text BY VALUE);
+
+SELECT
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY REF)::text,
+  xmlcast(42 AS xml)::text = xmlcast(42 AS xml BY VALUE)::text,
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY REF),
+  xmlcast('42'::xml AS int) = xmlcast('42'::xml AS int BY VALUE);
+
+SELECT
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY REF)::text,
+  xmlcast(42.73 AS xml)::text = xmlcast(42.73 AS xml BY VALUE)::text,
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY REF),
+  xmlcast('42.73'::xml AS numeric) = xmlcast('42.73'::xml AS numeric BY VALUE);
+
+SELECT
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY REF)::text,
+  xmlcast('2024-08-14'::date AS xml)::text = xmlcast('2024-08-14'::date AS xml BY VALUE)::text,
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY REF),
+  xmlcast('2024-08-14'::xml AS date) = xmlcast('2024-08-14'::xml AS date BY VALUE);
+
+SELECT
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY REF)::text,
+  xmlcast('12:30:45'::time without time zone AS xml)::text = xmlcast('12:30:45'::time without time zone AS xml BY VALUE)::text,
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY REF),
+  xmlcast('12:30:45'::xml AS time without time zone) = xmlcast('12:30:45'::xml AS time without time zone BY VALUE);
+
+SELECT
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY REF)::text,
+  xmlcast('09:30:10+06:00'::time with time zone AS xml)::text = xmlcast('09:30:10+06:00'::time with time zone AS xml BY VALUE)::text,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY REF),
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) = xmlcast('09:30:10+06:00'::xml AS time with time zone BY VALUE);
+
+SELECT
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY REF)::text,
+  xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml)::text = xmlcast('2002-05-30 09:30:10+06:00'::timestamp with time zone AS xml BY VALUE)::text,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY REF),
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) = xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone BY VALUE);
+
+SELECT
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY REF)::text,
+  xmlcast('1 year 2 mons'::interval AS xml)::text = xmlcast('1 year 2 mons'::interval AS xml BY VALUE)::text,
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY REF),
+  xmlcast('1 year 2 mons'::xml AS interval) = xmlcast('1 year 2 mons'::xml AS interval BY VALUE);
+
+CREATE VIEW view_xmlcast_to_xml AS
+SELECT
+  xmlcast(NULL AS xml) AS c1,
+  xmlcast('foo' AS xml) AS c2,
+  xmlcast(''::text AS xml) AS c3,
+  xmlcast(NULL::text AS xml) AS c4,
+  xmlcast(''::xml AS text) AS c5,
+  xmlcast(NULL::xml AS text) c6,
+  xmlcast('foo & <"bar">'::text AS xml) AS c7,
+  xmlcast('foo & <"bar">'::varchar AS xml) AS c8,
+  xmlcast('foo & <"bar">'::name AS xml) AS c9,
+  xmlcast(xmltext(E'foo & <"bar">\r') AS text) AS c10,
+  xmlcast(xmlcast(E'foo & <"bar">\r' AS xml) AS text) AS c11,
+  xmlcast(to_date('29/05/2024','dd/mm/yyyy') AS xml) AS c12,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp with time zone at time zone 'Europe/Berlin' AS xml) AS c13,
+  xmlcast('2024-05-29 12:04:10.703585+02'::timestamp without time zone AS xml) AS c14,
+  xmlcast('1 year 2 months 3 days 4 hours 5 minutes 6 seconds'::interval AS xml) AS c15,
+  xmlcast(427353542 AS xml) AS c16,
+  xmlcast(4273535420162021 AS xml) AS c17,
+  xmlcast(42.007312345678910 AS xml) AS c18,
+  xmlcast(42.007312345678910::double precision AS xml) AS c19,
+  xmlcast(true AS xml) AS c20,
+  xmlcast(false AS xml) AS c21,
+  xmlcast(42 = 73 AS xml) AS c22,
+  xmlcast(42 <> 73 AS xml) AS c23,
+  xmlcast('11:11:11.5'::time AS xml) AS c24,
+  xmlcast('11:11:11.5'::time with time zone at time zone 'Europe/Berlin' AS xml) AS c25;
+
+\sv view_xmlcast_to_xml
+SELECT * FROM view_xmlcast_to_xml;
+
+CREATE VIEW view_xmlcast_from_xml AS
+SELECT
+  xmlcast('P1Y2M3DT4H5M6S'::xml AS interval) AS c1,
+  xmlcast('1 year 2 mons 3 days 4 hours 5 minutes 6 seconds'::xml AS interval) AS c2,
+  xmlcast('2002-09-24'::xml AS date) AS c3,
+  xmlcast('2002-09-24+06:00'::xml AS date) AS c4,
+  xmlcast('09:30:10Z'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c5,
+  xmlcast('09:30:10-06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c6,
+  xmlcast('09:30:10+06:00'::xml AS time with time zone) at time zone 'Europe/Berlin' AS c7,
+  xmlcast('2002-05-30T09:30:10Z'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c8,
+  xmlcast('2002-05-30T09:30:10-06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c9,
+  xmlcast('2002-05-30T09:30:10+06:00'::xml AS timestamp with time zone) at time zone 'Europe/Berlin' AS c10,
+  xmlcast('foo bar'::xml AS text) AS c11,
+  xmlcast('       foo bar     '::xml AS varchar) AS c12,
+  xmlcast('foo &amp; &lt;&quot;bar&quot;&gt;'::xml AS text) AS c13,
+  xmlcast('42.7312345678910'::xml AS numeric) AS c14,
+  xmlcast('+42.7312345678910'::xml AS numeric) AS c15,
+  xmlcast('-42.7312345678910'::xml AS numeric) AS c16,
+  xmlcast('42'::xml AS integer) AS c17,
+  xmlcast('+42'::xml AS integer) AS c18,
+  xmlcast('-42'::xml AS integer) AS c19,
+  xmlcast('4273535420162021'::xml AS bigint) AS c20,
+  xmlcast('+4273535420162021'::xml AS bigint) AS c21,
+  xmlcast('-4273535420162021'::xml AS bigint) AS c22,
+  xmlcast('true'::xml AS boolean) AS c23,
+  xmlcast('false'::xml AS boolean) AS c24,
+  xmlcast(''::xml AS character varying) AS c25,
+  xmlcast(NULL::xml AS character varying) AS c26;
+
+\sv view_xmlcast_from_xml
+SELECT * FROM view_xmlcast_from_xml;
\ No newline at end of file
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index e3c3523b5b..a33bda3416 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3400,6 +3400,7 @@ XidStatus
 XmlExpr
 XmlExprOp
 XmlOptionType
+XmlCast
 XmlSerialize
 XmlTableBuilderData
 YYLTYPE
-- 
2.43.0