TechNet
Export (0) Print
Expand All

Integration Services Data Types

 

When data enters a data flow in a package, the source that extracts the data converts the data to an Integration Services data type. Numeric data is assigned a numeric data type, string data is assigned a character data type, and dates are assigned a date data type. Other data, such as GUIDs and Binary Large Object Blocks (BLOBs), are also assigned appropriate Integration Services data types. If data has a data type that is not convertible to an Integration Services data type, an error occurs.

Some data flow components convert data types between the Integration Services data types and the managed data types of the Microsoft .NET Framework. For more information about the mapping between Integration Services and managed data types, see Working with Data Types in the Data Flow.

The following table lists the Integration Services data types. Some of the data types in the table have precision and scale information that applies to them. For more information about precision and scale, see Precision, Scale, and Length (Transact-SQL).

Data typeDescription
DT_BOOLA Boolean value.
DT_BYTESA binary data value. The length is variable and the maximum length is 8000 bytes.
DT_CYA currency value. This data type is an eight-byte signed integer with a scale of 4 and a maximum precision of 19 digits.
DT_DATEA date structure that consists of year, month, day, hour, minute, seconds, and fractional seconds. The fractional seconds have a fixed scale of 7 digits.

The DT_DATE data type is implemented using an 8-byte floating-point number. Days are represented by whole number increments, starting with 30 December 1899, and midnight as time zero. Hour values are expressed as the absolute value of the fractional part of the number. However, a floating point value cannot represent all real values; therefore, there are limits on the range of dates that can be presented in DT_DATE.

On the other hand, DT_DBTIMESTAMP is represented by a structure that internally has individual fields for year, month, day, hours, minutes, seconds, and milliseconds. This data type has larger limits on ranges of the dates it can present.
DT_DBDATEA date structure that consists of year, month, and day.
DT_DBTIMEA time structure that consists of hour, minute, and second.
DT_DBTIME2A time structure that consists of hour, minute, second, and fractional seconds. The fractional seconds have a maximum scale of 7 digits.
DT_DBTIMESTAMPA timestamp structure that consists of year, month, day, hour, minute, second, and fractional seconds. The fractional seconds have a maximum scale of 3 digits.
DT_DBTIMESTAMP2A timestamp structure that consists of year, month, day, hour, minute, second, and fractional seconds. The fractional seconds have a maximum scale of 7 digits.
DT_DBTIMESTAMPOFFSETA timestamp structure that consists of year, month, day, hour, minute, second, and fractional seconds. The fractional seconds have a maximum scale of 7 digits.

Unlike the DT_DBTIMESTAMP and DT_DBTIMESTAMP2 data types, the DT_DBTIMESTAMPOFFSET data type has a time zone offset. This offset specifies the number of hours and minutes that the time is offset from the Coordinated Universal Time (UTC). The time zone offset is used by the system to obtain the local time.

The time zone offset must include a sign, plus or minus, to indicate whether the offset is added or subtracted from the UTC. The valid number of hours offset is between -14 and +14. The sign for the minute offset depends on the sign for the hour offset:

If the sign of the hour offset is negative, the minute offset must be negative or zero.

If the sign for the hour offset is positive, the minute offset must be positive or zero.

If the sign for the hour offset is zero, the minute offset can be any value from negative 0.59 to positive 0.59.
DT_DECIMALAn exact numeric value with a fixed precision and a fixed scale. This data type is a 12-byte unsigned integer with a separate sign, a scale of 0 to 28, and a maximum precision of 29.
DT_FILETIMEA 64-bit value that represents the number of 100-nanosecond intervals since January 1, 1601. The fractional seconds have a maximum scale of 3 digits.
DT_GUIDA globally unique identifier (GUID).
DT_I1A one-byte, signed integer.
DT_I2A two-byte, signed integer.
DT_I4A four-byte, signed integer.
DT_I8An eight-byte, signed integer.
DT_NUMERICAn exact numeric value with a fixed precision and scale. This data type is a 16-byte unsigned integer with a separate sign, a scale of 0 - 38, and a maximum precision of 38.
DT_R4A single-precision floating-point value.
DT_R8A double-precision floating-point value.
DT_STRA null-terminated ANSI/MBCS character string with a maximum length of 8000 characters. (If a column value contains additional null terminators, the string will be truncated at the occurrence of the first null.)
DT_UI1A one-byte, unsigned integer.
DT_UI2A two-byte, unsigned integer.
DT_UI4A four-byte, unsigned integer.
DT_UI8An eight-byte, unsigned integer.
DT_WSTRA null-terminated Unicode character string with a maximum length of 4000 characters. (If a column value contains additional null terminators, the string will be truncated at the occurrence of the first null.)
DT_IMAGEA binary value with a maximum size of 231-1 (2,147,483,647) bytes. .
DT_NTEXTA Unicode character string with a maximum length of 230 - 1 (1,073,741,823) characters.
DT_TEXTAn ANSI/MBCS character string with a maximum length of 231-1 (2,147,483,647) characters.

If the data in a column does not require the full width allocated by the source data type, you might want to change the data type of the column. Making each data row as narrow as possible helps optimize performance when transferring data because the narrower each row is, the faster the data is moved from source to destination.

Integration Services includes a complete set of numeric data types, so that you can match the data type closely to the size of the data. For example, if the values in a column with a DT_UI8 data type are always integers between 0 and 3000, you can change the data type to DT_UI2. Similarly, if a column with the DT_CY data type can meet the package data requirements by using an integer data type instead, you can change the data type to DT_I4.

You can change the data type of a column in the following ways:

Converting Between Strings and Date/Time Data Types

The following table lists the results of casting or converting between date/time data types and strings:

  • When you use the cast operator or the Data Conversion transformation, the date or time type data type will be converted to the corresponding string format. For example, the DT_DBTIME data type will be converted to a string that has the format, "hh:mm:ss".

  • When you want to convert from a string to a date or time data type, the string must use the string format that corresponds to the appropriate date or time data type. For example, to successfully convert some date strings to the DT_DBDATE data type, these date strings must be in the format, "yyyy-mm-dd".

    Data typeString format
    DT_DBDATEyyyy-mm-dd
    DT_FILETIMEyyyy-mm-dd hh:mm:ss:fff
    DT_DBTIMEhh:mm:ss
    DT_DBTIME2hh:mm:ss[.fffffff]
    DT_DBTIMESTAMPyyyy-mm-dd hh:mm:ss[.fff]
    DT_DBTIMESTAMP2yyyy-mm-dd hh:mm:ss[.fffffff]
    DT_DBTIMESTAMPOFFSETyyyy-mm-dd hh:mm:ss[.fffffff] [{+|-} hh:mm]

In the format for DT_FILETIME and DT_DBTIMESTAMP fff is a value between 0 and 999 that represents fractional seconds.

In the date format for DT_DBTIMESTAMP2, DT_DBTIME2, and DT_DBTIMESTAMPOFFSET, fffffff is a value between 0 and 9999999 that represents fractional seconds.

The date format for DT_DBTIMESTAMPOFFSET also includes a time zone element. There is a space between the time element and the time zone element.

Converting Date/Time Data Types

You can change the data type on a column with date/time data to extract the date or the time part of the data. The following tables list the results of changing from one date/time data type to another date/time data type.

Converting from DT_FILETIME

Convert DT_FILETIME toResult
DT_FILETIMENo change.
DT_DATEConverts the data type.
DT_DBDATERemoves the time value.
DT_DBTIMERemoves the date value.

Removes the fractional second value when its scale is greater than the number of fractional digits that the DT_DBTIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIME2Removes the date value represented by the DT_FILETIME data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPConverts the data type.
DT_DBTIMESTAMP2Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPOFFSETSets the time zone field in the DT_DBTIMESTAMPOFFSET data type to zero.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMPOFFSET data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.

Converting from DT_DATE

Convert DT_DATE toResult
DT_FILETIMEConverts the data type.
DT_DATENo change.
DT_DBDATERemoves the time value represented by the DT_DATA data type.
DT_DBTIMERemoves the date value represented by the DT_DATE data type.
DT_DBTIME2Removes the date value represented by the DT_DATE data type.
DT_DBTIMESTAMPConverts the data type.
DT_DBTIMESTAMP2Converts the data type.
DT_DBTIMESTAMPOFFSETSets the time zone field in the DT_DBTIMESTAMPOFFSET data type to zero.

Converting from DT_DBDATE

Convert DT_DBDATE toResult
DT_FILETIMESets the time fields in the DT_FILETIME data type to zero.
DT_DATESets the time fields in the DT_DATE data type to zero.
DT_DBDATENo change.
DT_DBTIMESets the time fields in the DT_DBTIME data type to zero.
DT_DBTIME2Sets the time fields in the DT_DBTIME2 data type to zero.
DT_DBTIMESTAMPSets the time fields in the DT_DBTIMESTAMP data type to zero.
DT_DBTIMESTAMP2Sets the time fields in the DT_DBTIMESTAMP data type to zero.
DT_DBTIMESTAMPOFFSETSets the time fields and the time zone field in the DT_DBTIMESTAMPOFFSET data type to zero.

Converting from DT_DBTIME

Convert DT_DBTIME toResult
DT_FILETIMESets the date field in the DT_FILETIME data type to the current date.
DT_DATESets the date field in the DT_DATE data type to the current date.
DT_DBDATESets the date field in the DT_DBDATE data type to the current date.
DT_DBTIMENo change.
DT_DBTIME2Converts the data type.
DT_DBTIMESTAMPSets the date field in the DT_DBTIMESTAMP data type to the current date.
DT_DBTIMESTAMP2Sets the date field in the DT_DBTIMESTAMP2 data type to the current date.
DT_DBTIMESTAMPOFFSETSets the date field and the time zone field in the DT_DBTIMESTAMPOFFSET data type to the current date and to zero, respectively.

Converting from DT_DBTIME2

Convert DT_DBTIME2 toResult
DT_FILETIMESets the date field in the DT_FILETIME data type to the current date.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_FILETIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DATESets the date field of the DT_DATE data type to the current date.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DATE data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBDATESets the date field of the DT_DBDATE data type to the current date.
DT_DBTIMERemoves the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIME2Removes the fractional second value when its scale is greater than the number of fractional second digits that the destination DT_DBTIME2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPSet the date field in the DT_DBTIMESTAMP data type to the current date.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMP2Sets the date field in the DT_DBTIMESTAMP2 data type to the current date.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPOFFSETSets the date field and the time zone field in the DT_DBTIMESTAMPOFFSET data type to the current date and to zero, respectively.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMPOFFSET data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.

Converting from DT_DBTIMESTAMP

Convert DT_DBTIMESTAMP toResult
DT_FILETIMEConverts the data type.
DT_DATEIf a value represented by the DT_DBTIMESTAMP data type overflows the range of the DT_DATE data type, returns the DB_E_DATAOVERFLOW error. For more information, see Error Handling in Data.
DT_DBDATERemoves the time value represented by the DT_DBTIMESTAMP data type.
DT_DBTIMERemoves the date value represented by the DT_DBTIMESTAMP data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIME2Removes the date value represented by the DT_DBTIMESTAMP data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPNo change.
DT_DBTIMESTAMP2Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPOFFSETSets the time zone field in the DT_DBTIMESTAMPOFFSET data type to zero.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMPOFFSET data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.

Converting from DT_DBTIMESTAMP2

Convert DT_DBTIMESTAMP2 toResult
DT_FILETIMERemoves the fractional second value when its scale is greater than the number of fractional second digits that the DT_FILETIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DATEIf a value represented by the DT_DBTIMESTAMP2 data type overflows the range of the DT_DATE data type, the DB_E_DATAOVERFLOW error is returned. For more information, see Error Handling in Data.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DATE data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBDATERemoves the time value represented by the DT_DBTIMESTAMP2 data type.
DT_DBTIMERemoves the date value represented by the DT_DBTIMESTAMP2 data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIME2Removes the date value represented by the DT_DBTIMESTAMP2 data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPIf a value represented by the DT_DBTIMESTAMP2 data type overflows the range of the DT_DBTIMESTAMP data type, returns the DB_E_DATAOVERFLOW error.

DT_DBTIMESTAMP2 maps to a SQL Server data type, datetime2, with a range of January 1, 1A.D. through December 31, 9999. DT_DBTIMESTAMP maps to a SQL Server data type, datetime, with smaller a range of January 1, 1753 through December 31, 9999.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP data type can contain. After removing the fractional second value, generates a report about this data truncation.

For more information about errors, see Error Handling in Data.
DT_DBTIMESTAMP2Removes the fractional second value when its scale is greater than the number of fractional second digits that the destination DT_DBTIMESTAMP2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPOFFSETSets the time zone field in the DT_DBTIMESTAMPOFFSET data type to zero.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMPOFFSET data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.

Converting from DT_DBTIMESTAMPOFFSET

Convert DT_DBTIMESTAMPOFFSET toResult
DT_FILETIMEChanges the time value represented by the DT_DBTIMESTAMPOFFSET data type to Coordinated Universal Time (UTC).

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_FILETIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DATEChanges the time value represented by the DT_DBTIMESTAMPOFFSET data type to UTC.

If a value represented by the DT_DBTIMESTAMPOFFSET data type overflows the range of the DT_DATE data type, returns the DB_E_DATAOVERFLOW error.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DATE data type can contain. After removing the fractional second value, generates a report about this data truncation.

For more information, see Error Handling in Data.
DT_DBDATEChanges the time value represented by the DT_DBTIMESTAMPOFFSET data type to UTC, which can affect the date value. The time value is then removed.
DT_DBTIMEChanges the time value represented by the DT_DBTIMESTAMPOFFSET data type to UTC.

Removes the data value represented by the DT_DBTIMESTAMPEOFFSET data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIME2Changes the time value represented by the DT_DBTIMESTAMPOFFSET data type to UTC.

Removes the date value represented by the DT_DBTIMESTAMPOFFSET data type.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIME2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPChanges the time value represented by the DT_DBTIMESTAMPOFFSET data type to UTC.

If a value represented by the DT_DBTIMESTAMPOFFSET data type overflows the range of the DT_DBTIMESTAMP data type, the DB_E_DATAOVERFLOW error is returned.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP data type can contain. After removing the fractional second value, generates a report about this data truncation.

For more information, see Error Handling in Data.
DT_DBTIMESTAMP2Changes the time value represented by the DT_DBTIMESTAMPOFFSET data type to UTC.

Removes the fractional second value when its scale is greater than the number of fractional second digits that the DT_DBTIMESTAMP2 data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.
DT_DBTIMESTAMPOFFSETRemoves the fractional second value when its scale is greater than the number of fractional second digits that the destination DT_DBTIMESTAMPOFFSET data type can contain. After removing the fractional second value, generates a report about this data truncation. For more information, see Error Handling in Data.

The following table provides guidance on mapping the data types used by certain databases to Integration Services data types. These mappings are summarized from the mapping files used by the SQL Server Import and Export Wizard when it imports data from these sources. For more information about these mapping files, see SQL Server Import and Export Wizard.

System_CAPS_ICON_important.jpg Important


These mappings are not intended to represent strict equivalency, but only to provide guidance. In certain situations, you may need to use a different data type than the one shown in this table.

System_CAPS_ICON_note.jpg Note


You can use the SQL Server data types to estimate the size of corresponding Integration Services date and time data types.

Data TypeSQL Server

(SQLOLEDB; SQLNCLI10)
SQL Server (SqlClient)JetOracle

(OracleClient)
DB2

(DB2OLEDB)
DB2

(IBMDADB2)
DT_BOOLbitbitBit
DT_BYTESbinary, varbinary, timestampbinary, varbinary, timestampBigBinary, VarBinaryRAW
DT_CYsmallmoney, moneysmallmoney, moneyCurrency
DT_DATE
DT_DBDATEdate (Transact-SQL)date (Transact-SQL)datedatedate
DT_DBTIMEtimestamptimetime
DT_DBTIME2time (Transact-SQL)(p)time (Transact-SQL) (p)
DT_DBTIMESTAMPdatetime (Transact-SQL), smalldatetime (Transact-SQL)datetime (Transact-SQL), smalldatetime (Transact-SQL)DateTimeTIMESTAMP, DATE, INTERVALTIME, TIMESTAMP, DATETIME, TIMESTAMP, DATE
DT_DBTIMESTAMP2datetime2 (Transact-SQL)datetime2 (Transact-SQL)timestamptimestamptimestamp
DT_DBTIMESTAMPOFFSETdatetimeoffset (Transact-SQL)(p)datetimeoffset (Transact-SQL) (p)timestampoffsettimestamp,

varchar
timestamp,

varchar
DT_DECIMAL
DT_FILETIME
DT_GUIDuniqueidentifieruniqueidentifierGUID
DT_I1
DT_I2smallintsmallintShortSMALLINTSMALLINT
DT_I4intintLongINTEGERINTEGER
DT_I8bigintbigintBIGINTBIGINT
DT_NUMERICdecimal, numericdecimal, numericDecimalNUMBER, INTDECIMAL, NUMERICDECIMAL, NUMERIC
DT_R4realrealSingleREALREAL
DT_R8floatfloatDoubleFLOAT, REALFLOAT, DOUBLEFLOAT, DOUBLE
DT_STRchar, varcharVarCharCHAR, VARCHARCHAR, VARCHAR
DT_UI1tinyinttinyintByte
DT_UI2
DT_UI4
DT_UI8
DT_WSTRnchar, nvarchar, sql_variant, xmlchar, varchar, nchar, nvarchar, sql_variant, xmlLongTextCHAR, ROWID, VARCHAR2, NVARCHAR2, NCHARGRAPHIC, VARGRAPHICGRAPHIC, VARGRAPHIC
DT_IMAGEimageimageLongBinaryLONG RAW, BLOB, LOBLOCATOR, BFILE, VARGRAPHIC, LONG VARGRAPHIC, user-definedCHAR () FOR BIT DATA, VARCHAR () FOR BIT DATACHAR () FOR BIT DATA, VARCHAR () FOR BIT DATA, BLOB
DT_NTEXTntexttext, ntextLONG, CLOB, NCLOB, NVARCHAR, TEXTLONG VARCHAR, NCHAR, NVARCHAR, TEXTLONG VARCHAR, DBCLOB, NCHAR, NVARCHAR, TEXT
DT_TEXTtextLONG VARCHAR FOR BIT DATALONG VARCHAR FOR BIT DATA, CLOB

For information on mapping data types in the data flow, see Working with Data Types in the Data Flow.

Blog entry, Performance Comparison between Data Type Conversion Techniques in SSIS 2008, on blogs.msdn.com.

Data in Data Flows

Show:
© 2016 Microsoft