datetime (Transact-SQL)
Defines a date that is combined with a time of day with fractional seconds that is based on a 24-hour clock.
Note
Use the time, date, datetime2 and datetimeoffset data types for new work. These types align with the SQL Standard. They are more portable. time, datetime2 and datetimeoffset provide more seconds precision. datetimeoffset provides time zone support for globally deployed applications.
For an overview of all Transact-SQL date and time data types and functions, see Date and Time Functions (Transact-SQL). For information and examples that are common to date and time data types and functions, see Using Date and Time Data.
datetime Description
Property |
Value |
---|---|
Syntax |
datetime |
Usage |
DECLARE @MyDatetime datetime CREATE TABLE Table1 ( Column1 datetime ) |
Default string literal formats (used for down-level client) |
Not applicable |
Date range |
January 1, 1753, through December 31, 9999 |
Time range |
00:00:00 through 23:59:59.997 |
Time zone offset range |
None |
Element ranges |
YYYY is four digits from 1753 through 9999 that represent a year. MM is two digits, ranging from 01 to 12, that represent a month in the specified year. DD is two digits, ranging from 01 to 31 depending on the month, that represent a day of the specified month. hh is two digits, ranging from 00 to 23, that represent the hour. mm is two digits, ranging from 00 to 59, that represent the minute. ss is two digits, ranging from 00 to 59, that represent the second. n* is zero to three digits, ranging from 0 to 999, that represent the fractional seconds. |
Character length |
19 positions minimum to 23 maximum |
Storage size |
8 bytes |
Accuracy |
Rounded to increments of .000, .003, or .007 seconds |
Default value |
1900-01-01 00:00:00 |
Calendar |
Gregorian (Does not include the complete range of years.) |
User-defined fractional second precision |
No |
Time zone offset aware and preservation |
No |
Daylight saving aware |
No |
Supported String Literal Formats for datetime
The following tables list the supported string literal formats for datetime. Except for ODBC, datetime string literals are in single quotation marks ('), for example, 'string_literaL'. If the environment is not us_english, the string literals should be in the format N'string_literaL'.
Numeric |
Description |
---|---|
Date formats: [0]4/15/[19]96 -- (mdy) [0]4-15-[19]96 -- (mdy) [0]4.15.[19]96 -- (mdy) [0]4/[19]96/15 -- (myd) 15/[0]4/[19]96 -- (dmy) 15/[19]96/[0]4 -- (dym) [19]96/15/[0]4 -- (ydm) [19]96/[0]4/15 -- (ymd) Time formats: 14:30 14:30[:20:999] 14:30[:20.9] 4am 4 PM |
You can specify date data with a numeric month specified. For example, 5/20/97 represents the twentieth day of May 1997. When you use numeric date format, specify the month, day, and year in a string that uses slash marks (/), hyphens (-), or periods (.) as separators. This string must appear in the following form:
When the language is set to us_english, the default order for the date is mdy. You can change the date order by using the SET DATEFORMAT statement. The setting for SET DATEFORMAT determines how date values are interpreted. If the order does not match the setting, the values are not interpreted as dates, because they are out of range or the values are misinterpreted. For example, 12/10/08 can be interpreted as one of six dates, depending on the DATEFORMAT setting. A four-part year is interpreted as the year. |
Alphabetical |
Description |
---|---|
Apr[il] [15][,] 1996 Apr[il] 15[,] [19]96 Apr[il] 1996 [15] [15] Apr[il][,] 1996 15 Apr[il][,][19]96 15 [19]96 apr[il] [15] 1996 apr[il] 1996 APR[IL] [15] 1996 [15] APR[IL] |
You can specify date data with a month specified as the full month name. For example, April or the month abbreviation of Apr specified in the current language; commas are optional and capitalization is ignored. Here are some guidelines for using alphabetical date formats:
The SET DATEFORMAT session setting is not applied when you specify the month in alphabetical form. |
ISO 8601 |
Description |
---|---|
YYYY-MM-DDThh:mm:ss[.mmm] YYYYMMDD[ hh:mm:ss[.mmm]] |
Examples:
To use the ISO 8601 format, you must specify each element in the format. This also includes the T, the colons (:), and the period (.) that are shown in the format. The brackets indicate that the fraction of second component is optional. The time component is specified in the 24-hour format. The T indicates the start of the time part of the datetime value. The advantage in using the ISO 8601 format is that it is an international standard with unambiguous specification. Also, this format is not affected by the SET DATEFORMAT or SET LANGUAGE setting. |
Unseparated |
Description |
---|---|
YYYYMMDD hh:mm:ss[.mmm] |
ODBC |
Description |
---|---|
{ ts '1998-05-02 01:23:56.123' } { d '1990-10-02' } { t '13:33:41' } |
The ODBC API defines escape sequences to represent date and time values, which ODBC calls timestamp data. This ODBC timestamp format is also supported by the OLE DB language definition (DBGUID-SQL) supported by the Microsoft OLE DB provider for SQL Server. Applications that use the ADO, OLE DB, and ODBC-based APIs can use this ODBC timestamp format to represent dates and times. ODBC timestamp escape sequences are of the format: { literal_type 'constant_value' }:
|
Rounding of datetime Fractional Second Precision
datetime values are rounded to increments of .000, .003, or .007 seconds, as shown in the following table.
User-specified value |
System stored value |
---|---|
01/01/98 23:59:59.999 |
1998-01-02 00:00:00.000 |
01/01/98 23:59:59.995 01/01/98 23:59:59.996 01/01/98 23:59:59.997 01/01/98 23:59:59.998 |
1998-01-01 23:59:59.997 |
01/01/98 23:59:59.992 01/01/98 23:59:59.993 01/01/98 23:59:59.994 |
1998-01-01 23:59:59.993 |
01/01/98 23:59:59.990 01/01/98 23:59:59.991 |
1998-01-01 23:59:59.990 |
ANSI and ISO 8601 Compliance
datetime is not ANSI or ISO 8601 compliant.
Examples
The following example compares the results of casting a string to each date and time data type.
SELECT
CAST('2007-05-08 12:35:29. 1234567 +12:15' AS time(7)) AS 'time'
,CAST('2007-05-08 12:35:29. 1234567 +12:15' AS date) AS 'date'
,CAST('2007-05-08 12:35:29.123' AS smalldatetime) AS
'smalldatetime'
,CAST('2007-05-08 12:35:29.123' AS datetime) AS 'datetime'
,CAST('2007-05-08 12:35:29. 1234567 +12:15' AS datetime2(7)) AS
'datetime2'
,CAST('2007-05-08 12:35:29.1234567 +12:15' AS datetimeoffset(7)) AS
'datetimeoffset';
Here is the result set.
Data type |
Output |
---|---|
time |
12:35:29. 1234567 |
date |
2007-05-08 |
smalldatetime |
2007-05-08 12:35:00 |
datetime |
2007-05-08 12:35:29.123 |
datetime2 |
2007-05-08 12:35:29. 1234567 |
datetimeoffset |
2007-05-08 12:35:29.1234567 +12:15 |