Update data sources with DataAdapters
Applies to: .NET Framework .NET .NET Standard
The Update
method of the DataAdapter is called to resolve changes from a DataSet back to the data source. The Update
method, like the Fill
method, takes as arguments an instance of a DataSet
, and an optional DataTable object or DataTable
name. The DataSet
instance is the DataSet
that contains the changes that have been made, and the DataTable
identifies the table from which to retrieve the changes. If no DataTable
is specified, the first DataTable
in the DataSet
is used.
When you call the Update
method, the DataAdapter
analyzes the changes that have been made and executes the appropriate command (INSERT, UPDATE, or DELETE). When the DataAdapter
encounters a change to a DataRow, it uses the InsertCommand, UpdateCommand, or DeleteCommand to process the change.
These properties allow you to maximize the performance of your ADO.NET application by specifying command syntax at design time and, where possible, through the use of stored procedures. You must explicitly set the commands before calling Update
. If Update
is called and the appropriate command does not exist for a particular update (for example, no DeleteCommand
for deleted rows), an exception is thrown.
Important
If you are using SQL Server stored procedures to edit or delete data using a DataAdapter
, 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.
Command parameters can be used to specify input and output values for a SQL statement or stored procedure for each modified row in a DataSet
. For more information, see DataAdapter parameters.
Note
It is important to understand the difference between deleting a row in a DataTable and removing the row. When you call the Remove
or RemoveAt
method, the row is removed immediately. Any corresponding rows in the back end data source will not be affected if you then pass the DataTable
or DataSet
to a DataAdapter
and call Update
. When you use the Delete
method, the row remains in the DataTable
and is marked for deletion. If you then pass the DataTable
or DataSet
to a DataAdapter
and call Update
, the corresponding row in the back end data source is deleted.
If your DataTable
maps to or is generated from a single database table, you can take advantage of the DbCommandBuilder object to automatically generate the DeleteCommand
, InsertCommand
, and UpdateCommand
objects for the DataAdapter
. For more information, see Generating commands with CommandBuilders.
Use UpdatedRowSource to map values to a DataSet
You can control how the values returned from the data source are mapped back to the DataTable
following a call to the Update method of a DataAdapter
, by using the UpdatedRowSource property of a SqlCommand object. By setting the UpdatedRowSource
property to one of the UpdateRowSource enumeration values, you can control whether output parameters returned by the DataAdapter
commands are ignored or applied to the changed row in the DataSet
. You can also specify whether the first returned row (if it exists) is applied to the changed row in the DataTable
.
The following table describes the different values of the UpdateRowSource
enumeration and how they affect the behavior of a command used with a DataAdapter
.
UpdatedRowSource Enumeration | Description |
---|---|
Both | Both the output parameters and the first row of a returned result set may be mapped to the changed row in the DataSet . |
FirstReturnedRecord | Only the data in the first row of a returned result set may be mapped to the changed row in the DataSet . |
None | Any output parameters or rows of a returned result set are ignored. |
OutputParameters | Only output parameters may be mapped to the changed row in the DataSet . |
The Update
method resolves your changes back to the data source; however other clients may have modified data at the data source since the last time you filled the DataSet
. To refresh your DataSet
with current data, use the DataAdapter
and Fill
method. New rows will be added to the table, and updated information will be incorporated into existing rows.
The Fill
method determines whether a new row will be added or an existing row will be updated by examining the primary key values of the rows in the DataSet
and the rows returned by the SelectCommand
. If the Fill
method encounters a primary key value for a row in the DataSet
that matches a primary key value from a row in the results returned by the SelectCommand
, it updates the existing row with the information from the row returned by the SelectCommand
and sets the RowState of the existing row to Unchanged
. If a row returned by the SelectCommand
has a primary key value that does not match any of the primary key values of the rows in the DataSet
, the Fill
method adds a new row with a RowState
of Unchanged
.
Note
If the SelectCommand
returns the results of an OUTER JOIN, the DataAdapter
will not set a PrimaryKey
value for the resulting DataTable
. You must define the PrimaryKey
yourself to ensure that duplicate rows are resolved correctly.
To handle exceptions that may occur when calling the Update
method, you can use the RowUpdated
event to respond to row update errors as they occur (see Handle DataAdapter events), or you can set ContinueUpdateOnError to true
before calling Update
, and respond to the error information stored in the RowError
property of a particular row when the update is complete.
Note
Calling AcceptChanges
on the DataSet
, DataTable
, or DataRow
will cause all Original
values for a DataRow
to be overwritten with the Current
values for the DataRow
. If the field values that identify the row as unique have been modified, after calling AcceptChanges
the Original
values will no longer match the values in the data source. AcceptChanges
is called automatically for each row during a call to the Update
method of a DataAdapter
. You can preserve the original values during a call to the Update method by first setting the AcceptChangesDuringUpdate
property of the DataAdapter
to false, or by creating an event handler for the RowUpdated
event and setting the Status to SkipCurrentRow. For more information, see Handle DataAdapter Events.
The following examples demonstrate how to perform updates to modified rows by explicitly setting the UpdateCommand
of a DataAdapter
and calling its Update
method.
Note
The parameter specified in the WHERE clause
of the UPDATE statement
is set to use the Original
value of the SourceColumn
. This is important, because the Current
value may have been modified and may not match the value in the data source. The Original
value is the value that was used to populate the DataTable
from the data source.
private static void AdapterUpdate(string connectionString)
{
using (SqlConnection connection =
new SqlConnection(connectionString))
{
SqlDataAdapter dataAdpater = new SqlDataAdapter(
"SELECT CategoryID, CategoryName FROM Categories",
connection);
dataAdpater.UpdateCommand = new SqlCommand(
"UPDATE Categories SET CategoryName = @CategoryName " +
"WHERE CategoryID = @CategoryID", connection);
dataAdpater.UpdateCommand.Parameters.Add(
"@CategoryName", SqlDbType.NVarChar, 15, "CategoryName");
SqlParameter parameter = dataAdpater.UpdateCommand.Parameters.Add(
"@CategoryID", SqlDbType.Int);
parameter.SourceColumn = "CategoryID";
parameter.SourceVersion = DataRowVersion.Original;
DataTable categoryTable = new DataTable();
dataAdpater.Fill(categoryTable);
DataRow categoryRow = categoryTable.Rows[0];
categoryRow["CategoryName"] = "New Beverages";
dataAdpater.Update(categoryTable);
Console.WriteLine("Rows after update.");
foreach (DataRow row in categoryTable.Rows)
{
{
Console.WriteLine("{0}: {1}", row[0], row[1]);
}
}
}
}
AutoIncrement columns
If the tables from your data source have auto-incrementing columns, you can fill the columns in your DataSet
either by returning the auto-increment value as an output parameter of a stored procedure and mapping that to a column in a table, by returning the auto-increment value in the first row of a result set returned by a stored procedure or SQL statement, or by using the RowUpdated
event of the DataAdapter
to execute an additional SELECT statement. For more information and an example, see Retrieve identity or autonumber values.
Ordering of inserts, updates, and deletes
In many circumstances, the order in which changes made through the DataSet
are sent to the data source is important. For example, if a primary key value for an existing row is updated, and a new row has been added with the new primary key value as a foreign key, it is important to process the update before the insert.
You can use the Select
method of the DataTable
to return a DataRow
array that only references rows with a particular RowState
. You can then pass the returned DataRow
array to the Update
method of the DataAdapter
to process the modified rows. By specifying a subset of rows to be updated, you can control the order in which inserts, updates, and deletes are processed.
Example
For example, the following code ensures that the deleted rows of the table are processed first, then the updated rows, and then the inserted rows.
// Assumes that dataSet and adapter are valid objects.
DataTable table = dataSet.Tables["Customers"];
// First process deletes.
adapter.Update(table.Select(null, null, DataViewRowState.Deleted));
// Next process updates.
adapter.Update(table.Select(null, null,
DataViewRowState.ModifiedCurrent));
// Finally, process inserts.
adapter.Update(table.Select(null, null, DataViewRowState.Added));
Use a DataAdapter to retrieve and update data
You can use a DataAdapter to retrieve and update the data.
The sample uses
DataAdapter.AcceptChangesDuringFill
to clone the data in the database. If the property is set as false, AcceptChanges is not called when filling the table, and the newly added rows are treated as inserted rows. So, the sample uses these rows to insert the new rows into the database.The samples uses
DataAdapter.TableMappings
to define the mapping between the source table and DataTable.The sample uses
DataAdapter.FillLoadOption
to determine how the adapter fills the DataTable from the DbDataReader. When you create a DataTable, you can only write the data from database to the current version or the original version by setting the property as the LoadOption.Upsert or the LoadOption.PreserveChanges.The sample will also update the table by using
DbDataAdapter.UpdateBatchSize
to perform batch operations.
Before you compile and run the sample, you need to create the sample database:
USE [master]
GO
CREATE DATABASE [MySchool]
GO
USE [MySchool]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Course]([CourseID] [nvarchar](10) NOT NULL,
[Year] [smallint] NOT NULL,
[Title] [nvarchar](100) NOT NULL,
[Credits] [int] NOT NULL,
[DepartmentID] [int] NOT NULL,
CONSTRAINT [PK_Course] PRIMARY KEY CLUSTERED
(
[CourseID] ASC,
[Year] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]) ON [PRIMARY]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[Department]([DepartmentID] [int] IDENTITY(1,1) NOT NULL,
[Name] [nvarchar](50) NOT NULL,
[Budget] [money] NOT NULL,
[StartDate] [datetime] NOT NULL,
[Administrator] [int] NULL,
CONSTRAINT [PK_Department] PRIMARY KEY CLUSTERED
(
[DepartmentID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]) ON [PRIMARY]
GO
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C1045', 2012, N'Calculus', 4, 7)
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C1061', 2012, N'Physics', 4, 1)
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C2021', 2012, N'Composition', 3, 2)
INSERT [dbo].[Course] ([CourseID], [Year], [Title], [Credits], [DepartmentID]) VALUES (N'C2042', 2012, N'Literature', 4, 2)
SET IDENTITY_INSERT [dbo].[Department] ON
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (1, N'Engineering', 350000.0000, CAST(0x0000999C00000000 AS DateTime), 2)
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (2, N'English', 120000.0000, CAST(0x0000999C00000000 AS DateTime), 6)
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (4, N'Economics', 200000.0000, CAST(0x0000999C00000000 AS DateTime), 4)
INSERT [dbo].[Department] ([DepartmentID], [Name], [Budget], [StartDate], [Administrator]) VALUES (7, N'Mathematics', 250024.0000, CAST(0x0000999C00000000 AS DateTime), 3)
SET IDENTITY_INSERT [dbo].[Department] OFF
ALTER TABLE [dbo].[Course] WITH CHECK ADD CONSTRAINT [FK_Course_Department] FOREIGN KEY([DepartmentID])
REFERENCES [dbo].[Department] ([DepartmentID])
GO
ALTER TABLE [dbo].[Course] CHECK CONSTRAINT [FK_Course_Department]
GO
using System;
using System.Data;
using System.Data.Common;
using Microsoft.Data.SqlClient;
using System.Linq;
using CSDataAdapterOperations.Properties;
class Program
{
static void Main(string[] args)
{
Settings settings = new Settings();
// Copy the data from the database. Get the table Department and Course from the database.
String selectString = @"SELECT [DepartmentID],[Name],[Budget],[StartDate],[Administrator]
FROM [MySchool].[dbo].[Department];
SELECT [CourseID],@Year as [Year],Max([Title]) as [Title],
Max([Credits]) as [Credits],Max([DepartmentID]) as [DepartmentID]
FROM [MySchool].[dbo].[Course]
Group by [CourseID]";
DataSet mySchool = new DataSet();
SqlCommand selectCommand = new SqlCommand(selectString);
SqlParameter parameter = selectCommand.Parameters.Add("@Year", SqlDbType.SmallInt, 2);
parameter.Value = new Random(DateTime.Now.Millisecond).Next(9999);
// Use DataTableMapping to map the source tables and the destination tables.
DataTableMapping[] tableMappings = { new DataTableMapping("Table", "Department"), new DataTableMapping("Table1", "Course") };
CopyData(mySchool, settings.MySchoolConnectionString, selectCommand, tableMappings);
Console.WriteLine("The following tables are from the database.");
foreach (DataTable table in mySchool.Tables)
{
Console.WriteLine(table.TableName);
ShowDataTable(table);
}
// Roll back the changes
DataTable department = mySchool.Tables["Department"];
DataTable course = mySchool.Tables["Course"];
department.Rows[0]["Name"] = "New" + department.Rows[0][1];
course.Rows[0]["Title"] = "New" + course.Rows[0]["Title"];
course.Rows[0]["Credits"] = 10;
Console.WriteLine("After we changed the tables:");
foreach (DataTable table in mySchool.Tables)
{
Console.WriteLine(table.TableName);
ShowDataTable(table);
}
department.RejectChanges();
Console.WriteLine("After use the RejectChanges method in Department table to roll back the changes:");
ShowDataTable(department);
DataColumn[] primaryColumns = { course.Columns["CourseID"] };
DataColumn[] resetColumns = { course.Columns["Title"] };
ResetCourse(course, settings.MySchoolConnectionString, primaryColumns, resetColumns);
Console.WriteLine("After use the ResetCourse method in Course table to roll back the changes:");
ShowDataTable(course);
// Batch update the table.
String insertString = @"Insert into [MySchool].[dbo].[Course]([CourseID],[Year],[Title],
[Credits],[DepartmentID])
values (@CourseID,@Year,@Title,@Credits,@DepartmentID)";
SqlCommand insertCommand = new SqlCommand(insertString);
insertCommand.Parameters.Add("@CourseID", SqlDbType.NVarChar, 10, "CourseID");
insertCommand.Parameters.Add("@Year", SqlDbType.SmallInt, 2, "Year");
insertCommand.Parameters.Add("@Title", SqlDbType.NVarChar, 100, "Title");
insertCommand.Parameters.Add("@Credits", SqlDbType.Int, 4, "Credits");
insertCommand.Parameters.Add("@DepartmentID", SqlDbType.Int, 4, "DepartmentID");
const Int32 batchSize = 10;
BatchInsertUpdate(course, settings.MySchoolConnectionString, insertCommand, batchSize);
}
private static void CopyData(DataSet dataSet, String connectionString, SqlCommand selectCommand, DataTableMapping[] tableMappings)
{
using (SqlConnection connection = new SqlConnection(connectionString))
{
selectCommand.Connection = connection;
connection.Open();
using (SqlDataAdapter adapter = new SqlDataAdapter(selectCommand))
{
adapter.TableMappings.AddRange(tableMappings);
// If set the AcceptChangesDuringFill as the false, AcceptChanges will not be called on a
// DataRow after it is added to the DataTable during any of the Fill operations.
adapter.AcceptChangesDuringFill = false;
adapter.Fill(dataSet);
}
}
}
// Roll back only one column or several columns data of the Course table by call ResetDataTable method.
private static void ResetCourse(DataTable table, String connectionString,
DataColumn[] primaryColumns, DataColumn[] resetColumns)
{
table.PrimaryKey = primaryColumns;
// Build the query string
String primaryCols = String.Join(",", primaryColumns.Select(col => col.ColumnName));
String resetCols = String.Join(",", resetColumns.Select(col => $"Max({col.ColumnName}) as {col.ColumnName}"));
String selectString = $"Select {primaryCols},{resetCols} from Course Group by {primaryCols}";
SqlCommand selectCommand = new SqlCommand(selectString);
ResetDataTable(table, connectionString, selectCommand);
}
// RejectChanges will roll back all changes made to the table since it was loaded, or the last time AcceptChanges
// was called. When you copy from the database, you can lose all the data after calling RejectChanges
// The ResetDataTable method rolls back one or more columns of data.
private static void ResetDataTable(DataTable table, String connectionString,
SqlCommand selectCommand)
{
using (SqlConnection connection = new SqlConnection(connectionString))
{
selectCommand.Connection = connection;
connection.Open();
using (SqlDataAdapter adapter = new SqlDataAdapter(selectCommand))
{
// The incoming values for this row will be written to the current version of each
// column. The original version of each column's data will not be changed.
adapter.FillLoadOption = LoadOption.Upsert;
adapter.Fill(table);
}
}
}
private static void BatchInsertUpdate(DataTable table, String connectionString,
SqlCommand insertCommand, Int32 batchSize)
{
using (SqlConnection connection = new SqlConnection(connectionString))
{
insertCommand.Connection = connection;
// When setting UpdateBatchSize to a value other than 1, all the commands
// associated with the SqlDataAdapter have to have their UpdatedRowSource
// property set to None or OutputParameters. An exception is thrown otherwise.
insertCommand.UpdatedRowSource = UpdateRowSource.None;
connection.Open();
using (SqlDataAdapter adapter = new SqlDataAdapter())
{
adapter.InsertCommand = insertCommand;
// Gets or sets the number of rows that are processed in each round-trip to the server.
// Setting it to 1 disables batch updates, as rows are sent one at a time.
adapter.UpdateBatchSize = batchSize;
adapter.Update(table);
Console.WriteLine("Successfully to update the table.");
}
}
}
private static void ShowDataTable(DataTable table)
{
foreach (DataColumn col in table.Columns)
{
Console.Write("{0,-14}", col.ColumnName);
}
Console.WriteLine("{0,-14}", "RowState");
foreach (DataRow row in table.Rows)
{
foreach (DataColumn col in table.Columns)
{
if (col.DataType.Equals(typeof(DateTime)))
Console.Write("{0,-14:d}", row[col]);
else if (col.DataType.Equals(typeof(Decimal)))
Console.Write("{0,-14:C}", row[col]);
else
Console.Write("{0,-14}", row[col]);
}
Console.WriteLine("{0,-14}", row.RowState);
}
}
}
namespace CSDataAdapterOperations.Properties
{
internal sealed partial class Settings : System.Configuration.ApplicationSettingsBase
{
private static readonly Settings defaultInstance =
((Settings)(System.Configuration.ApplicationSettingsBase.Synchronized(new Settings())));
public static Settings Default => defaultInstance;
[System.Configuration.ApplicationScopedSetting()]
[System.Configuration.DefaultSettingValue("Data Source=(local);Initial Catalog=MySchool;Integrated Security=True")]
public string MySchoolConnectionString => ((string)(this["MySchoolConnectionString"]));
}
}