Modify data with stored procedures
Applies to: .NET Framework .NET .NET Standard
Stored procedures can accept data as input parameters and can return data as output parameters, result sets, or return values. The sample below illustrates how Microsoft SqlClient Data Provider for SQL Server sends and receives input parameters, output parameters, and return values. The example inserts a new record into a table where the primary key column is an identity column.
Note
If you are using stored procedures to edit or delete data using a SqlDataAdapter, make sure that you do not use SET NOCOUNT ON in the stored procedure definition. This causes the rows affected count returned to be zero, which the DataAdapter
interprets as a concurrency conflict. In this event, a DBConcurrencyException will be thrown.
Example
The sample uses the following stored procedure to insert a new category into the Northwind Categories table. The stored procedure takes the value in the CategoryName column as an input parameter and uses the SCOPE_IDENTITY() function to retrieve the new value of the identity field, CategoryID, and return it in an output parameter. The RETURN statement uses the @@ROWCOUNT function to return the number of rows inserted.
CREATE PROCEDURE dbo.InsertCategory
@CategoryName nvarchar(15),
@Identity int OUT
AS
INSERT INTO Categories (CategoryName) VALUES(@CategoryName)
SET @Identity = SCOPE_IDENTITY()
RETURN @@ROWCOUNT
The following code example uses the InsertCategory
stored procedure shown above as the source for the InsertCommand of the SqlDataAdapter. The @Identity
output parameter will be reflected in the DataSet after the record has been inserted into the database when the Update
method of the SqlDataAdapter is called. The code also retrieves the return value.
using System;
using System.Data;
using Microsoft.Data.SqlClient;
class Program
{
static void Main()
{
string connectionString = GetConnectionString();
ReturnIdentity(connectionString);
// Console.ReadLine();
}
private static void ReturnIdentity(string connectionString)
{
using (SqlConnection connection = new SqlConnection(connectionString))
{
// Create a SqlDataAdapter based on a SELECT query.
SqlDataAdapter adapter = new SqlDataAdapter(
"SELECT CategoryID, CategoryName FROM dbo.Categories", connection);
// Create a SqlCommand to execute the stored procedure.
adapter.InsertCommand = new SqlCommand("InsertCategory", connection);
adapter.InsertCommand.CommandType = CommandType.StoredProcedure;
// Create a parameter for the ReturnValue.
SqlParameter parameter = adapter.InsertCommand.Parameters.Add("@RowCount", SqlDbType.Int);
parameter.Direction = ParameterDirection.ReturnValue;
// Create an input parameter for the CategoryName.
// You do not need to specify direction for input parameters.
adapter.InsertCommand.Parameters.Add("@CategoryName", SqlDbType.NChar, 15, "CategoryName");
// Create an output parameter for the new identity value.
parameter = adapter.InsertCommand.Parameters.Add("@Identity", SqlDbType.Int, 0, "CategoryID");
parameter.Direction = ParameterDirection.Output;
// Create a DataTable and fill it.
DataTable categories = new DataTable();
adapter.Fill(categories);
// Add a new row.
DataRow categoryRow = categories.NewRow();
categoryRow["CategoryName"] = "New Beverages";
categories.Rows.Add(categoryRow);
// Update the database.
adapter.Update(categories);
// Retrieve the ReturnValue.
Int rowCount = (Int)adapter.InsertCommand.Parameters["@RowCount"].Value;
Console.WriteLine("ReturnValue: {0}", rowCount.ToString());
Console.WriteLine("All Rows:");
foreach (DataRow row in categories.Rows)
{
Console.WriteLine(" {0}: {1}", row[0], row[1]);
}
}
}
static private string GetConnectionString()
{
// To avoid storing the connection string in your code,
// you can retrieve it from a configuration file.
return "Data Source=(local);Initial Catalog=Northwind;Integrated Security=true";
}
}