Using XML with SQL Server
The .NET team is not the only group at Microsoft that's been working with XML. Over the past several releases, Microsoft SQL Server has become increasingly integrated with XML. In the current release, you can generate XML with SQL statements, using Microsoft T-SQL extensions to the SQL standard query language. You can also update SQL Server tables by sending properly formed XML messages, called DiffGrams, to a SQL Server database. In this section, you'll learn the basics of interacting with SQL Server via XML.
Generating XML with SQL Statements
Access and Manipulate XML Data: Write a SQL statement that retrieves XML data from a SQL Server database.
Understanding the FOR XML Clause
SQL Server enables you to retrieve the results of any query as XML rather than as a SQL resultset. To do this, you use the Microsoft-specific FOR XML clause. You can use a variety of options in the FOR XML clause to customize the XML that SQL Server generates.
The first option is FOR XML RAW. When you use raw mode with FOR XML, SQL Server returns one element (always named row) for each row of the resultset, with the individual columns represented as attributes. For example, consider this query:
SELECT Customers.CustomerID, Customers.CompanyName, Orders.OrderID, Orders.OrderDate FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID WHERE Country = 'Brazil' AND OrderDate BETWEEN '1997-03-15' AND '1997-04-15' FOR XML RAW
If you execute this query (for example, using SQL Query Analyzer) in the Northwind sample database, you'll get back these results:
<row CustomerID="RICAR" CompanyName="Ricardo Adocicados" OrderID="10481" OrderDate="1997-03-20T00:00:00"/> <row CustomerID="QUEEN" CompanyName="Queen Cozinha" OrderID="10487" OrderDate="1997-03-26T00:00:00"/> <row CustomerID="COMMI" CompanyName="Comércio Mineiro" OrderID="10494" OrderDate="1997-04-02T00:00:00"/> <row CustomerID="TRADH" CompanyName="Tradiça[dd]o Hipermercados" OrderID="10496" OrderDate="1997-04-04T00:00:00"/>
NOTE
Result Formatting SQL Query Analyzer returns XML results as one long string. I've reformatted these results for easier display on the printed page. If you have trouble seeing all the results in SQL Query Analyzer, select Tools, Options, Results, and increase the Maximum Character Width setting.
If the query output contains binary columns, you must include the BINARY BASE64 option after the FOR XML clause to avoid a runtime error:
SELECT EmployeeID, Photo FROM Employees FOR XML RAW, BINARY BASE64
With this option, standard Base64 coding is used to encode any binary columns in the output XML.
The second variant of the FOR XML clause is FOR XML AUTO. When you use auto mode with FOR XML, nested tables in the resultset are represented as nested elements in the XML. Columns are still represented as attributes. For example, here's a query that uses FOR XML AUTO:
SELECT Customers.CustomerID, Customers.CompanyName, Orders.OrderID, Orders.OrderDate FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID WHERE Country = 'Brazil' AND OrderDate BETWEEN '1997-03-15' AND '1997-04-15' FOR XML AUTO
Here's the corresponding resultset:
<Customers CustomerID="RICAR" CompanyName="Ricardo Adocicados"> <Orders OrderID="10481" OrderDate="1997-03-20T00:00:00"/> </Customers> <Customers CustomerID="QUEEN" CompanyName="Queen Cozinha"> <Orders OrderID="10487" OrderDate="1997-03-26T00:00:00"/> </Customers> <Customers CustomerID="COMMI" CompanyName="Comércio Mineiro"> <Orders OrderID="10494" OrderDate="1997-04-02T00:00:00"/> </Customers> <Customers CustomerID="TRADH" CompanyName="Tradição Hipermercados"> <Orders OrderID="10496" OrderDate="1997-04-04T00:00:00"/> </Customers>
Note that in this resultset, the Orders element is nested within the Customers element for each order. If there were multiple orders for a single customer, the Orders element would repeat as many times as necessary.
There's a second variant of FOR XML AUTO. You can include the ELEMENTS option to represent columns as elements rather than as attributes. Here's query that uses this option:
SELECT Customers.CustomerID, Customers.CompanyName, Orders.OrderID, Orders.OrderDate FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID WHERE Country = 'Brazil' AND OrderDate BETWEEN '1997-03-15' AND '1997-04-15' FOR XML AUTO, ELEMENTS
Here's the corresponding resultset:
<Customers> <CustomerID>RICAR</CustomerID> <CompanyName>Ricardo Adocicados</CompanyName> <Orders> <OrderID>10481</OrderID> <OrderDate>1997-03-20T00:00:00</OrderDate> </Orders> </Customers> <Customers> <CustomerID>QUEEN</CustomerID> <CompanyName>Queen Cozinha</CompanyName> <Orders> <OrderID>10487</OrderID> <OrderDate>1997-03-26T00:00:00</OrderDate> </Orders> </Customers> <Customers> <CustomerID>COMMI</CustomerID> <CompanyName>Comércio Mineiro</CompanyName> <Orders> <OrderID>10494</OrderID> <OrderDate>1997-04-02T00:00:00</OrderDate> </Orders> </Customers> <Customers> <CustomerID>TRADH</CustomerID> <CompanyName>Tradição Hipermercados</CompanyName> <Orders> <OrderID>10496</OrderID> <OrderDate>1997-04-04T00:00:00</OrderDate> </Orders> </Customers>
The final variant of FOR XML is FOR XML EXPLICIT. In explicit mode, you must construct your query so as to create a resultset with the first column named Tag and the second column named Parent. These columns create a self-join in the resultset that is used to determine the hierarchy of the created XML file. Here's a relatively simple query in explicit mode:
SELECT 1 AS Tag, NULL AS Parent, Customers.CustomerID AS [Customer!1!CustomerID], Customers.CompanyName AS [Customer!1!CompanyName], NULL AS [Order!2!OrderID], NULL AS [Order!2!OrderDate] FROM Customers WHERE COUNTRY = 'Brazil' UNION ALL SELECT 2, 1, Customers.CustomerID, Customers.CompanyName, Orders.OrderID, Orders.OrderDate FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID WHERE Country = 'Brazil' AND OrderDate BETWEEN '1997-03-15' AND '1997-04-15' ORDER BY [Customer!1!CustomerID], [Order!2!OrderID] FOR XML EXPLICIT
The resulting XML from this query is as follows:
<Customer CustomerID="COMMI" CompanyName="Comércio Mineiro"> <Order OrderID="10494" OrderDate="1997-04-02T00:00:00"/> </Customer> <Customer CustomerID="FAMIA" CompanyName="Familia Arquibaldo"/> <Customer CustomerID="GOURL" CompanyName="Gourmet Lanchonetes"/> <Customer CustomerID="HANAR" CompanyName="Hanari Carnes"/> <Customer CustomerID="QUEDE" CompanyName="Que Delícia"/> <Customer CustomerID="QUEEN" CompanyName="Queen Cozinha"> <Order OrderID="10487" OrderDate="1997-03-26T00:00:00"/> </Customer> <Customer CustomerID="RICAR" CompanyName="Ricardo Adocicados"> <Order OrderID="10481" OrderDate="1997-03-20T00:00:00"/> </Customer> <Customer CustomerID="TRADH" CompanyName="Tradição Hipermercados"> <Order OrderID="10496" OrderDate="1997-04-04T00:00:00"/> </Customer><Customer CustomerID="WELLI" CompanyName="Wellington Importadora"/>
Note that in this case even customers without orders in the specified time period are included, because the first half of the query retrieves all customers from Brazil. Explicit mode allows you the finest control over the generated XML, but it's also the most complex mode to use in practice. You should stick to raw or auto mode whenever possible.
Finally, you can generate schema information as part of a SQL Server query by including the XMLDATA option in the query. You can do this in any of the FOR XML modes. For example, here's a query you saw earlier in this section with the XMLDATA option added:
SELECT Customers.CustomerID, Customers.CompanyName, Orders.OrderID, Orders.OrderDate FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID WHERE Country = 'Brazil' AND OrderDate BETWEEN '1997-03-15' AND '1997-04-15' FOR XML AUTO, ELEMENTS, XMLDATA
The resulting XML is as follows:
<Schema name="Schema1" xmlns="urn:schemas-microsoft-com:xml-data" xmlns:dt="urn:schemas-microsoft-com:datatypes"> <ElementType name="Customers" content="eltOnly" model="closed" order="many"> <element type="Orders" maxOccurs="*"/> <element type="CustomerID"/> <element type="CompanyName"/> </ElementType> <ElementType name="CustomerID" content="textOnly" model="closed" dt:type="string"/> <ElementType name="CompanyName" content="textOnly" model="closed" dt:type="string"/> <ElementType name="Orders" content="eltOnly" model="closed" order="many"> <element type="OrderID"/> <element type="OrderDate"/> </ElementType> <ElementType name="OrderID" content="textOnly" model="closed" dt:type="i4"/> <ElementType name="OrderDate" content="textOnly" model="closed" dt:type="dateTime"/> </Schema> <Customers xmlns="x-schema:#Schema1"> <CustomerID>RICAR</CustomerID> <CompanyName>Ricardo Adocicados</CompanyName> <Orders> <OrderID>10481</OrderID> <OrderDate>1997-03-20T00:00:00</OrderDate> </Orders> </Customers> <Customers xmlns="x-schema:#Schema1"> <CustomerID>QUEEN</CustomerID> <CompanyName>Queen Cozinha</CompanyName> <Orders> <OrderID>10487</OrderID> <OrderDate>1997-03-26T00:00:00</OrderDate> </Orders> </Customers> <Customers xmlns="x-schema:#Schema1"> <CustomerID>COMMI</CustomerID> <CompanyName>Comércio Mineiro</CompanyName> <Orders> <OrderID>10494</OrderID> <OrderDate>1997-04-02T00:00:00</OrderDate> </Orders> </Customers> <Customers xmlns="x-schema:#Schema1"> <CustomerID>TRADH</CustomerID> <CompanyName>Tradição Hipermercados</CompanyName> <Orders> <OrderID>10496</OrderID> <OrderDate>1997-04-04T00:00:00</OrderDate> </Orders> </Customers>
Using ExecuteXmlReader() Method
ADO.NET provides a means to integrate SQL Server's XML capabilities with the .NET Framework classes. The ExecuteXmlReader() method of the SqlCommand object enables you to retrieve an XmlReader directly from a SQL statement, provided that the SQL statement uses the FOR XML clause. Step-by-Step 2.15 shows you how.
STEP BY STEP 2.15 - Using the ExecuteXmlReader() Method
-
Add a new form to the project. Name the new form StepByStep2_15.cs.
-
Add a Button control (btnReadXml) and a ListBox control (lbNodes) to the form.
-
Open Server explorer. Expand the Data Connections node and locate a node that represents the Northwind sample database from a SQL Server. Drag and drop the node to the form to create a SqlConnection object.
-
Switch to code view and add the following using directives:
using System.Text; using System.Xml; using System.Data; using System.Data.SqlClient;
-
Double-click the Button control and add the following code to handle the button's Click event:
private void btnReadXML_Click( object sender, System.EventArgs e) { SqlCommand cmd = sqlConnection1.CreateCommand(); // Create a command to retrieve XML cmd.CommandType = CommandType.Text; cmd.CommandText = "SELECT Customers.CustomerID, " + "Customers.CompanyName," + "Orders.OrderID, Orders.OrderDate " + "FROM Customers INNER JOIN Orders " + "ON Customers.CustomerID = Orders.CustomerID " + "WHERE Country = 'Brazil' AND " + "OrderDate BETWEEN '1997-03-15' AND '1997-04-15' " + "FOR XML AUTO, ELEMENTS"; sqlConnection1.Open(); // Read the XML into an XmlReader XmlReader xr = cmd.ExecuteXmlReader(); StringBuilder sbNode = new StringBuilder(); // Dump the contents of the reader while(xr.Read()) { if((xr.NodeType == XmlNodeType.Element) || (xr.NodeType == XmlNodeType.Text) ) { sbNode.Length = 0; for(int intI=1; intI <= xr.Depth ; intI++) { sbNode.Append(" "); } sbNode.Append(xr.Name + " "); sbNode.Append(xr.NodeType.ToString()); if (xr.HasValue) { sbNode.Append(": " + xr.Value); } lbNodes.Items.Add(sbNode.ToString()); // Now add the attributes, if any if (xr.HasAttributes) { while(xr.MoveToNextAttribute()) { sbNode.Length=0; for(int intI=1; intI <= xr.Depth;intI++) { sbNode.Append(" "); } sbNode.Append(xr.Name + " "); sbNode.Append( xr.NodeType.ToString()); if (xr.HasValue) { sbNode.Append(": " + xr.Value); } lbNodes.Items.Add( sbNode.ToString()); } } } } // Clean up xr.Close(); sqlConnection1.Close(); }
WARNING
Close the XmlReader Object When you populate an XmlReader object with the ExecuteXmlReader() method, the XmlReader object gets exclusive use of the underlying SqlConnection object. You cannot perform any other operations through this SqlConnection object until you call the Close() method of the XmlReader object. Be sure to call the Close() method as soon as you are finished with the XmlReader object.
-
Insert the Main() method to launch the form. Set the form as the startup form for the project.
-
Run the project. Click the button to run the FOR XML query and display the results in the ListBox control, as shown in Figure 2.15.
Figure 2.15 You can retrieve data as XML from a SQL Server database by using the ExecuteXmlReader() method.
Updating SQL Server Data by Using XML
Access and Manipulate XML Data: Update a SQL Server database by using XML.
You can also update SQL Server data by using special XML messages called DiffGrams. The .NET Framework uses DiffGrams internally as a means of serializing changes in a DataSet object. For example, if you pass the changes in a DataSet object from one tier to another, the .NET Framework uses a DiffGram to send the changes.
NOTE
Not a Valid Document It's tempting to think that you can read an XmlDocument object directly from the XmlReader object returned by the ExecuteXmlReader() method. Unfortunately, if you try this you'll find that it generates an error. This is because the XML returned by FOR XML queries is well-formed, but it lacks an XML declaration and a root node, and is therefore an XML fragment and not a valid XML document.
You can also use DiffGrams yourself to update data in SQL Server. However, before you can do so, you need to install some additional software. This software is the SQLXML Managed Classes, an interface between SQL Server and the .NET Framework. In this section, you learn how to install this software and then how to use DiffGrams to modify SQL Server data.
Installing SQLXML
Although SQL Server 2000 includes some XML support (for example, the FOR XML syntax is built into the product) there have been many advances in XML since that version of SQL Server was released. Microsoft has kept SQL Server in tune with these advances by issuing a series of free upgrade packages with the general name of SQLXML. As of this writing, the current release of SQLXML is SQLXML 3.0 SP1. This package includes the following features:
A direct SOAP interface so that SQL Server can work with Web services without intervening components.
XML views via XSD schemas.
Client-side FOR XML support.
An OLE DB provider for SQL XML data.
Managed classes to expose SQLXML functionality in the .NET environment.
Support for DiffGrams generated by .NET.
To install SQLXML, you need to download the current release directly from Microsoft's web site. You can always find the current release by starting at the SQLXML home page, msdn.microsoft.com/nhp/default.asp?contentid=28001300. Before you run the installation, be sure you have the following prerequisite software installed:
Windows Installer 2.0
Microsoft SOAP Toolkit 2.0 SP2
SQL Server 2000 Client Tools
MDAC 2.6 or later
.NET Framework 1.0 or later.
SQLXML 3.0 also depends on release 4.0 of the MSXML parser. If this component is not present on your computer, it will be installed as part of the SQLXML installation.
To install SQLXML, download and run the executable. You can either choose to install all components, or select specific components to install.
Using DiffGrams
After you've installed SQLXML, you can use the SqlXmlCommand object to execute a DiffGram, as shown in Step-by-Step 2.16.
STEP BY STEP 2.16 - Executing a DiffGram
-
Add a new form to the project. Name the new form StepByStep2_16.cs.
-
Add a Button control (btnUpdate) to the form.
-
In Solution Explorer, right-click on the References node and select Add Reference. Select the .NET tab and click the Browse button. Browse to the SQLXML .NET library. By default this file is at c:\Program Files\SQLXML 3.0\bin\Microsoft.Data.SqlXml.dll. Click Open and then OK to add the reference.
-
Switch to code view and add the following using directives:
using Microsoft.Data.SqlXml; using System.IO;
-
Double-click the Button control and add code to execute a DiffGram when you click the button. If your server requires you to log in with a username and password, modify the connection string accordingly:
private void btnUpdate_Click( object sender, System.EventArgs e) { // Connect to the SQL Server database SqlXmlCommand sxc = new SqlXmlCommand("Provider=SQLOLEDB;" + "Server=(local);database=Northwind;" + "Integrated Security=SSPI"); // Set up the DiffGram sxc.CommandType = SqlXmlCommandType.DiffGram; sxc.SchemaPath = @"..\..\diffgram.xsd"; FileStream fs = new FileStream(@"..\..\diffgram.xml", FileMode.Open); sxc.CommandStream = fs; try { // And execute it sxc.ExecuteNonQuery(); MessageBox.Show("Database was updated!"); } catch (SqlXmlException ex) { ex.ErrorStream.Position = 0; string strErr = (new StreamReader( ex.ErrorStream).ReadToEnd()); MessageBox.Show(strErr); } catch (Exception ex) { MessageBox.Show(ex.Message); } finally { fs.Close(); } }
-
Add a new XML file to the project. Name the new file diffgram.xml. Modify the XML for diffgram.xml as follows:
<?xml version="1.0" standalone="yes"?> <diffgr:diffgram xmlns:msdata="urn:schemas-microsoft-com:xml-msdata" xmlns:diffgr= "urn:schemas-microsoft-com:xml-diffgram-v1"> <NewDataSet> <Customers diffgr:id="Customers1" msdata:rowOrder="0" diffgr:hasChanges="modified"> <CustomerID>ALFKI</CustomerID> <ContactName>Maria Anderson</ContactName> </Customers> </NewDataSet> <diffgr:before> <Customers diffgr:id="Customers1" msdata:rowOrder="0"> <CustomerID>ALFKI</CustomerID> <ContactName>Maria Anders</ContactName> </Customers> </diffgr:before> </diffgr:diffgram>
-
Add a new schema file to the project. Name the new file diffgram.xsd. Switch to XML view and modify the XML for this file as follows:
<xsd:schema xmlns:xsd= "http://www.w3.org/2001/XMLSchema" xmlns:sql="urn:schemas-microsoft-com:mapping-schema"> <xsd:element name="Customers" sql:relation="Customers" > <xsd:complexType> <xsd:sequence> <xsd:element name="CustomerID" sql:field="CustomerID" type="xsd:string" /> <xsd:element name="ContactName" sql:field="ContactName" type="xsd:string" /> </xsd:sequence> </xsd:complexType> </xsd:element> </xsd:schema>
-
Insert the Main() method to launch the form. Set the form as the startup form for the project.
-
Run the project. Click the button to update your SQL Server Northwind database. You can verify that the update worked by running a SELECT query in SQL Query Analyzer, as shown in Figure 2.16.
Figure 2.16 You can use the SqlXmlCommand object to apply DiffGrams to a SQL Server database.
You can think of a DiffGram as a before-and-after snapshot of a part of a SQL Server table. In this case, the first part of the XML file lists a row in the Customers table and indicates that it has been modified. The second part of the DiffGram contains the original data from the SQL Server table. SQL Server can use this data to find the row to be modified.
In addition to the DiffGram, this code requires a schema file that maps the element names in the DiffGram back to tables and columns in the SQL Server database. The sql:relation attribute in the schema file indicates the table mapping, whereas the sql:field attributes indicate the field mappings.
DiffGrams can insert or delete data as well as modify data. For an insertion, the DiffGram contains the data for the new row and no old data. For a deletion, the DiffGram contains the row to be deleted but no new row.
For more information on the DiffGram format, refer to the help files that are installed as a part of the SQLXML package.
REVIEW BREAK
The FOR XML clause in the SQL Server SELECT statement lets you generate XML documents directly from SQL Server data.
By choosing appropriate options in FOR XML, you can map SQL Server columns as either attributes or elements in the generated XML. You can also choose whether to use Base64 encoding in binary columns, and whether to embed schema information.
You can use the ExecuteXmlReader() method of the SqlCommand object to retrieve XML from a SQL Server database and assign it to classes within the .NET Framework.
The SQLXML package contains XML-related updates for SQL Server 2000.
You can use DiffGrams to package updates to SQL Server tables as XML files. The SqlXmlCommand object can apply DiffGrams to a SQL Server database.
Guided Practice Exercise 2.2
The SQLXML Managed Classes allow some additional flexibility in retrieving XML data from SQL Server to the .NET Framework classes. The key factor is that the SqlXmlCommand object includes a RootTag property. This property enables you to specify a root element to be included in the generated XML.
For this exercise, you'll use a SqlXmlCommand object to retrieve the results of a FOR XML query from a SQL Server database. You should load the results into an XmlDocument object and then display the contents of that object.
Try this on your own first. If you get stuck or would like to see one possible solution, follow the steps below.
-
Add a new form to the project. Name the new form GuidedPracticeExercise2_2.cs.
-
Add a Button control (btnReadXml) and a ListBox control (lbNodes) to the form.
-
Switch to code view and add the following using directives:
using Microsoft.Data.SqlXml; using System.Xml;
-
You need the Utility.cs class created in Step-by-Step 2.5, so create it now if you didn't already create it.
-
Double-click the button control and add code to read XML from the SQL Server when you click the button:
private void btnReadXML_Click( object sender, System.EventArgs e) { // Connect to the SQL Server database SqlXmlCommand sxc = new SqlXmlCommand("Provider=SQLOLEDB;" + "Server=(local);database=Northwind;" + "Integrated Security=SSPI"); sxc.CommandType = SqlXmlCommandType.Sql; sxc.CommandText = "SELECT Customers.CustomerID, " + "Customers.CompanyName," + "Orders.OrderID, Orders.OrderDate " + "FROM Customers INNER JOIN Orders " + "ON Customers.CustomerID = Orders.CustomerID " + "WHERE Country = 'Brazil' AND " + "OrderDate BETWEEN '1997-03-15' " + "AND '1997-04-15' FOR XML AUTO, ELEMENTS"; sxc.RootTag = "dataroot"; // Read the XML into an XmlReader XmlReader xr = sxc.ExecuteXmlReader(); XmlDocument xd = new XmlDocument(); xd.Load(xr); Utility u = new Utility(); u.XmlToListBox(xd, lbNodes); xr.Close(); }
-
Insert the Main() method to launch the form. Set the form as the startup object for the project.
-
Run the project. Click the button to run the FOR XML query and display the results in the ListBox control, as shown in Figure 2.17.
Figure 2.17 You can specify a root element for retrieved XML data from the SQL Server database by using the RootTag property of the SqlXmlCommand object.