sp_datatype_info (Transact-SQL)
TOC
Collapse the table of content
Expand the table of content

sp_datatype_info (Transact-SQL)

 

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2008)noAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Returns information about the data types supported by the current environment.

Applies to: SQL Server (SQL Server 2008 through current version), Azure SQL Database.

Topic link icon Transact-SQL Syntax Conventions

  
sp_datatype_info [ [ @data_type = ] data_type ]   
     [ , [ @ODBCVer = ] odbc_version ]   

[ @data_type= ] data_type
Is the code number for the specified data type. To obtain a list of all data types, omit this parameter. data_type is int, with a default of 0.

[ @ODBCVer= ] odbc_version
Is the version of ODBC that is used. odbc_version is tinyint, with a default of 2.

None

Column nameData typeDescription
TYPE_NAMEsysnameDBMS-dependent data type.
DATA_TYPEsmallintCode for the ODBC type to which all columns of this type are mapped.
PRECISIONintMaximum precision of the data type on the data source. NULL is returned for data types for which precision is not applicable. The return value for the PRECISION column is in base 10.
LITERAL_PREFIXvarchar(32)Character or characters used before a constant. For example, a single quotation mark (') for character types and 0x for binary.
LITERAL_SUFFIXvarchar(32)Character or characters used to terminate a constant. For example, a single quotation mark (') for character types and no quotation marks for binary.
CREATE_PARAMSvarchar(32)Description of the creation parameters for this data type. For example, decimal is "precision, scale", float is NULL, and varchar is "max_length".
NULLABLEsmallintSpecifies nullability.

1 = Allows null values.

0 = Does not allow null values.
CASE_SENSITIVEsmallintSpecifies case sensitivity.

1 = All columns of this type are case-sensitive (for collations).

0 = All columns of this type are case-insensitive.
SEARCHABLEsmallintSpecifies the search capability of the column type:

1 = Cannot be searched.

2 = Searchable with LIKE.

3 = Searchable with WHERE.

4 = Searchable with WHERE or LIKE.
UNSIGNED_ATTRIBUTEsmallintSpecifies the sign of the data type.

1 = Data type unsigned.

0 = Data type signed.
MONEYsmallintSpecifies the money data type.

1 = money data type.

0 = Not a money data type.
AUTO_INCREMENTsmallintSpecifies autoincrementing.

1 = Autoincrementing.

0 = Not autoincrementing.

NULL = Attribute not applicable.

An application can insert values into a column that has this attribute, but the application cannot update the values in the column. With the exception of the bit data type, AUTO_INCREMENT is valid only for data types that belong to the Exact Numeric and Approximate Numeric data type categories.
LOCAL_TYPE_NAMEsysnameLocalized version of the data source-dependent name of the data type. For example, DECIMAL is DECIMALE in French. NULL is returned if a localized name is not supported by the data source.
MINIMUM_SCALEsmallintMinimum scale of the data type on the data source. If a data type has a fixed scale, the MINIMUM_SCALE and MAXIMUM_SCALE columns both contain this value. NULL is returned where scale is not applicable.
MAXIMUM_SCALEsmallintMaximum scale of the data type on the data source. If the maximum scale is not defined separately on the data source, but is instead defined to be the same as the maximum precision, this column contains the same value as the PRECISION column.
SQL_DATA_TYPEsmallintValue of the SQL data type as it appears in the TYPE field of the descriptor. This column is the same as the DATA_TYPE column, except for the datetime and ANSI interval data types. This field always returns a value.
SQL_DATETIME_SUBsmallintdatetime or ANSI interval subcode if the value of SQL_DATA_TYPE is SQL_DATETIME or SQL_INTERVAL. For data types other than datetime and ANSI interval, this field is NULL.
NUM_PREC_RADIXintNumber of bits or digits for calculating the maximum number that a column can hold. If the data type is an approximate numeric data type, this column contains the value 2 to indicate several bits. For exact numeric types, this column contains the value 10 to indicate several decimal digits. Otherwise, this column is NULL. By combining the precision with radix, the application can calculate the maximum number that the column can hold.
INTERVAL_PRECISIONsmallintValue of interval leading precision if data_type is interval; otherwise NULL.
USERTYPEsmallintusertype value from the systypes table.

sp_datatype_info is equivalent to SQLGetTypeInfo in ODBC. The results returned are ordered by DATA_TYPE and then by how closely the data type maps to the corresponding ODBC SQL data type.

Requires membership in the public role.

The following example retrieves information for the sysname and nvarchar data types by specifying the data_type value of -9.

USE master;  
GO  
EXEC sp_datatype_info -9;  
GO  

Database Engine Stored Procedures (Transact-SQL)
Data Types (Transact-SQL)
System Stored Procedures (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft