Mapping CLR Parameter Data

 

Updated: August 1, 2016

The following table lists Microsoft SQL Server data types, their equivalents in the common language runtime (CLR) for SQL Server in the System.Data.SqlTypes namespace, and their native CLR equivalents in the Microsoft .NET Framework.

SQL Server data typeType (in System.Data.SqlTypes or Microsoft.SqlServer.Types)CLR data type (.NET Framework)
bigintSqlInt64Int64, Nullable<Int64>
binarySqlBytes, SqlBinaryByte[]
bitSqlBooleanBoolean, Nullable<Boolean>
charNoneNone
cursorNoneNone
dateSqlDateTimeDateTime, Nullable<DateTime>
datetimeSqlDateTimeDateTime, Nullable<DateTime>
datetime2NoneDateTime, Nullable<DateTime>
DATETIMEOFFSETNoneDateTimeOffset, Nullable<DateTimeOffset>
decimalSqlDecimalDecimal, Nullable<Decimal>
floatSqlDoubleDouble, Nullable<Double>
geographySqlGeography

 SqlGeography is defined in Microsoft.SqlServer.Types.dll, which is installed with SQL Server and can be downloaded from the SQL Server 2016 feature pack.
None
geometrySqlGeometry

 SqlGeometry is defined in Microsoft.SqlServer.Types.dll, which is installed with SQL Server and can be downloaded from the SQL Server 2016 feature pack.
None
hierarchyidSqlHierarchyId

 SqlHierarchyId is defined in Microsoft.SqlServer.Types.dll, which is installed with SQL Server and can be downloaded from the SQL Server 2016 feature pack.
None
imageNoneNone
intSqlInt32Int32, Nullable<Int32>
moneySqlMoneyDecimal, Nullable<Decimal>
ncharSqlChars, SqlStringString, Char[]
ntextNoneNone
numericSqlDecimalDecimal, Nullable<Decimal>
nvarcharSqlChars, SqlString

 SQLChars is a better match for data transfer and access, and SQLString is a better match for performing String operations.
String, Char[]
nvarchar(1), nchar(1)SqlChars, SqlStringChar, String, Char[], Nullable<char>
realSqlSingle (the range of SqlSingle, however, is larger than real)Single, Nullable<Single>
rowversionNoneByte[]
smallintSqlInt16Int16, Nullable<Int16>
smallmoneySqlMoneyDecimal, Nullable<Decimal>
sql_variantNoneObject
tableNoneNone
textNoneNone
timeNoneTimeSpan, Nullable<TimeSpan>
timestampNoneNone
tinyintSqlByteByte, Nullable<Byte>
uniqueidentifierSqlGuidGuid, Nullable<Guid>
User-defined type(UDT)NoneThe same class that is bound to the user-defined type in the same assembly or a dependent assembly.
varbinarySqlBytes, SqlBinaryByte[]
varbinary(1), binary(1)SqlBytes, SqlBinarybyte, Byte[], Nullable<byte>
varcharNoneNone
xmlSqlXmlNone

A CLR method can return information to the calling code or program by marking an input parameter with the out modifier (Microsoft Visual C#) or <Out()> ByRef (Microsoft Visual Basic) If the input parameter is a CLR data type in the System.Data.SqlTypes namespace, and the calling program specifies its equivalent SQL Server data type as the input parameter, a type conversion occurs automatically when the CLR method returns the data type.

For example, the following CLR stored procedure has an input parameter of SqlInt32 CLR data type that is marked with out (C#) or <Out()> ByRef (Visual Basic):

[Microsoft.SqlServer.Server.SqlProcedure]  
public static void PriceSum(out SqlInt32 value)  
{ … }  

After the assembly is built and created in the database, the stored procedure is created in SQL Server with the following Transact-SQL, which specifies a SQL Server data type of int as an OUTPUT parameter:

CREATE PROCEDURE PriceSum (@sum int OUTPUT)  
AS EXTERNAL NAME TestStoredProc.StoredProcedures.PriceSum  

When the CLR stored procedure is called, the SqlInt32 data type is automatically converted to an int data type, and returned to the calling program.

Not all CLR data types can be automatically converted to their equivalent SQL Server data types through an out parameter, however. The following table lists these exceptions.

CLR data type (SQL Server)SQL Server data type
Decimalsmallmoney
SqlMoneysmallmoney
Decimalmoney
DateTimesmalldatetime
SQLDateTimesmalldatetime
Updated content
Added SqlGeography, SqlGeometry, and SqlHierarchyId types to the mapping table.

SQL Server Data Types in the .NET Framework

Community Additions

ADD
Show: