ADO Support for OpenXML
OpenXML is a SQL Server 2000 extension to Transact-SQL that allows stored procedures to process XML and generate rowsets from the data for use by Transact-SQL statements. In the following example, ADO passes an XML document to a stored procedure. The stored procedure executes a SELECT statement generating a rowset. This rowset can then be processed by the stored procedure, or returned to the client as an ADO Recordset.
To use stored procedures to process XML:
- Execute the sp_xml_preparedocument stored procedure to prepare the XML document for use by Transact-SQL statements.
- Use the OpenXML-generated rowset in one or more queries.
- Execute sp_xml_removedocument to remove the prepared XML document from memory.
The ASP calls Command.Execute to execute the stored procedure, and passes in the XML document. The application then executes sp_xml_preparedocument to create an in-memory representation of the XML document. sp_xml_preparedocument has an output parameter (@iDoc, int), which is a pointer to the prepared XML document, and an input parameter (@XMLDoc, VarChar(2000), which contains the text of an XML document to be accessed using T-SQL statements.
EXECUTE sp_xml_preparedocument @iDoc OUTPUT, @XMLDoc
In this SELECT statement, the application passes in the @iDoc handle, an XPath command '/Root/Customers', a flag '1' indicating that the XML is attribute-centric, and a WITH clause describing the structure of the rowset to be returned.
SELECT * FROM OpenXML(@iDoc, '/ROOT/Customers',1)
WITH (CustomerID varchar(10), ContactName varchar(20))
Any Transact-SQL statement that operates with a rowset can be used with the OpenXML keyword. For example, an application can also use INSERT, UPDATE, DELETE, and JOIN statements.
After the application completes processing of the in-memory XML document, it releases the document by passing the @iDoc parameter to sp_xml_removedocument:
EXECUTE sp_xml_removedocument @iDoc
For more information about OpenXML, see Writing XML Using OpenXML.
Example
This is the complete listing of the stored procedure discussed previously.
CREATE PROCEDURE SP_OpenXML_Example
@XMLDoc varchar(2000)
AS
DECLARE @ReturnCode INT
DECLARE @iDoc int
EXECUTE sp_xml_preparedocument @iDoc OUTPUT, @XMLDoc
SELECT * FROM OpenXML(@iDoc, '/ROOT/Customers',1)
WITH (CustomerID varchar(10), ContactName varchar(20))
EXECUTE sp_xml_removedocument @iDoc
SELECT @ReturnCode = 1
RETURN @ReturnCode
GO
Active Server Page
This is the complete listing of the ASP discussed previously.
<HTML>
<HEAD>
<META NAME="GENERATOR" Content="Microsoft Developer Studio"/>
<META HTTP-EQUIV="Content-Type" content="text/html" charset="iso-8859-1"/>
<TITLE>ADO 2.6 OpenXML Example - OpenXML.asp</TITLE>
<STYLE>
BODY
{
FONT-FAMILY: Tahoma;
FONT-SIZE: 8pt;
OVERFLOW: auto
}
H3
{
FONT-FAMILY: Tahoma;
FONT-SIZE: 8pt;
OVERFLOW: auto
}
</STYLE>
<!-- #include file="adovbs.inc" -->
<%
Response.Write "Page Generated @ " & Now() & "<BR/>"
Dim sConn
sConn = "Provider=SQLOLEDB;Data Source=MYSERVER1;Initial Catalog=Northwind;User ID=SA;Password=;"
Response.write "Connect String = " & sConn & "<BR/>"
Dim adoConn
Set adoConn = Server.CreateObject("ADODB.Connection")
adoConn.ConnectionString = sConn
adoConn.CursorLocation = adUseClient
adoConn.Open
Response.write "ADO Version = " & adoConn.Version & "<BR/>"
Response.write "adoConn.State = " & adoConn.State & "<BR/>"
Dim sXMLDoc, sQuery
sXMLDoc = "<ROOT>"
sXMLDoc = sXMLDoc & "<Customers CustomerID='VINET' ContactName='Paul Henriot'>"
sXMLDoc = sXMLDoc & "<Orders CustomerID='VINET' EmployeeID='5' OrderDate='1996-07-04T00:00:00'>"
sXMLDoc = sXMLDoc & "<Order_0020_Details OrderID='10248' ProductID='11' Quantity='12'/>"
sXMLDoc = sXMLDoc & "<Order_0020_Details OrderID='10248' ProductID='42' Quantity='10'/>"
sXMLDoc = sXMLDoc & "</Orders>"
sXMLDoc = sXMLDoc & "</Customers>"
sXMLDoc = sXMLDoc & "<Customers CustomerID='LILAS' ContactName='Carlos Gonzlez'>"
sXMLDoc = sXMLDoc & "<Orders CustomerID='LILAS' EmployeeID='3' OrderDate='1996-08-16T00:00:00'>"
sXMLDoc = sXMLDoc & "<Order_0020_Details OrderID='10283' ProductID='72' Quantity='3'/>"
sXMLDoc = sXMLDoc & "</Orders>"
sXMLDoc = sXMLDoc & "</Customers>"
sXMLDoc = sXMLDoc & "</ROOT>"
sQuery = "SP_OpenXML_Example"
Response.write "sQuery = " & sQuery & "<BR/>"
Dim adoCmd
Set adoCmd = Server.CreateObject("ADODB.Command")
Set adoCmd.ActiveConnection = adoConn
adoCmd.CommandText = sQuery
adoCmd.CommandType = adCmdStoredProc
adoCmd.Parameters.Refresh
adoCmd.Parameters.Item(1).Value = sXMLDoc
Dim adoRS
Set adoRS = adoCmd.Execute()
Response.write "Data = " & adoRS.Fields(0).Value & "<BR/>"
adoRS.Close
Response.write "ReturnValue = " & adoCmd.Parameters.Item(0).Value & "<BR/>"
%>
</HEAD>
<BODY>
</BODY>
</HTML>