Home > Articles > Certification > Microsoft Certification

This chapter is from the book

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

  1. Add a new form to the project. Name the new form StepByStep2_15.cs.

  2. Add a Button control (btnReadXml) and a ListBox control (lbNodes) to the form.

  3. 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.

  4. Switch to code view and add the following using directives:

    using System.Text;
    using System.Xml;
    using System.Data;
    using System.Data.SqlClient;
  5. 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.

  1. Insert the Main() method to launch the form. Set the form as the startup form for the project.

  2. 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.15Figure 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

  1. Add a new form to the project. Name the new form StepByStep2_16.cs.

  2. Add a Button control (btnUpdate) to the form.

  3. 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.

  4. Switch to code view and add the following using directives:

    using Microsoft.Data.SqlXml;
    using System.IO;
  5. 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();
      }
    }
  6. 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>
  7. 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>
  8. Insert the Main() method to launch the form. Set the form as the startup form for the project.

  9. 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.16Figure 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.

  1. Add a new form to the project. Name the new form GuidedPracticeExercise2_2.cs.

  2. Add a Button control (btnReadXml) and a ListBox control (lbNodes) to the form.

  3. Switch to code view and add the following using directives:

    using Microsoft.Data.SqlXml;
    using System.Xml;
  4. You need the Utility.cs class created in Step-by-Step 2.5, so create it now if you didn't already create it.

  5. 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();
    }
  6. Insert the Main() method to launch the form. Set the form as the startup object for the project.

  7. 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.17Figure 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.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020