Skip to content

shannonlowder.com

Menu
  • About
  • Biml Interrogator Demo
  • Latest Posts
Menu

SQL301-Nesting For XML Queries

Posted on February 23, 2011July 6, 2011 by slowder
Don't mess with their nest!
Don't mess with their nest!

Given the 4 options I’ve shown you for creating XML output from SQL, you should be able to create nearly any structure you’d want (especially considering FOR XML EXPLICIT).  But you may actually c0me across a scenario where you can’t pull off what you want in a single query.

When  you can’t make a single query return the results you want, you can always nest one FOR XML query within another. This goes back to the basics of building one related sub query within an outer query.  The difference here is the output is an XML fragment rather than a data grid.  Let’s look at a simple example of this situation.

Let’s say you want to create xml representing customers and their orders.  For each customer element you want three attributes, name, account number, and type.  For each of their orders you want the order ID and order date (from Sales.SalesOrderHeader).  Finally, for each order you want the product name and quantity ordered.

Let’s get started, as usual, I’m working in my 2008R2 instance of SQL Server.

   1: USE Adventureworks

   2: go

   3: SELECT

   4:     contact.FirstName + ' ' + contact.LastName AS "@Name"

   5:     ,customer.AccountNumber AS "@AccountNumber"

   6:     ,customer.CustomerType AS "@Type"

   7:     ,(

   8:         SELECT

   9:             soh.SalesOrderID AS "@Id"

  10:             ,soh.OrderDate AS "@OrderDate"

  11:             ,(

  12:                 SELECT

  13:                     p.Name AS "@ProductName"

  14:                     ,sod.OrderQty AS "@Quantity"

  15:                 FROM Sales.SalesOrderDetail AS sod

  16:                 INNER JOIN Production.Product p

  17:                     ON sod.ProductID = p.ProductID

  18:                 WHERE sod.SalesOrderID = soh.SalesOrderID

  19:                 FOR XML PATH('OrderDetail'), TYPE

  20:             )

  21:         FROM Sales.SalesOrderHeader AS soh

  22:         WHERE soh.CustomerID = customer.CustomerID

  23:         FOR XML PATH('Order'), TYPE

  24:     ) AS "Orders"

  25: FROM Sales.Customer AS customer

  26: INNER JOIN Person.Contact AS contact

  27:     on customer.CustomerID = contact.ContactID

  28: WHERE customer.CustomerID = 1

  29: FOR XML PATH('Customer');

I start out my query by getting the customer name, account number and customer type from the Sales.Customer table, joined to the Person.ContactID where the customerID matches ContactID.

I then move to my first related sub query.  I query sales order ID and order date from the Sales.SalesOrderHeader table, I relate the results of this query to the outer query where SalesOrderHeader.CustomerID matches the Customer.CustomerID.  Then in my inner most, and last query, I get the product Name and order quantity from the Sales.SalesOrderDetail table Joined to the Production.Product table on productID.

I then join the inner most query to the sub query just before it by relating the SalesOrderID from the Sales.SalesOrderDetail table to the SalesOrderID from the Sales.SalesOrderHeader table.

This gives us the following result on my server.

   1: <Customer Name="Gustavo Achong" AccountNumber="AW00000001" Type="S">

   2:   <Orders>

   3:     <Order Id="43860" OrderDate="2001-08-01T00:00:00">

   4:       <OrderDetail ProductName="Road-650 Red, 62" Quantity="2" />

   5:       <OrderDetail ProductName="Road-650 Black, 52" Quantity="1" />

   6:     </Order>

   7:     <Order Id="44501" OrderDate="2001-11-01T00:00:00">

   8:       <OrderDetail ProductName="Road-650 Red, 62" Quantity="1" />

   9:     </Order>

  10:   </Orders>

  11: </Customer>

You may get different results, but they will be in the same format.

Just like normal queries you should be careful when using sub queries.  If you use them in the wrong place, you could have  a significantly higher costing query.  Keep an eye on the execution plans for your queries, and you’ll be ok.

So, any questions?  It makes sense right?  Building on the ideas of sub queries and throwing on the FOR XML PATH option?  Let me know if you have any questions.  I’ll do my best to explain!

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Recent Posts

  • A New File Interrogator
  • Using Generative AI in Data Engineering
  • Getting started with Microsoft Fabric
  • Docker-based Spark
  • Network Infrastructure Updates

Recent Comments

  1. slowder on Data Engineering for Databricks
  2. Alex Ott on Data Engineering for Databricks

Archives

  • July 2023
  • June 2023
  • March 2023
  • February 2023
  • January 2023
  • December 2022
  • November 2022
  • October 2022
  • October 2018
  • August 2018
  • May 2018
  • February 2018
  • January 2018
  • November 2017
  • October 2017
  • September 2017
  • August 2017
  • June 2017
  • March 2017
  • February 2014
  • January 2014
  • December 2013
  • November 2013
  • October 2013
  • August 2013
  • July 2013
  • June 2013
  • February 2013
  • January 2013
  • August 2012
  • June 2012
  • May 2012
  • April 2012
  • March 2012
  • February 2012
  • January 2012
  • December 2011
  • November 2011
  • October 2011
  • September 2011
  • August 2011
  • July 2011
  • June 2011
  • May 2011
  • April 2011
  • March 2011
  • February 2011
  • January 2011
  • December 2010
  • November 2010
  • October 2010
  • September 2010
  • August 2010
  • July 2010
  • June 2010
  • May 2010
  • April 2010
  • March 2010
  • January 2010
  • December 2009
  • November 2009
  • October 2009
  • September 2009
  • August 2009
  • July 2009
  • June 2009
  • May 2009
  • April 2009
  • March 2009
  • February 2009
  • January 2009
  • December 2008
  • November 2008
  • October 2008
  • September 2008
  • August 2008
  • July 2008
  • June 2008
  • May 2008
  • April 2008
  • March 2008
  • February 2008
  • January 2008
  • November 2007
  • October 2007
  • September 2007
  • August 2007
  • July 2007
  • June 2007
  • May 2007
  • April 2007
  • March 2007
  • February 2007
  • January 2007
  • December 2006
  • November 2006
  • October 2006
  • September 2006
  • August 2006
  • July 2006
  • June 2006
  • May 2006
  • April 2006
  • March 2006
  • February 2006
  • January 2006
  • December 2005
  • November 2005
  • October 2005
  • September 2005
  • August 2005
  • July 2005
  • June 2005
  • May 2005
  • April 2005
  • March 2005
  • February 2005
  • January 2005
  • November 2004
  • September 2004
  • August 2004
  • July 2004
  • April 2004
  • March 2004
  • June 2002

Categories

  • Career Development
  • Data Engineering
  • Data Science
  • Infrastructure
  • Microsoft SQL
  • Modern Data Estate
  • Personal
  • Random Technology
  • uncategorized
© 2025 shannonlowder.com | Powered by Minimalist Blog WordPress Theme