Upravit

Sdílet prostřednictvím


DataAdapter parameters

Applies to: .NET Framework .NET .NET Standard

Download ADO.NET

The DbDataAdapter has four properties that are used to retrieve data from and update data to the data source: the SelectCommand property returns data from the data source; and the InsertCommand , UpdateCommand, and DeleteCommand properties are used to manage changes at the data source.

Note

The SelectCommand property must be set before you call the Fill method of the DataAdapter. The InsertCommand, UpdateCommand, or DeleteCommand properties must be set before the Update method of the DataAdapter is called, depending on what changes were made to the data in the DataTable. For example, if rows have been added, the InsertCommand must be set before you call Update. When Update is processing an inserted, updated, or deleted row, the DataAdapter uses the respective Command property to process the action. Current information about the modified row is passed to the Command object through the Parameters collection.

When you update a row at the data source, you call the UPDATE statement, which uses a unique identifier to identify the row in the table to be updated. The unique identifier is typically the value of a primary key field. The UPDATE statement uses parameters that contain both the unique identifier and the columns and values to be updated, as shown in the following Transact-SQL statement.

UPDATE Customers SET CompanyName = @CompanyName
  WHERE CustomerID = @CustomerID  

Note

The syntax for parameter placeholders depends on the data source. This example shows placeholders for a SQL Server data source.

In this example, the CompanyName field is updated with the value of the @CompanyName parameter for the row where CustomerID equals the value of the @CustomerID parameter. The parameters retrieve information from the modified row using the SourceColumn property of the SqlParameter object. The following are the parameters for the previous sample UPDATE statement. The code assumes that the variable adapter represents a valid SqlDataAdapter object.

// Assumes that connection is a valid SqlAdapter object
adapter.UpdateCommand.Parameters.Add("@CompanyName", 
            SqlDbType.VarChar, 15, "CompanyName");
SqlParameter parameter = adapter.UpdateCommand.Parameters.Add("@CustomerID",
            SqlDbType.Char, 5, "CustomerID");
parameter.SourceVersion = DataRowVersion.Original;

The Add method of the Parameters collection takes the name of the parameter, the data type, the size (if applicable to the type), and the name of the SourceColumn from the DataTable. Notice that the SourceVersion of the @CustomerID parameter is set to Original. This guarantees that the existing row in the data source is updated if the value of the identifying column or columns has been changed in the modified DataRow. In that case, the Original row value would match the current value at the data source, and the Current row value would contain the updated value. The SourceVersion for the @CompanyName parameter is not set and uses the default, Current row value.

Note

For both the Fill operations of the DataAdapter and the Get methods of the DataReader, the .NET type is inferred from the type returned from the Microsoft SqlClient Data Provider for SQL Server. The inferred .NET types and accessor methods for Microsoft SQL Server data types are described in Data Type Mappings in ADO.NET.

Parameter.SourceColumn, Parameter.SourceVersion

The SourceColumn and SourceVersion may be passed as arguments to the Parameter constructor, or set as properties of an existing Parameter. The SourceColumn is the name of the DataColumn from the DataRow where the value of the Parameter will be retrieved. The SourceVersion specifies the DataRow version that the DataAdapter uses to retrieve the value.

The following table shows the DataRowVersion enumeration values available for use with SourceVersion.

DataRowVersion Enumeration Description
Current The parameter uses the current value of the column. This is the default.
Default The parameter uses the DefaultValue of the column.
Original The parameter uses the original value of the column.
Proposed The parameter uses a proposed value.

The SqlClient code example in the next section defines a parameter for an UpdateCommand in which the CustomerID column is used as a SourceColumn for two parameters: @CustomerID (SET CustomerID = @CustomerID), and @OldCustomerID (WHERE CustomerID = @OldCustomerID). The @CustomerID parameter is used to update the CustomerID column to the current value in the DataRow. As a result, the CustomerID SourceColumn with a SourceVersion of Current is used. The @OldCustomerID parameter is used to identify the current row in the data source. Because the matching column value is found in the Original version of the row, the same SourceColumn (CustomerID) with a SourceVersion of Original is used.

Work with SqlClient parameters

The following example demonstrates how to create a SqlDataAdapter and set the MissingSchemaAction to AddWithKey in order to retrieve additional schema information from the database. The SelectCommand, InsertCommand, UpdateCommand, and DeleteCommand properties set and their corresponding SqlParameter objects added to the Parameters collection. The method returns a SqlDataAdapter object.

public static SqlDataAdapter CreateSqlDataAdapter(SqlConnection connection)
{
    // Assumes that connection is a valid SqlConnection object
    SqlDataAdapter adapter = new SqlDataAdapter();
    adapter.MissingSchemaAction = MissingSchemaAction.AddWithKey;

    // Create the commands.
    adapter.SelectCommand = new SqlCommand(
        "SELECT CustomerID, CompanyName FROM CUSTOMERS", connection);
    adapter.InsertCommand = new SqlCommand(
        "INSERT INTO Customers (CustomerID, CompanyName) " +
        "VALUES (@CustomerID, @CompanyName)", connection);
    adapter.UpdateCommand = new SqlCommand(
        "UPDATE Customers SET CustomerID = @CustomerID, CompanyName = @CompanyName " +
        "WHERE CustomerID = @oldCustomerID", connection);
    adapter.DeleteCommand = new SqlCommand(
        "DELETE FROM Customers WHERE CustomerID = @CustomerID", connection);

    // Create the parameters.
    adapter.InsertCommand.Parameters.Add("@CustomerID",
        SqlDbType.Char, 5, "CustomerID");
    adapter.InsertCommand.Parameters.Add("@CompanyName",
        SqlDbType.VarChar, 40, "CompanyName");

    adapter.UpdateCommand.Parameters.Add("@CustomerID",
        SqlDbType.Char, 5, "CustomerID");
    adapter.UpdateCommand.Parameters.Add("@CompanyName",
        SqlDbType.VarChar, 40, "CompanyName");
    adapter.UpdateCommand.Parameters.Add("@oldCustomerID",
        SqlDbType.Char, 5, "CustomerID").SourceVersion =
        DataRowVersion.Original;

    adapter.DeleteCommand.Parameters.Add("@CustomerID",
        SqlDbType.Char, 5, "CustomerID").SourceVersion =
        DataRowVersion.Original;

    return adapter;
}

See also