- Chapter 16 - Working With XML Data in SQL Server 2000
- XML Support in SQL Server 2000
- Retrieving SQL Server Data in XML Format
- Using XML Data With Transact-SQL
- HTTP Access to SQL Server 2000
- Modifying SQL Server 2000 Data With Updategrams
- What's Next?
Modifying SQL Server 2000 Data With Updategrams
In the preceding sections, you learned how to retrieve data from SQL Server in XML format, and how to use XML data inside a Transact-SQL process.
The XML for SQL Server Web Release, which you can download from the Internet as explained earlier, provides the following extra features:
Insert, delete, and update actual rows in SQL Server using XML updategrams.
Import XML data into SQL Server using the XML Bulk Load component.
An updategram is a XML template that contains before and after images of the data.
Because an XML document is a hierarchical document, changes to the data can affect multiple tables. You can use the transaction capabilities of updategrams to consider specific changes as members of the same transaction, maintaining data consistency across those changes. Every transaction is identified by a sync element. Listing 16.26 contains a simple updategram that changes the contact name of a customer.
Listing 16.26A Simple Updategram That Changes a Customer's Contact Name
<CustomerUpdate xmlns:updg="urn:schemas-microsoft-com:xml-updategram"> <updg:sync> <updg:before> <Customers CustomerID="ALFKI"> <ContactName>Maria Anders</ContactName> </Customers> </updg:before> <updg:after> <Customers CustomerID="ALFKI"> <ContactName>Stephen Johns</ContactName> </Customers> </updg:after> </updg:sync> </CustomerUpdate>
Use Notepad to create the example from Listing 16.26 and save it as CustomerUpdate.xml in the Templates directory you created earlier in this chapter, in the "Creating a SQL Server Virtual Directory for IIS" section.
To execute this updategram, open Internet Explorer and type the following URL:
http://localhost/sqlxml/templates/CustomerUpdate.xml
Tip
If you receive an error message, check the spelling in the XML file. Remember that XML tags are case-sensitive.
You can open a new connection to SQL Server from Query Analyzer and check that the change has been made to the customer 'ALFKI' as defined in the updategram.
Looking at the example from Listing 16.26, you can identify the following sections:
<CustomerUpdate xmlns:updg="urn:schemas-microsoft-com:xml-updategram">
This line, at the beginning of the file, defines this XML file as an XML Template containing an updategram.
<updg:sync> ... </updg:sync>
These two tags define the boundaries of a single transaction.
<updg:before> ... </updg:before>
These two tags define the before image of the data. Somehow, you can consider this section as the WHERE clause in an UPDATE statement, where you define which rows will be updated.
<updg:after> ... </updg:after>
Finally, these two tags delimit the values to update. This section produces the same action as the SET clause in an UPDATE statement.
In this example, you used the default mapping, where the XML code shows the actual names for tables and columns, in this case to the Customers table, and the CustomerID and ContactName columns. In some cases, you might prefer to provide a schema file, such as CustomerSchema.xml, in which case you must change the <updg:sync> line, in the updategram file, to provide the mapping-schema attribute, as in the following line:
<updg:sync mapping-schema="CustomerSchema.xml">
Note
If the schema was not stored in the same path as the updategram, you can provide its full path in the mapping-schema attribute.
You can summit an updategram from an Active Server Page (ASP), by using ADO 2.6, as in the example from Listing 16.27.
Listing 16.27Using ADO 2.6 in VBScript to Execute an Updategram
<%@ LANGUAGE = VBScript %> <% Option Explicit %> <HTML> <HEAD> <META HTTP-EQUIV="Content-Type" content="text/html" charset="UTF-8"/> <TITLE>SQL-XML by Example - SQLXML.asp</TITLE> <% ' THIS IS THE SERVER SIDE SCRIPTING ' this part won't be visible from the client side ' some constants to make the code more readable ' some of these constants are available in the adovbs.inc file const adUseClient = 3 const adWriteChar = 0 const adWriteLine = 1 const adExecuteStream = 1024 ' Create a ADO Connection object Dim adoConn Set adoConn = Server.CreateObject("ADODB.Connection") ' Define the connection string to connect to a valid SQL Server 2000 instance ' and the Northwind database. Specify client side processing, ' which in this case will be in the IIS server ' Note: if your default instance is SQL Server 7, this code will not work ' unless you installed XML support for SQL Server 7.0 Dim sConn sConn = "Provider=sqloledb;" sConn = sConn & "Data Source=MSSQLFGG\S2K;" sConn = sConn & "Initial Catalog=Northwind;" sConn = sConn & "User ID=sa" adoConn.ConnectionString = sConn adoConn.CursorLocation = adUseClient ' Open the connection adoConn.Open ' Create an ADO Command object, to send the XML query ' and receive the XML results Dim adoCmd Set adoCmd = Server.CreateObject("ADODB.Command") Set adoCmd.ActiveConnection = adoConn ' Let's define the XML updategram ' as in Listing 16.26 ' Note that you must change " into ' because VBScript ' uses "" to enclosed constants Dim sQuery sQuery = "<CustomerUpdate " sQuery = sQuery & "xmlns:updg='urn:schemas-microsoft-com:xml-updategram'>" sQuery = sQuery & "<updg:sync>" sQuery = sQuery & "<updg:before>" sQuery = sQuery & "<Customers CustomerID='ALFKI'>" sQuery = sQuery & "<ContactName>Maria Anders</ContactName>" sQuery = sQuery & "</Customers>" sQuery = sQuery & "</updg:before>" sQuery = sQuery & "<updg:after>" sQuery = sQuery & "<Customers CustomerID='ALFKI'>" sQuery = sQuery & "<ContactName>Stephen Johns</ContactName>" sQuery = sQuery & "</Customers>" sQuery = sQuery & "</updg:after>" sQuery = sQuery & "</updg:sync>" sQuery = sQuery & "</CustomerUpdate>" ' Create and open the Stream object Dim adoStreamQuery Set adoStreamQuery = Server.CreateObject("ADODB.Stream") adoStreamQuery.Open ' Write the XML query into the Stream object adoStreamQuery.WriteText sQuery, adWriteChar adoStreamQuery.Position = 0 ' Select the Stream object as the Command to execute ' Note the GUID for the Dialect property, ' this GUID represents the MSSQLXML format adoCmd.CommandStream = adoStreamQuery ' Now we will select to send the output to the Response object ' which is a Stream object too adoCmd.Properties("Output Stream") = Response ' We can execute the command with the updategram Response.write "Executing Updategram... " adoCmd.Execute , , adExecuteStream Response.write "Updategram Executed" %> </HEAD> <BODY> <H1>SQL-XML by Example</H1> <H3>Updategram Execution</H3> <UL id=log> </UL> </BODY> </HTML>
As you can see, the example in Listing 16.27 is basically the same as the example in Listing 16.17. The only differences are the updategram and the lack of client-side scripting, which in this case it is not required.
Inserting SQL Server 2000 Data With Updategrams
In the preceding section, you learned how to update SQL Server data using updategrams. You can insert data into SQL Server using updategrams as well, as long as they don't contain an <updg:after> section.
Listing 16.28 contains an updategram that inserts a new category into the Categories table.
Listing 16.28Inserting a New Category Through Updategrams
<CategoryAdd xmlns:updg="urn:schemas-microsoft-com:xml-updategram"> <updg:sync> <updg:before> </updg:before> <updg:after> <Categories> <CategoryName>New Category</CategoryName> </Categories> </updg:after> </updg:sync> </CategoryAdd>
As you can see in Listing 16.28, the before image is empty, and when executing this updategram, a new category will be added, using "New Category" as name, and having all the other fields with their default values, or NULL.
The insertion operation can be more complex. Insert a new category and a new product in that category in the same transaction. The problem is that CategoryID is an identity column, and we need that new value to be used in the Products table. Listing 16.29 shows the updategram to perform this action.
Listing 16.29Inserting a New Category and a New Product in the New Category Through Updategrams
<CategoryProductAdd xmlns:updg="urn:schemas-microsoft-com:xml-updategram"> <updg:sync> <updg:before> </updg:before> <updg:after updg:returnid="ID"> <Categories updg:at-identity="ID"> <CategoryName>More Category</CategoryName> </Categories> <Products CategoryID="ID" ProductName="New Product" Discontinued="1" /> </updg:after> </updg:sync> </CategoryProductAdd>
The example in Listing 16.29 has some new attributes:
<updg:after updg:returnid="ID">
This directive instructs to return the Identity value automatically generated by SQL Server.
<Categories updg:at-identity="ID">
In this case you define a variable name, ID, for the identity column.
<Products CategoryID="ID" ProductName="New Product" Discontinued="1" />
You add a new product, using the recently generated Identity value stored in the ID variable, as CategoryID.
If you executed the updategram file as a URL from Internet Explorer, you will receive the response shown in Listing 16.30
Listing 16.30Response After Inserting a New Category and a New Product Through Updategrams
- <CategoryProductAdd xmlns:updg="urn:schemas-microsoft-com:xml-updategram"> - <returnid> <ID>11</ID> </returnid> </CategoryProductAdd>
The value of 11 is the new identity value used for the new category.
Deleting SQL Server 2000 Data With Updategrams
In the preceding section, you learned how to use updategrams without the before image to insert new rows in SQL Server. Following the same concept, to delete rows from SQL Server you can use updategrams without the after image.
Listing 16.31 shows the updategram to delete the products and categories inserted in Listings 16.27 and 16.28.
Listing 16.31Deleting Categories and Products Through Updategrams
<DeleteCatProducts xmlns:updg="urn:schemas-microsoft-com:xml-updategram"> <updg:sync> <updg:before> <Products ProductName="New Product" /> <Categories CategoryName="More Category" /> <Categories CategoryName="New Category" /> </updg:before> <updg:after> </updg:after> </updg:sync> </DeleteCatProducts>
CAUTION
Be careful with how you define the before image in the updategram. Remember that this is the WHERE clause of your DELETE statement.