Working with Multiple Active Result SetsĀ
Before the introduction of Multiple Active Result Sets (MARS), developers had to use either multiple connections or server-side cursors to solve certain scenarios. In addition, when multiple connections were used in a transactional situation, bound connections (with sp_getbindtoken and sp_bindsession) were required. The following scenarios show how to use a MARS-enabled connection instead of multiple connections.
Using Multiple Commands with MARS
The following Console application demonstrates how to use two SqlDataReader objects with two SqlCommand objects and a single SqlConnection object with MARS enabled.
Example
The example opens a single connection to the AdventureWorks database. Using a SqlCommand object, a SqlDataReader is created. As the reader is used, a second SqlDataReader is opened, using data from the first SqlDataReader as input to the WHERE clause for the second reader.
Note
The following example uses the sample AdventureWorks database included with SQL Server 2005. The connection string provided in the sample code assumes that the database is installed and available on the local computer. Modify the connection string as necessary for your environment.
Option Strict On
Option Explicit On
Imports System
Imports System.Data
Imports System.Data.SqlClient
Module Module1
Sub Main()
' By default, MARS is disabled when connecting
' to a MARS-enabled host such as SQL Server 2005.
' It must be enabled in the connection string.
Dim connectionString As String = GetConnectionString()
Dim vendorID As Integer
Dim vendorCmd As SqlCommand
Dim productCmd As SqlCommand
Dim productReader As SqlDataReader
Dim vendorSQL As String = & _
"SELECT VendorId, Name FROM Purchasing.Vendor"
Dim productSQL As String = _
"SELECT Production.Product.Name FROM Production.Product " & _
"INNER JOIN Purchasing.ProductVendor " & _
"ON Production.Product.ProductID = " & _
"Purchasing.ProductVendor.ProductID " & _
"WHERE Purchasing.ProductVendor.VendorID = @VendorId"
Using awConnection As New SqlConnection(connectionString)
vendorCmd = New SqlCommand(vendorSQL, awConnection)
productCmd = New SqlCommand(productSQL, awConnection)
productCmd.Parameters.Add("@VendorId", SqlDbType.Int)
awConnection.Open()
Using vendorReader As SqlDataReader = vendorCmd.ExecuteReader()
While vendorReader.Read()
Console.WriteLine(vendorReader("Name"))
vendorID = CInt(vendorReader("VendorId"))
productCmd.Parameters("@VendorId").Value = vendorID
' The following line of code requires
' a MARS-enabled connection.
productReader = productCmd.ExecuteReader()
Using productReader
While productReader.Read()
Console.WriteLine(" " & CStr(productReader("Name")))
End While
End Using
End While
End Using
End Using
Console.WriteLine("Press any key to continue")
Console.ReadLine()
End Sub
Function GetConnectionString() As String
' To avoid storing the connection string in your code,
' you can retrive it from a configuration file.
Return "Data Source=(local);Integrated Security=SSPI;" & _
"Initial Catalog=AdventureWorks; MultipleActiveResultSets=True"
End Function
End Module
using System;
using System.Data;
using System.Data.SqlClient;
class Class1
{
static void Main()
{
// By default, MARS is disabled when connecting
// to a MARS-enabled host such as SQL Server 2005.
// It must be enabled in the connection string.
string connectionString = GetConnectionString();
int vendorID;
SqlDataReader productReader = null;
string vendorSQL =
"SELECT VendorId, Name FROM Purchasing.Vendor";
string productSQL =
"SELECT Production.Product.Name FROM Production.Product " +
"INNER JOIN Purchasing.ProductVendor " +
"ON Production.Product.ProductID = " +
"Purchasing.ProductVendor.ProductID " +
"WHERE Purchasing.ProductVendor.VendorID = @VendorId";
using (SqlConnection awConnection =
new SqlConnection(connectionString))
{
SqlCommand vendorCmd = new SqlCommand(vendorSQL, awConnection);
SqlCommand productCmd =
new SqlCommand(productSQL, awConnection);
productCmd.Parameters.Add("@VendorId", SqlDbType.Int);
awConnection.Open();
using (SqlDataReader vendorReader = vendorCmd.ExecuteReader())
{
while (vendorReader.Read())
{
Console.WriteLine(vendorReader["Name"]);
vendorID = (int)vendorReader["VendorId"];
productCmd.Parameters["@VendorId"].Value = vendorID;
// The following line of code requires
// a MARS-enabled connection.
productReader = productCmd.ExecuteReader();
using (productReader)
{
while (productReader.Read())
{
Console.WriteLine(" " +
productReader["Name"].ToString());
}
}
}
}
Console.WriteLine("Press any key to continue");
Console.ReadLine();
}
}
private static string GetConnectionString()
{
// To avoid storing the connection string in your code,
// you can retrive it from a configuration file.
return "Data Source=(local);Integrated Security=SSPI;" +
"Initial Catalog=AdventureWorks;MultipleActiveResultSets=True";
}
}
Reading and Updating Data with MARS
MARS allows a connection to be used for both read operations and data manipulation language (DML) operations with more than one pending operation. This feature eliminates the need for an application to deal with connection-busy errors. In addition, MARS can replace the user of server-side cursors, which generally consume more resources. Finally, because multiple operations can operate on a single connection, they can share the same transaction context, eliminating the need to use sp_getbindtoken and sp_bindsession system stored procedures.
Example
The following Console application demonstrates how to use two SqlDataReader objects with three SqlCommand objects and a single SqlConnection object with MARS enabled. The first command object retrieves a list of vendors whose credit rating is 5. The second command object uses the vendor ID provided from a SqlDataReader to load the second SqlDataReader with all of the products for the particular vendor. Each product record is visited by the second SqlDataReader. A calculation is performed to determine what the new OnOrderQty should be. The third command object is then used to update the ProductVendor table with the new value. This entire process takes place within a single transaction, which is rolled back at the end.
Note
The following example uses the sample AdventureWorks database included with SQL Server 2005. The connection string provided in the sample code assumes that the database is installed and available on the local computer. Modify the connection string as necessary for your environment.
Option Strict On
Option Explicit On
Imports System
Imports System.Data
Imports System.Data.SqlClient
Module Module1
Sub Main()
' By default, MARS is disabled when connecting
' to a MARS-enabled host such as SQL Server 2005.
' It must be enabled in the connection string.
Dim connectionString As String = GetConnectionString()
Dim updateTx As SqlTransaction
Dim vendorCmd As SqlCommand
Dim prodVendCmd As SqlCommand
Dim updateCmd As SqlCommand
Dim prodVendReader As SqlDataReader
Dim vendorID As Integer
Dim productID As Integer
Dim minOrderQty As Integer
Dim maxOrderQty As Integer
Dim onOrderQty As Integer
Dim recordsUpdated As Integer
Dim totalRecordsUpdated As Integer
Dim vendorSQL As String = _
"SELECT VendorID, Name FROM Purchasing.Vendor " & _
"WHERE CreditRating = 5"
Dim prodVendSQL As String = _
"SELECT ProductID, MaxOrderQty, MinOrderQty, OnOrderQty " & _
"FROM Purchasing.ProductVendor " & _
"WHERE VendorID = @VendorID"
Dim updateSQL As String = _
"UPDATE Purchasing.ProductVendor " & _
"SET OnOrderQty = @OrderQty " & _
"WHERE ProductID = @ProductID AND VendorID = @VendorID"
Using awConnection As New SqlConnection(connectionString)
awConnection.Open()
updateTx = awConnection.BeginTransaction()
vendorCmd = New SqlCommand(vendorSQL, awConnection)
vendorCmd.Transaction = updateTx
prodVendCmd = New SqlCommand(prodVendSQL, awConnection)
prodVendCmd.Transaction = updateTx
prodVendCmd.Parameters.Add("@VendorId", SqlDbType.Int)
updateCmd = New SqlCommand(updateSQL, awConnection)
updateCmd.Transaction = updateTx
updateCmd.Parameters.Add("@OrderQty", SqlDbType.Int)
updateCmd.Parameters.Add("@ProductID", SqlDbType.Int)
updateCmd.Parameters.Add("@VendorID", SqlDbType.Int)
Using vendorReader As SqlDataReader = vendorCmd.ExecuteReader()
While vendorReader.Read()
Console.WriteLine(vendorReader("Name"))
vendorID = CInt(vendorReader("VendorID"))
prodVendCmd.Parameters("@VendorID").Value = vendorID
prodVendReader = prodVendCmd.ExecuteReader()
Using prodVendReader
While (prodVendReader.Read)
productID = CInt(prodVendReader("ProductID"))
If IsDBNull(prodVendReader("OnOrderQty")) Then
minOrderQty = CInt(prodVendReader("MinOrderQty"))
onOrderQty = minOrderQty
Else
maxOrderQty = CInt(prodVendReader("MaxOrderQty"))
onOrderQty = CInt(maxOrderQty / 2)
End If
updateCmd.Parameters("@OrderQty").Value = onOrderQty
updateCmd.Parameters("@ProductID").Value = productID
updateCmd.Parameters("@VendorID").Value = vendorID
recordsUpdated = updateCmd.ExecuteNonQuery()
totalRecordsUpdated += recordsUpdated
End While
End Using
End While
End Using
Console.WriteLine("Total Records Updated: " & _
CStr(totalRecordsUpdated))
updateTx.Rollback()
Console.WriteLine("Transaction Rolled Back")
End Using
Console.WriteLine("Press any key to continue")
Console.ReadLine()
End Sub
Function GetConnectionString() As String
' To avoid storing the connection string in your code,
' you can retrive it from a configuration file.
Return "Data Source=(local);Integrated Security=SSPI;" & _
"Initial Catalog=AdventureWorks;MultipleActiveResultSets=True"
End Function
End Module
using System;
using System.Collections.Generic;
using System.Text;
using System.Data;
using System.Data.SqlClient;
class Program
{
static void Main()
{
// By default, MARS is disabled when connecting
// to a MARS-enabled host such as SQL Server 2005.
// It must be enabled in the connection string.
string connectionString = GetConnectionString();
SqlTransaction updateTx = null;
SqlCommand vendorCmd = null;
SqlCommand prodVendCmd = null;
SqlCommand updateCmd = null;
SqlDataReader prodVendReader = null;
int vendorID = 0;
int productID = 0;
int minOrderQty = 0;
int maxOrderQty = 0;
int onOrderQty = 0;
int recordsUpdated = 0;
int totalRecordsUpdated = 0;
string vendorSQL =
"SELECT VendorID, Name FROM Purchasing.Vendor " +
"WHERE CreditRating = 5";
string prodVendSQL =
"SELECT ProductID, MaxOrderQty, MinOrderQty, OnOrderQty " +
"FROM Purchasing.ProductVendor " +
"WHERE VendorID = @VendorID";
string updateSQL =
"UPDATE Purchasing.ProductVendor " +
"SET OnOrderQty = @OrderQty " +
"WHERE ProductID = @ProductID AND VendorID = @VendorID";
using (SqlConnection awConnection =
new SqlConnection(connectionString))
{
awConnection.Open();
updateTx = awConnection.BeginTransaction();
vendorCmd = new SqlCommand(vendorSQL, awConnection);
vendorCmd.Transaction = updateTx;
prodVendCmd = new SqlCommand(prodVendSQL, awConnection);
prodVendCmd.Transaction = updateTx;
prodVendCmd.Parameters.Add("@VendorId", SqlDbType.Int);
updateCmd = new SqlCommand(updateSQL, awConnection);
updateCmd.Transaction = updateTx;
updateCmd.Parameters.Add("@OrderQty", SqlDbType.Int);
updateCmd.Parameters.Add("@ProductID", SqlDbType.Int);
updateCmd.Parameters.Add("@VendorID", SqlDbType.Int);
using (SqlDataReader vendorReader = vendorCmd.ExecuteReader())
{
while (vendorReader.Read())
{
Console.WriteLine(vendorReader["Name"]);
vendorID = (int) vendorReader["VendorID"];
prodVendCmd.Parameters["@VendorID"].Value = vendorID;
prodVendReader = prodVendCmd.ExecuteReader();
using (prodVendReader)
{
while (prodVendReader.Read())
{
productID = (int) prodVendReader["ProductID"];
if (prodVendReader["OnOrderQty"] == DBNull.Value)
{
minOrderQty = (int) prodVendReader["MinOrderQty"];
onOrderQty = minOrderQty;
}
else
{
maxOrderQty = (int) prodVendReader["MaxOrderQty"];
onOrderQty = (int)(maxOrderQty / 2);
}
updateCmd.Parameters["@OrderQty"].Value = onOrderQty;
updateCmd.Parameters["@ProductID"].Value = productID;
updateCmd.Parameters["@VendorID"].Value = vendorID;
recordsUpdated = updateCmd.ExecuteNonQuery();
totalRecordsUpdated += recordsUpdated;
}
}
}
}
Console.WriteLine("Total Records Updated: " +
totalRecordsUpdated.ToString());
updateTx.Rollback();
Console.WriteLine("Transaction Rolled Back");
}
Console.WriteLine("Press any key to continue");
Console.ReadLine();
}
private static string GetConnectionString()
{
// To avoid storing the connection string in your code,
// you can retrive it from a configuration file.
return "Data Source=(local);Integrated Security=SSPI;" +
"Initial Catalog=AdventureWorks;" +
"MultipleActiveResultSets=True";
}
}