Edit

Share via


SqlTypes and the DataSet

ADO.NET 2.0 introduced enhanced type support for the DataSet through the System.Data.SqlTypes namespace. The types in System.Data.SqlTypes are designed to provide data types with the same semantics and precision as the data types in a SQL Server database. Each data type in System.Data.SqlTypes has an equivalent data type in SQL Server, with the same underlying data representation.

Using System.Data.SqlTypes directly in a DataSet confers several benefits when working with SQL Server data types. System.Data.SqlTypes supports the same semantics as SQL Server native data types. Specifying one of the System.Data.SqlTypes in the definition of a DataColumn eliminates the loss of precision that can occur when converting decimal or numeric data types to one of the common language runtime (CLR) data types.

Example

The following example creates a DataTable object, explicitly defining the DataColumn data types by using System.Data.SqlTypes instead of CLR types. The code fills the DataTable with data from the Sales.SalesOrderDetail table in the AdventureWorks database in SQL Server. The output displayed in the console window shows the data type of each column, and the values retrieved from SQL Server.

C#
static void GetSqlTypesAW(string connectionString)
{
    // Create a DataTable and specify a SqlType
    // for each column.
    DataTable table = new();
    table.Columns.Add("SalesOrderID", typeof(SqlInt32));
    table.Columns.Add("UnitPrice", typeof(SqlMoney));
    table.Columns.Add("LineTotal", typeof(SqlDecimal));
    table.Columns.Add("ModifiedDate", typeof(SqlDateTime));

    // Open a connection to SQL Server and fill the DataTable
    // with data from the Sales.SalesOrderDetail table
    // in the AdventureWorks sample database.
    using (SqlConnection connection = new(connectionString))
    {
        const string queryString =
            "SELECT TOP 5 SalesOrderID, UnitPrice, LineTotal, ModifiedDate "
            + "FROM Sales.SalesOrderDetail WHERE LineTotal < @LineTotal";

        // Create the SqlCommand.
        SqlCommand command = new(queryString, connection);

        // Create the SqlParameter and assign a value.
        SqlParameter parameter =
            new("@LineTotal", SqlDbType.Decimal)
            {
                Value = 1.5
            };
        command.Parameters.Add(parameter);

        // Open the connection and load the data.
        connection.Open();
        SqlDataReader reader =
            command.ExecuteReader(CommandBehavior.CloseConnection);
        table.Load(reader);

        // Close the SqlDataReader.
        reader.Close();
    }

    // Display the SqlType of each column.
    Console.WriteLine("Data Types:");
    foreach (DataColumn column in table.Columns)
    {
        Console.WriteLine($" {column.ColumnName} -- {column.DataType.UnderlyingSystemType}");
    }

    // Display the value for each row.
    Console.WriteLine("Values:");
    foreach (DataRow row in table.Rows)
    {
        Console.Write(" {0}, ", row["SalesOrderID"]);
        Console.Write(" {0}, ", row["UnitPrice"]);
        Console.Write(" {0}, ", row["LineTotal"]);
        Console.Write(" {0} ", row["ModifiedDate"]);
        Console.WriteLine();
    }
}

See also