query() Method (xml Data Type)

Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance

Specifies an XQuery against an instance of the xml data type. The result is of xml type. The method returns an instance of untyped XML.

Syntax

query ('XQuery')  

Note

To view Transact-SQL syntax for SQL Server 2014 (12.x) and earlier versions, see Previous versions documentation.

Arguments

XQuery
Is a string, an XQuery expression, that queries for XML nodes, such as elements and attributes, in an XML instance.

Examples

This section provides examples of using the query() method of the xml data type.

A. Using the query() method against an xml type variable

The following example declares a variable @myDoc of xml type and assigns an XML instance to it. The query() method is then used to specify an XQuery against the document.

The query retrieves the <Features> child element of the <ProductDescription> element:

DECLARE @myDoc XML  
SET @myDoc = '<Root>  
<ProductDescription ProductID="1" ProductName="Road Bike">  
<Features>  
  <Warranty>1 year parts and labor</Warranty>  
  <Maintenance>3 year parts and labor extended maintenance is available</Maintenance>  
</Features>  
</ProductDescription>  
</Root>'  
SELECT @myDoc.query('/Root/ProductDescription/Features')  

The following output shows the result:

<Features>  
  <Warranty>1 year parts and labor</Warranty>  
  <Maintenance>3 year parts and labor extended maintenance is available</Maintenance>  
</Features>        

B. Using the query() method against an XML type column

In the following example, the query() method is used to specify an XQuery against the CatalogDescription column of xml type in the AdventureWorks database:

SELECT CatalogDescription.query('  
declare namespace PD="https://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription";  
<Product ProductModelID="{ /PD:ProductDescription[1]/@ProductModelID }" />  
') as Result  
FROM Production.ProductModel  
where CatalogDescription.exist('  
declare namespace PD="https://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription";  
declare namespace wm="https://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelWarrAndMain";  
     /PD:ProductDescription/PD:Features/wm:Warranty ') = 1  

Note the following items from the previous query:

  • The CatalogDescription column is a typed xml column, which means it has a schema collection associated with it. In the XQuery Prolog, the namespace keyword defines the prefix that's later used in the query body.

  • The query() method constructs XML, a <Product> element that has a ProductModelID attribute, in which the ProductModelID attribute value is retrieved from the database. For more information about XML construction, see XML Construction (XQuery).

  • The exist() method (XML data type) in the WHERE clause finds only rows that contain the <Warranty> element in the XML. Again, the namespace keyword defines two namespace prefixes.

The following output shows the partial result:

<Product ProductModelID="19"/>   
<Product ProductModelID="23"/>   
...  

Note the query() and exist() methods both declare the PD prefix. In these cases, you can use WITH XMLNAMESPACES to first define the prefixes and use it in the query.

WITH XMLNAMESPACES 
(  
   'https://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription' AS PD,  
   'https://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelWarrAndMain' AS WM
)  
SELECT CatalogDescription.query('<Product ProductModelID="{ /PD:ProductDescription[1]/@ProductModelID }" />')
       AS Result  
FROM Production.ProductModel  
WHERE CatalogDescription.exist('/PD:ProductDescription/PD:Features/WM:Warranty ') = 1;

See Also

Add Namespaces to Queries with WITH XMLNAMESPACES
Compare Typed XML to Untyped XML
Create Instances of XML Data
xml Data Type Methods
XML Data Modification Language (XML DML)