Nested FOR XML results with SQL Server’s PATH mode

Nested FOR XML results with SQL Server’s PATH mode

Today, while doing some work on a highly data (not object) driven .NET application, I needed a query output as XML from the application’s SQL Server 2005 database. I wanted:

  • Nicely formatted and properly mapped XML (e.g. no <row> elements as found in FOR XML RAW mode)
  • To be able to easily map columns to XML elements and attributes
  • A single root node, so I can load it into an XmlDocument without having to create the root node myself
  • Nested child elements
  • Not to have to turn my elegant little query into a huge mess of esoteric T-SQL (as with [Explicit!1!Mode])

I discovered that all this is surprisingly easy to achieve all of these things with SQL Server 2005′s FOR XML PATH mode. (I say surprising, because I’ve tried this sort of thing with FOR XML AUTO a few times before under SQL Server 2000, and gave up each time).

Here’s a quick example I’ve created using the venerable AdventureWorks example database, with comments against all the important bits:

SELECT        -- Map columns to XML attributes/elements with XPath selectors.        category.ProductCategoryID AS '@id',        category.Name AS '@name',        (                -- Use a sub query for child elements.                SELECT                        ProductID AS '@id',                        Name AS '@name',                        ListPrice AS '@price'                FROM                        SalesLT.Product                WHERE                        ProductCategoryID = category.ProductCategoryID                FOR                        XML PATH('product'), -- The element name for each row.                        TYPE -- Column is typed so it nests as XML, not text.                                ) AS 'products' -- The root element name for this child collection.FROM        SalesLT.ProductCategory categoryFOR        XML PATH('category'), -- The element name for each row.        ROOT('categories') -- The root element name for this result set.

As you can see, we’ve mapped columns to attributes/elements with XPath selectors, and set row and root element names with PATH() and ROOT() respectively.

Plus, by specifying my own names for everything, I was also able to address the difference in capitalization, prefixing and pluralization style between the AdventureWorks’ database table names and common XML.

Running this query produces output in the following format. Note the root nodes for both outer and child collections:

<categories>  <category id="4" name="Accessories" />  <category id="24" name="Gloves">    <products>      <product id="858" name="Half-Finger Gloves, S" price="24.4900" />      <product id="859" name="Half-Finger Gloves, M" price="24.4900" />      <product id="860" name="Half-Finger Gloves, L" price="24.4900" />      <product id="861" name="Full-Finger Gloves, S" price="37.9900" />      <product id="862" name="Full-Finger Gloves, M" price="37.9900" />      <product id="863" name="Full-Finger Gloves, L" price="37.9900" />    </products>  </category>  <category id="35" name="Helmets">    <products>      <product id="707" name="Sport-100 Helmet, Red" price="34.9900" />      <product id="708" name="Sport-100 Helmet, Black" price="34.9900" />      <product id="711" name="Sport-100 Helmet, Blue" price="34.9900" />    </products>  </category></categories>

You can read more about using FOR XML PATH here.

August 26, 2008

Related Posts