Actualizar columnas de UDT con DataAdapters
Los tipos definidos por el usuario (UDT) se admiten utilizando System.Data.DataSet y System.Data.SqlClient.SqlDataAdapter para recuperar y modificar los datos.
Rellenar un conjunto de datos
Puede utilizar la instrucción SELECT de Transact-SQL para seleccionar los valores de columna UDT y rellenar un conjunto de datos mediante un adaptador de datos. El ejemplo siguiente supone que tiene una tabla Points definida con la siguiente estructura y algunos datos de ejemplo. Las siguientes instrucciones Transact-SQL crean la tabla Points e insertan algunas filas.
CREATE TABLE dbo.Points (id int PRIMARY Key, p Point);
INSERT INTO dbo.Points VALUES (1, CONVERT(Point, '1,3'));
INSERT INTO dbo.Points VALUES (2, CONVERT(Point, '2,4'));
INSERT INTO dbo.Points VALUES (3, CONVERT(Point, '3,5'));
INSERT INTO dbo.Points VALUES (4, CONVERT(Point, '4,6'));
GO
El siguiente fragmento de código ADO.NET recupera una cadena de conexión válida, crea un nuevo SqlDataAdaptery rellena System.Data.DataTable con las filas de datos de la tabla Points.
Dim da As New SqlDataAdapter( _
"SELECT id, p FROM dbo.Points", connectionString)
Dim datTable As New DataTable("Points")
da.Fill(datTable)
SqlDataAdapter da = new SqlDataAdapter(
"SELECT id, p FROM dbo.Points", connectionString);
DataTable datTable = new DataTable("Points");
da.Fill(datTable);
Actualizar datos UDT en un conjunto de datos
Puede utilizar dos métodos para actualizar una columna UDT de un DataSet:
Proporcione objetos InsertCommand, UpdateCommand y DeleteCommand personalizados para un objeto SqlDataAdapter.
Utilice el generador de comandos (System.Data.SqlClient.SqlCommandBuilder) para crear automáticamente los comandos INSERT, UPDATE y DELETE. Para disponer de detección de conflictos, agregue una columna timestamp (alias rowversion) a la tabla de SQL Server que contiene el UDT. El tipo de datos timestamp permite marcar la versión de las filas de una tabla con una garantía de exclusividad dentro de una base de datos. Cuando se cambia un valor de la tabla, SQL Server actualiza automáticamente el número binario de ocho bytes correspondiente a la fila afectada por el cambio.
Tenga en cuenta que SqlCommandBuilder no tiene en cuenta el UDT en la detección de conflictos si no hay una columna timestamp en la tabla subyacente. Los UDT pueden o no ser comparables, por lo que se incluyen en la cláusula WHERE cuando se utiliza la opción de comparación de valores originales para generar un comando.
Ejemplo
El ejemplo siguiente requiere crear una segunda tabla con la columna UDT Point así como una columna timestamp. Ambas tablas se utilizan para mostrar cómo se crean objetos de comando personalizados para actualizar datos y cómo se actualiza con una columna timestamp. Ejecute las siguientes instrucciones Transact-SQL para crear la segunda tabla y rellenarla con datos de ejemplo.
CREATE TABLE dbo.Points_ts (id int PRIMARY KEY, p Point, ts timestamp);
INSERT INTO dbo.Points_ts (id, p) VALUES (1, CONVERT(Point, '1,3'));
INSERT INTO dbo.Points_ts (id, p) VALUES (2, CONVERT(Point, '2,4'));
INSERT INTO dbo.Points_ts (id, p) VALUES (3, CONVERT(Point, '3,5'));
INSERT INTO dbo.Points_ts (id, p) VALUES (4, CONVERT(Point, '4,6'));
El siguiente ejemplo de ADO.NET incluye dos métodos:
UserProvidedCommands, que muestra cómo proporcionar objetos InsertCommand, UpdateCommand y DeleteCommandpara actualizar el UDT Point de la tabla Points (que no contiene ninguna columna timestamp).
CommandBuilder, que muestra cómo utilizar SqlCommandBuilder en la tabla Points_ts que contiene la columna timestamp.
Imports System
Imports System.Data
Imports System.Data.SqlClient
Module Module1
' Retrieves the connection string
Private connString As String = GetConnectionString()
Sub Main()
UserProvidedCommands()
CommandBuilder()
End Sub
Private Sub UserProvidedCommands()
' Create a new SqlDataAdapter
Dim da As New SqlDataAdapter( _
"SELECT id, p FROM dbo.Points", connString)
' Setup the INSERT/UPDATE/DELETE commands
Dim idParam As SqlParameter
Dim pointParam As SqlParameter
da.InsertCommand = New SqlCommand( _
"INSERT INTO dbo.Points (id, p) VALUES (@id, @p)", _
da.SelectCommand.Connection)
idParam = da.InsertCommand.Parameters.Add( _
"@id", SqlDbType.Int)
idParam.SourceColumn = "id"
pointParam = da.InsertCommand.Parameters.Add( _
"@p", SqlDbType.Udt)
pointParam.SourceColumn = "p"
pointParam.UdtTypeName = "dbo.Point"
da.UpdateCommand = New SqlCommand( _
"UPDATE dbo.Points SET p = @p WHERE id = @id", _
da.SelectCommand.Connection)
idParam = _
da.UpdateCommand.Parameters.Add("@id", SqlDbType.Int)
idParam.SourceColumn = "id"
pointParam = da.UpdateCommand.Parameters.Add( _
"@p", SqlDbType.Udt)
pointParam.SourceColumn = "p"
pointParam.UdtTypeName = "dbo.Point"
da.DeleteCommand = New SqlCommand( _
"DELETE dbo.Points WHERE id = @id", _
da.SelectCommand.Connection)
idParam = da.DeleteCommand.Parameters.Add( _
"@id", SqlDbType.Int)
idParam.SourceColumn = "id"
' Fill the DataTable with UDT rows
Dim datTable As New DataTable("Points")
da.Fill(datTable)
' Display the contents of the p (Point) column
Dim r As DataRow
For Each r In datTable.Rows
Dim p As Point = CType(r(1), Point)
Console.WriteLine( _
"ID: {0}, x={1}, y={1}", r(0), p.X, p.Y)
Next r
' Update a row if the DataTable has at least 1 row
If datTable.Rows.Count > 0 Then
Dim oldPoint As Point = _
CType(datTable.Rows(0)(1), Point)
datTable.Rows(0)(1) = _
New Point(oldPoint.X + 1, oldPoint.Y + 1)
End If
' Delete the last row
If datTable.Rows.Count > 0 Then
' If we have at least 1 row
datTable.Rows(1).Delete()
End If
' Insert a row. This will fail if run twice
' because 100 is a primary key value.
datTable.Rows.Add(100, New Point(100, 200))
' Send the changes back to the database
da.Update(datTable)
End Sub
Private Sub CommandBuilder()
' Create a new SqlDataAdapter
Dim da As New SqlDataAdapter( _
"SELECT id, ts, p FROM dbo.Points_ts", connString)
' Select a few rows with UDTs from the database
Dim datTable As New DataTable("Points")
da.Fill(datTable)
' Display the contents of the p (Point) column
Dim r As DataRow
For Each r In datTable.Rows
Dim p As Point = CType(r(2), Point)
Console.WriteLine( _
"ID: {0}, x={1}, y={1}", r(0), p.X, p.Y)
Next r
' Update a row if DataTable has at least 1 row
If datTable.Rows.Count > 0 Then
Dim oldPoint As Point = _
CType(datTable.Rows(0)(2), Point)
datTable.Rows(0)(2) = _
New Point(oldPoint.X + 1, oldPoint.Y + 1)
End If
' Delete the last row
If datTable.Rows.Count > 0 Then
' if we have at least 1 row
datTable.Rows(1).Delete()
End If
' Insert a row. This will fail if run twice
' because 100 is a primary key value
datTable.Rows.Add(100, Nothing, New Point(100, 200))
' Use the CommandBuilder to generate DML statements
Dim bld As New SqlCommandBuilder(da)
bld.ConflictDetection = ConflictOptions.CompareRowVersion
' Send the changes back to the database
da.Update(datTable)
End Sub
Private Function GetConnectionString() As String
' To avoid storing the connection string in your code,
' you can retrieve it from a configuration file.
Return "Data Source=(local);Initial Catalog=AdventureWorks;" _
& "Integrated Security=SSPI"
End Function
End Module
using System;
using System.Data;
using System.Data.SqlClient;
class Class1
{
// Retrieves the connection string
private string connString = GetConnectionString();
static void Main()
{
UserProvidedCommands();
CommandBuilder();
}
static void UserProvidedCommands()
{
// Create a new SqlDataAdapter
SqlDataAdapter da = new SqlDataAdapter(
"SELECT id, p FROM dbo.Points", connString);
// Setup the INSERT/UPDATE/DELETE commands
SqlParameter idParam;
SqlParameter pointParam;
da.InsertCommand = new SqlCommand(
"INSERT INTO dbo.Points (id, p) VALUES (@id, @p)",
da.SelectCommand.Connection);
idParam =
da.InsertCommand.Parameters.Add("@id", SqlDbType.Int);
idParam.SourceColumn = "id";
pointParam =
da.InsertCommand.Parameters.Add("@p", SqlDbType.Udt);
pointParam.SourceColumn = "p";
pointParam.UdtTypeName = "dbo.Point";
da.UpdateCommand = new SqlCommand(
"UPDATE dbo.Points SET p = @p WHERE id = @id",
da.SelectCommand.Connection);
idParam =
da.UpdateCommand.Parameters.Add("@id", SqlDbType.Int);
idParam.SourceColumn = "id";
pointParam =
da.UpdateCommand.Parameters.Add("@p", SqlDbType.Udt);
pointParam.SourceColumn = "p";
pointParam.UdtTypeName = "dbo.Point";
da.DeleteCommand = new SqlCommand(
"DELETE dbo.Points WHERE id = @id",
da.SelectCommand.Connection);
idParam =
da.DeleteCommand.Parameters.Add("@id", SqlDbType.Int);
idParam.SourceColumn = "id";
// Fill the DataTable with UDT rows
DataTable datTable = new DataTable("Points");
da.Fill(datTable);
// Display the contents of the p (Point) column
foreach(DataRow r in datTable.Rows)
{
Point p = (Point)r[1];
Console.WriteLine(
"ID: {0}, x={1}, y={1}", r[0], p.X, p.Y);
}
// Update a row if the DataTable has at least 1 row
if(datTable.Rows.Count > 0 )
{
Point oldPoint = (Point)datTable.Rows[0][1];
datTable.Rows[0][1] =
new Point(oldPoint.X+1, oldPoint.Y+1);
}
// Delete the last row
if(datTable.Rows.Count > 0 )
{ // If we have at least 1 row
datTable.Rows[1].Delete();
}
// Insert a row. This will fail if run twice
// because 100 is a primary key value.
datTable.Rows.Add(100, new Point(100, 200));
// Send the changes back to the database
da.Update(datTable);
}
static void CommandBuilder()
{
// Create a new SqlDataAdapter
SqlDataAdapter da = new SqlDataAdapter(
"SELECT id, ts, p FROM dbo.Points_ts", connString);
// Select a few rows with UDTs from the database
DataTable datTable = new DataTable("Points");
da.Fill(datTable);
// Display the contents of the p (Point) column
foreach (DataRow r in datTable.Rows)
{
Point p = (Point)r[2];
Console.WriteLine(
"ID: {0}, x={1}, y={1}", r[0], p.X, p.Y);
}
// Update a row if DataTable has at least 1 row
if (datTable.Rows.Count > 0)
{
Point oldPoint = (Point)datTable.Rows[0][2];
datTable.Rows[0][2] =
new Point(oldPoint.X + 1, oldPoint.Y + 1);
}
// Delete the last row
if (datTable.Rows.Count > 0)
{ // if we have at least 1 row
datTable.Rows[1].Delete();
}
// Insert a row. This will fail if run twice
// because 100 is a primary key value
datTable.Rows.Add(100, null, new Point(100, 200));
// Use the CommandBuilder to generate DML statements
SqlCommandBuilder bld = new SqlCommandBuilder(da);
bld.ConflictDetection = ConflictOptions.CompareRowVersion;
// Send the changes back to the database
da.Update(datTable);
}
static private string GetConnectionString()
{
// To avoid storing the connection string in your code,
// you can retrieve it from a configuration file.
return "Data Source=localhost;Initial Catalog=AdventureWorks;"
+ "Integrated Security=SSPI";
}
}