As you saw in Exercise 18.2, you can append FOR XML AUTO to the end of a SELECT statement in order to cause the result to be returned as an XML document fragment. Transact-SQL's FOR XML syntax is much richer than this, though—it supports several options that extend its usefulness in numerous ways. In this section, we'll discuss a few of these and work through examples that illustrate them.
SELECT…FOR XML (Server-Side)
As I'm sure you've already surmised, you can retrieve XML data from SQL Server by using the FOR XML option of the SELECT command. FOR XML causes SELECT to return query results as an XML stream rather than a traditional rowset. On the server-side, this stream can have one of three formats: RAW, AUTO, or EXPLICIT. The basic FOR XML syntax looks like this:
SELECT column list FROM table list WHERE filter criteria FOR XML RAW | AUTO | EXPLICIT [, XMLDATA] [, ELEMENTS] [, BINARY BASE64]
RAW returns column values as attributes and wraps each row in a generic row element. AUTO returns column values as attributes and wraps each row in an element named after the table from which it came.1 EXPLICIT lets you completely control the format of the XML returned by a query.
XMLDATA causes an XML-Data schema to be returned for the document being retrieved. ELEMENTS causes the columns in XML AUTO data to be returned as elements rather than attributes. BINARY BASE64 specifies that binary data is to be returned using BASE64 encoding.
I'll discuss these options in more detail in just a moment. Also note that there are client-side specific options available with FOR XML queries that aren't available in server-side queries. We'll talk about those in just a moment, too.
RAW Mode
RAW mode is the simplest of the three basic FOR XML modes. It performs a very basic translation of the result set into XML. Listing 18.3 shows an example.
Listing 18.3
SELECT CustomerId, CompanyName FROM Customers FOR XML RAW
(Results abridged)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <row CustomerId="ALFKI" CompanyName="Alfreds Futterkiste"/><row Cu CompanyName="Ana Trujillo Emparedados y helados"/><row CustomerId= CompanyName="Antonio Moreno Taquer'a"/><row CustomerId="AROUT" Com Horn"/><row CustomerId="BERGS" CompanyName="Berglunds snabbköp"/>< CustomerId="BLAUS" CompanyName="Blauer See Delikatessen"/><row Cus CompanyName="Blondesddsl p_re et fils"/><row CustomerId="WELLI" CompanyName="Wellington Importadora"/><row CustomerId="WHITC" Comp Clover Markets"/><row CustomerId="WILMK" CompanyName="Wilman Kala" CustomerId="WOLZA" CompanyName="Wolski Zajazd"/>
Each column becomes an attribute in the result set, and each row becomes an element with the generic name of row.
As I've mentioned before, the XML that's returned by FOR XML is not well formed because it lacks a root element. It's technically an XML fragment and must include a root element in order to be usable by an XML parser. From the client side, you can set an ADO Command object's xml root property in order to automatically generate a root node when you execute a FOR XML query.
AUTO Mode
FOR XML AUTO gives you more control than RAW mode over the XML fragment that's produced. To begin with, each row in the result set is named after the table, view, or table-valued UDF that produced it. For example, Listing 18.4 shows a basic FOR XML AUTO query.
Listing 18.4
SELECT CustomerId, CompanyName FROM Customers FOR XML AUTO
(Results abridged)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers CustomerId="ALFKI" CompanyName="Alfreds Futterkiste"/>< CustomerId="ANATR" CompanyName="Ana Trujillo Emparedados y helados CustomerId="ANTON" CompanyName="Antonio Moreno Taquer'a"/><Custome CustomerId="AROUT" CompanyName="Around the Horn"/><Customers Custo CompanyName="Vins et alcools Chevalier"/><Customers CustomerId="WA CompanyName="Wartian Herkku"/><Customers CustomerId="WELLI" Compan Importadora"/><Customers CustomerId="WHITC" CompanyName="White Clo Markets"/><Customers CustomerId="WILMK" CompanyName="Wilman Kala"/ CustomerId="WOLZA" CompanyName="Wolski Zajazd"/>
Notice that each row is named after the table from whence it came: Customers. For results with more than one row, this amounts to having more than one top-level (root) element in the fragment, which isn't allowed in XML.
One big difference between AUTO and RAW mode is the way in which joins are handled. In RAW mode, a simple one-to-one translation occurs between columns in the result set and attributes in the XML fragment. Each row becomes an element in the fragment named row. These elements are technically empty themselves—they contain no values or subelements, only attributes. Think of attributes as specifying characteristics of an element, while data and subelements compose its contents. In AUTO mode, each row is named after the source from which it came, and the rows from joined tables are nested within one another. Listing 18.5 presents an example.
Listing 18.5
SELECT Customers.CustomerID, CompanyName, OrderId FROM Customers JOIN Orders ON (Customers.CustomerId=Orders.CustomerId) FOR XML AUTO
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers CustomerID="ALFKI" CompanyName="Alfreds Futterkiste"> <Orders OrderId="10643"/><Orders OrderId="10692"/> <Orders OrderId="10702"/><Orders OrderId="10835"/> <Orders OrderId="10952"/><Orders OrderId="11011"/> </Customers> <Customers CustomerID="ANATR" CompanyName="Ana Trujillo Emparedado <Orders OrderId="10308"/><Orders OrderId="10625"/> <Orders OrderId="10759"/><Orders OrderId="10926"/></Customers> <Customers CustomerID="FRANR" CompanyName="France restauration"> <Orders OrderId="10671"/><Orders OrderId="10860"/> <Orders OrderId="10971"/> </Customers>
I've formatted the XML fragment to make it easier to read—if you run the query yourself from Query Analyzer, you'll see an unformatted stream of XML text.
Note the way in which the Orders for each customer are contained within each Customer element. As I said, AUTO mode nests the rows returned by joins. Note my use of the full table name in the join criterion. Why didn't I use a table alias? Because AUTO mode uses the table aliases you specify to name the elements it returns. If you use shortened monikers for a table, its elements will have that name in the resulting XML fragment. While useful in traditional Transact-SQL, this makes the fragment difficult to read if the alias isn't sufficiently descriptive.
ELEMENTS Option
The ELEMENTS option of the FOR XML AUTO clause causes AUTO mode to return nested elements instead of attributes. Depending on your business needs, element-centric mapping may be preferable to the default attribute-centric mapping. Listing 18.6 gives an example of a FOR XML query that returns elements instead of attributes.
Listing 18.6
SELECT CustomerID, CompanyName FROM Customers FOR XML AUTO, ELEMENTS
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers> <CustomerID>ALFKI</CustomerID> <CompanyName>Alfreds Futterkiste</CompanyName> </Customers> <Customers> <CustomerID>ANATR</CustomerID> <CompanyName>Ana Trujillo Emparedados y helados</CompanyName> </Customers> <Customers> <CustomerID>ANTON</CustomerID> <CompanyName>Antonio Moreno Taquer'a</CompanyName> </Customers> <Customers> <CustomerID>AROUT</CustomerID> <CompanyName>Around the Horn</CompanyName> </Customers> <Customers> <CustomerID>WILMK</CustomerID> <CompanyName>Wilman Kala</CompanyName> </Customers> <Customers> <CustomerID>WOLZA</CustomerID> <CompanyName>Wolski Zajazd</CompanyName> </Customers>
Notice that the ELEMENTS option has caused what were being returned as attributes of the Customers element to instead be returned as subelements. Each attribute is now a pair of element tags that enclose the value from a column in the table.
Note
NOTE: Currently, AUTO mode does not support GROUP BY or aggregate functions. The heuristics it uses to determine element names are incompatible with these constructs, so you cannot use them in AUTO mode queries. Additionally, FOR XML itself is incompatible with COMPUTE, so you can't use it in FOR XML queries of any kind.
EXPLICIT Mode
If you need more control over the XML than FOR XML produces, EXPLICIT mode is more flexible (and therefore more complicated to use) than either RAW mode or AUTO mode. EXPLICIT mode queries define XML documents in terms of a “universal table”—a mechanism for returning a result set from SQL Server that describes what you want the document to look like, rather than composing the document itself. A universal table is just a SQL Server result set with special column headings that tell the server how to produce an XML document from your data. Think of it as a set-oriented method of making an API call and passing parameters to it. You use the facilities available in Transact-SQL to make the call and pass it parameters.
A universal table consists of one column for each table column that you want to return in the XML fragment, plus two additional columns: Tag and Parent. Tag is a positive integer that uniquely identifies each tag that is to be returned by the document; Parent establishes parent-child relationships between tags.
The other columns in a universal table—the ones that correspond to the data you want to include in the XML fragment—have special names that actually consist of multiple segments delimited by exclamation points (!). These special column names pass muster with SQL Server's parser and provide specific instructions regarding the XML fragment to produce. They have the following format:
Element!Tag!Attribute!Directive
We'll see some examples of these shortly.
The first thing you need to do to build an EXPLICIT mode query is to determine the layout of the XML document you want to end up with. Once you know this, you can work backward from there to build a universal table that will produce the desired format. For example, let's say we want a simple customer list based on the Northwind Customers table that returns the customer ID as an attribute and the company name as an element. The XML fragment we're after might look like this:
<Customers CustomerId="ALFKI">Alfreds Futterkiste</Customers>
Listing 18.7 shows a Transact-SQL query that returns a universal table that specifies this layout.
Listing 18.7
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1] FROM Customers
(Results abridged)
Tag Parent Customers!1!CustomerId Customers!1 ------ -------- ---------------------- --------------------------- 1 NULL ALFKI Alfreds Futterkiste 1 NULL ANATR Ana Trujillo Emparedados y 1 NULL ANTON Antonio Moreno Taquer'a
The first two columns are the extra columns I mentioned earlier. Tag specifies an identifier for the tag we want to produce. Since we want to produce only one element per row, we hard-code this to 1. The same is true of Parent—there's only one element and a top-level element doesn't have a parent, so we return NULL for Parent in every row.
Since we want to return the customer ID as an attribute, we specify an attribute name in the heading of column 3 (bolded). And since we want to return CompanyName as an element rather than an attribute, we omit the attribute name in column 4.
By itself, this table accomplishes nothing. We have to add FOR XML EXPLICIT to the end of it in order for the odd column names to have any special meaning. Add FOR XML EXPLICIT to the query and run it from Query Analyzer. Listing 18.8 shows what you should see.
Listing 18.8
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1] FROM Customers FOR XML EXPLICIT
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers CustomerId="ALFKI">Alfreds Futterkiste</Customers> <Customers CustomerId="ANATR">Ana Trujillo Emparedados y helados </Customers> <Customers CustomerId="WHITC">White Clover Markets</Customers> <Customers CustomerId="WILMK">Wilman Kala</Customers> <Customers CustomerId="WOLZA">Wolski Zajazd</Customers>
Table 18.2. EXPLICIT Mode Directives
Value |
Function |
---|---|
element |
Causes data in the column to be encoded and represented as a subelement |
xml |
Causes data to be represented as a subelement without encoding it |
xmltext |
Retrieves data from an overflow column and appends it to the document |
cdata |
Causes data in the column to be represented as a CDATA section in the resulting document |
hide |
Hides (omits) a column that appears in the universal table from the resulting XML fragment |
id, idref, and idrefs |
In conjunction with XMLDATA, can establish relationships between elements across multiple XML fragments |
As you can see, each CustomerId value is returned as an attribute, and each CompanyName is returned as the element data for the Customers element, just as we specified.
Directives
The fourth part of the multivalued column headings supported by EXPLICIT mode queries is the directive segment. You use it to further control how data is represented in the resulting XML fragment. As Table 18.2 illustrates, the directive segment supports eight values.
Of these, element is the most frequently used. It causes data to be rendered as a subelement rather than an attribute. For example, let's say that, in addition to CustomerId and CompanyName, we wanted to return ContactName in our XML fragment and we wanted it to be a subelement rather than an attribute. Listing 18.9 shows how the query would look.
Listing 18.9
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1], ContactName AS [Customers!1!ContactName!element] FROM Customers FOR XML EXPLICIT
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers CustomerId="ALFKI">Alfreds Futterkiste <ContactName>Maria Anders</ContactName> </Customers> <Customers CustomerId="ANATR">Ana Trujillo Emparedados y <ContactName>Ana Trujillo</ContactName> </Customers> <Customers CustomerId="ANTON">Antonio Moreno Taquer'a <ContactName>Antonio Moreno</ContactName> </Customers> <Customers CustomerId="AROUT">Around the Horn <ContactName>Thomas Hardy</ContactName> </Customers> <Customers CustomerId="BERGS">Berglunds snabbköp <ContactName>Christina Berglund</ContactName> </Customers> <Customers CustomerId="WILMK">Wilman Kala <ContactName>Matti Karttunen</ContactName> </Customers> <Customers CustomerId="WOLZA">Wolski Zajazd <ContactName>Zbyszek Piestrzeniewicz</ContactName> </Customers>
As you can see, ContactName is nested within each Customers element as a subelement. The elements directive encodes the data it returns. We can retrieve the same data by using the xml directive without encoding, as shown in Listing 18.10.
Listing 18.10
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1], ContactName AS [Customers!1!ContactName!xml] FROM Customers FOR XML EXPLICIT
The xml directive (bolded) causes the column to be returned without encoding any special characters it contains.
Establishing Data Relationships
Thus far, we've been listing the data from a single table, so our EXPLICT queries haven't been terribly complex. That would still be true even if we queried multiple tables as long as we didn't mind repeating the data from each table in each top-level element in the XML fragment. Just as the column values from joined tables are often repeated in the result sets of Transact-SQL queries, we could create an XML fragment that contained data from multiple tables repeated in each element. However, that wouldn't be the most efficient way to represent the data in XML. Remember: XML supports hierarchical relationships between elements. You can establish these hierarchies by using EXPLICIT mode queries and T-SQL UNIONs. Listing 18.11 provides an example.
Listing 18.11
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1], NULL AS [Orders!2!OrderId], NULL AS [Orders!2!OrderDate!element] FROM Customers UNION SELECT 2 AS Tag, 1 AS Parent, CustomerId, NULL, OrderId, OrderDate FROM Orders ORDER BY [Customers!1!CustomerId], [Orders!2!OrderDate!element] FOR XML EXPLICIT
This query does several interesting things. First, it links the Customers and Orders tables using the CustomerId column they share. Notice the third column in each SELECT statement—it returns the CustomerId column from each table. The Tag and Parent columns establish the details of the relationship between the two tables. The Tag and Parent values in the second query link it to the first. They establish that Order records are children of Customer records. Lastly, note the ORDER BY clause. It arranges the elements in the table in a sensible fashion—first by CustomerId and second by the OrderDate of each Order. Listing 18.12 shows the result set.
Listing 18.12
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers CustomerId="ALFKI">Alfreds Futterkiste <Orders OrderId="10643"> <OrderDate>1997-08-25T00:00:00</OrderDate> </Orders> <Orders OrderId="10692"> <OrderDate>1997-10-03T00:00:00</OrderDate> </Orders> <Orders OrderId="10702"> <OrderDate>1997-10-13T00:00:00</OrderDate> </Orders> <Orders OrderId="10835"> <OrderDate>1998-01-15T00:00:00</OrderDate> </Orders> <Orders OrderId="10952"> <OrderDate>1998-03-16T00:00:00</OrderDate> </Orders> <Orders OrderId="11011"> <OrderDate>1998-04-09T00:00:00</OrderDate> </Orders> </Customers> <Customers CustomerId="ANATR">Ana Trujillo Emparedados y helados <Orders OrderId="10308"> <OrderDate>1996-09-18T00:00:00</OrderDate> </Orders> <Orders OrderId="10625"> <OrderDate>1997-08-08T00:00:00</OrderDate> </Orders> <Orders OrderId="10759"> <OrderDate>1997-11-28T00:00:00</OrderDate> </Orders> <Orders OrderId="10926"> <OrderDate>1998-03-04T00:00:00</OrderDate> </Orders> </Customers>
As you can see, each customer's orders are nested within its element.
The hide Directive
The hide directive omits a column you've included in the universal table from the resulting XML document. One use of this functionality is to order the result by a column that you don't want to include in the XML fragment. When you aren't using UNION to merge tables, this isn't a problem because you can order by any column you choose. However, the presence of UNION in a query requires order by columns to exist in the result set. The hide directive gives you a way to satisfy this requirement without being forced to return data you don't want to. Listing 18.13 shows an example.
Listing 18.13
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1], PostalCode AS [Customers!1!PostalCode!hide], NULL AS [Orders!2!OrderId], NULL AS [Orders!2!OrderDate!element] FROM Customers UNION SELECT 2 AS Tag, 1 AS Parent, CustomerId, NULL, NULL, OrderId, OrderDate FROM Orders ORDER BY [Customers!1!CustomerId], [Orders!2!OrderDate!element], [Customers!1!PostalCode!hide] FOR XML EXPLICIT
Notice the hide directive (bolded) that's included in the column 5 heading. It allows the column to be specified in the ORDER BY clause without actually appearing in the resulting XML fragment.
The cdata Directive
CDATA sections may appear anywhere in an XML document that character data may appear. A CDATA section is used to escape characters that would otherwise be recognized as markup (e.g., <, >, /, and so on). Thus CDATA sections allow you to include sections in an XML document that might otherwise confuse the parser. To render a CDATA section from an EXPLICIT mode query, include the cdata directive, as demonstrated in Listing 18.14.
Listing 18.14
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId], CompanyName AS [Customers!1], Fax AS [Customers!1!!cdata] FROM Customers FOR XML EXPLICIT
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Customers CustomerId="ALFKI">Alfreds Futterkiste <![CDATA[030-0076545]]> </Customers> <Customers CustomerId="ANATR">Ana Trujillo Emparedados y helados <![CDATA[(5) 555-3745]]> </Customers> <Customers CustomerId="ANTON">Antonio Moreno Taquer'a </Customers> <Customers CustomerId="AROUT">Around the Horn <![CDATA[(171) 555-6750]]> </Customers> <Customers CustomerId="BERGS">Berglunds snabbköp <![CDATA[0921-12 34 67]]> </Customers>
As you can see, each value in the Fax column is returned as a CDATA section in the XML fragment. Note the omission of the attribute name in the cdata column heading (bolded). This is because attribute names aren't allowed for CDATA sections. Again, they represent escaped document segments, so the XML parser doesn't process any attribute or element names they may contain.
The id, idref, and idrefs Directives
The ID, IDREF, and IDFREFS data types can be used to represent relational data in an XML document. Set up in a DTD or XML-Data schema, they establish relationships between elements. They're handy in situations where you need to exchange complex data and want to minimize the amount of data duplication in the document.
EXPLICIT mode queries can use the id, idref, and idrefs directives to specify relational fields in an XML document. Naturally, this approach works only if a schema is used to define the document and identify the columns used to establish links between entities. FOR XML's XMLDATA option provides a means of generating an inline schema for its XML fragment. In conjunction with the id directives, it can identify relational fields in the XML fragment. Listing 18.15 gives an example.
Listing 18.15
SELECT 1 AS Tag, NULL AS Parent, CustomerId AS [Customers!1!CustomerId!id], CompanyName AS [Customers!1!CompanyName], NULL AS [Orders!2!OrderID], NULL AS [Orders!2!CustomerId!idref] FROM Customers UNION SELECT 2, NULL, NULL, NULL, OrderID, CustomerId FROM Orders ORDER BY [Orders!2!OrderID] FOR XML EXPLICIT, XMLDATA
(Results abridged and formatted)
XML_F52E2B61-18A1-11d1-B105-00805F49916B ------------------------------------------------------------------ <Schema name="Schema2" xmlns="urn:schemas-microsoft-com:xml-data" xmlns:dt="urn:schemas-microsoft-com:datatypes"> <ElementType name="Customers" content="mixed" model="open"> <AttributeType name="CustomerId" dt:type="id"/> <AttributeType name="CompanyName" dt:type="string"/> <attribute type="CustomerId"/> <attribute type="CompanyName"/> </ElementType> <ElementType name="Orders" content="mixed" model="open"> <AttributeType name="OrderID" dt:type="i4"/> <AttributeType name="CustomerId" dt:type="idref"/> <attribute type="OrderID"/> <attribute type="CustomerId"/> </ElementType> </Schema> <Customers xmlns="x-schema:#Schema2" CustomerId="ALFKI" CompanyName="Alfreds Futterkiste"/> <Customers xmlns="x-schema:#Schema2" CustomerId="ANATR" CompanyName="Ana Trujillo Emparedados y helados"/> <Customers xmlns="x-schema:#Schema2" CustomerId="ANTON" CompanyName="Antonio Moreno Taquer'a"/> <Customers xmlns="x-schema:#Schema2" CustomerId="AROUT" CompanyName="Around the Horn"/> <Orders xmlns="x-schema:#Schema2" OrderID="10248" CustomerId="VINET"/> <Orders xmlns="x-schema:#Schema2" OrderID="10249" CustomerId="TOMSP"/> <Orders xmlns="x-schema:#Schema2" OrderID="10250" CustomerId="HANAR"/> <Orders xmlns="x-schema:#Schema2" OrderID="10251" CustomerId="VICTE"/> <Orders xmlns="x-schema:#Schema2" OrderID="10252" CustomerId="SUPRD"/> <Orders xmlns="x-schema:#Schema2" OrderID="10253" CustomerId="HANAR"/> <Orders xmlns="x-schema:#Schema2" OrderID="10254" CustomerId="CHOPS"/> <Orders xmlns="x-schema:#Schema2" OrderID="10255" CustomerId="RICSU"/>
Note the use of the id and idref directives in the CustomerId columns of the Customers and Orders tables (bolded). These directives link the two tables by using the CustomerId column they share.
If you examine the XML fragment returned by the query, you'll see that it starts off with the XML-Data schema that the XMLDATA directive created. This schema is then referenced in the XML fragment that follows.
SELECT…FOR XML (Client-Side)
SQLXML also supports the notion of offloading to the client the work of translating a result set into XML. This functionality is accessible via the SQLXML managed classes, XML templates, a virtual directory configuration switch, and the SQLXMLOLEDB provider. Because it requires the least amount of setup, I'll cover client-side FOR XML using SQLXMLOLEDB here. The underlying technology is the same regardless of the mechanism used.
SQLXMLOLEDB serves as a layer between a client (or middle-tier) app and SQL Server's native SQLOLEDB provider. The Data Source property of the SQLXMLOLEDB provider specifies the OLE DB provider through which it executes queries; currently only SQLOLEDB is allowed.
SQLXMLOLEDB is not a rowset provider. In order to use it from ADO, you must access it via ADO's stream mode. I'll show you some code in just a minute that illustrates this.
You perform client-side FOR XML processing using SQLXMLOLEDB by following these general steps.
-
Connect using an ADO connection string that specifies SQLXMLOLEDB as the provider.
-
Set the ClientSideXML property of your ADO Command object to True.
-
Create and open an ADO stream object and associate it with your Command object's Output Stream property.
-
Execute a FOR XML EXPLICIT, FOR XML RAW, or FOR XML NESTED Transact-SQL query via your Command object, specifying the adExecuteStream option in your call to Execute.
Listing 18.16 illustrates. (You can find the source code for this app in the CH18\forxml_clientside subfolder on this book's CD.)
Listing 18.16
Private Sub Command1_Click() Dim oConn As New ADODB.Connection Dim oComm As New ADODB.Command Dim stOutput As New ADODB.Stream stOutput.Open oConn.Open (Text3.Text) oComm.ActiveConnection = oConn oComm.Properties("ClientSideXML") = "True" If Len(Text1.Text) = 0 Then Text1.Text = _ "select * from pubs..authors FOR XML NESTED" End If oComm.CommandText = Text1.Text oComm.Properties("Output Stream") = stOutput oComm.Properties("xml root") = "Root" oComm.Execute , , adExecuteStream Text2.Text = stOutput.ReadText(adReadAll) stOutput.Close oConn.Close Set oComm = Nothing Set oConn = Nothing End Sub
As you can see, most of the action here revolves around the ADO Command object. We set its ClientSideXML property to True and its Output Stream property to an ADO stream object we created before callings its Execute method.
Note the use of the FOR XML NESTED clause. The NESTED option is specific to client-side FOR XML processing—you can't use it in server-side queries. It's very much like FOR XML AUTO but has some minor differences. For example, when a FOR XML NESTED query references a view, the names of the view's underlying base tables are used in the generated XML. The same is true for table aliases—their base names are used in the XML that's produced. Using FOR XML AUTO in a client-side FOR XML query causes the query to be processed on the server rather than the client, so use NESTED when you want similar functionality to FOR XML AUTO on the client.
Given our previous investigation into whether MSXML is involved in the production of server-side XML (Exercise 18.2), you might be wondering whether it's used by SQLXML's client-side FOR XML processing. It isn't. Again, you can attach a debugger (in this case, to the forxml_clientside app) to see this for yourself. You will see SQLXMLn.DLL loaded into the app's process space the first time you run the query. This DLL is where the SQLXMLOLEDB provider resides and is where SQLXML's client-side FOR XML processing occurs.