The datetime and smalldatetime datatypes consist of a date portion either followed by or preceded by a time portion. (You can omit either the date or the time, or both.) Both datetime and smalldatetime values must be enclosed in single or double quotes.
datetime columns hold dates between January 1, 1753 and December 31, 9999. datetime values are accurate to 1/300 of a second on platforms that support this level of granularity. Storage size is 8 bytes: 4 bytes for the number of days since the base date of January 1, 1900 and 4 bytes for the time of day.
smalldatetime columns hold dates from January 1, 1900 to June 6, 2079, with accuracy to the minute. Storage size is 4 bytes: 2 bytes for the number of days since January 1, 1900 and 2 bytes for the number of minutes since midnight.
Dates consist of a month, day, and year and can be entered in a variety of formats:
You can enter the entire date as an unseparated string of 4, 6, or 8 digits, or use slash (/), hyphen (-), or period (.) separators between the date parts.
When entering dates as unseparated strings, use the appropriate format for that string length. Use leading zeros for single-digit years, months, and days. Dates entered in the wrong format may be misinterpreted or result in errors.
When entering dates with separators, use the set dateformat option to determine the expected order of date parts. If the first date part in a separated string is four digits, Adaptive Server interprets the string as yyyy-mm-dd format.
Some date formats accept 2-digit years (yy):
Numbers less than
50 are interpreted as 20yy. For example, 01
is 2001, 32
is
2032, and 49
is 2049.
Numbers equal to or greater than 50 are interpreted
as 19yy. For example, 50
is
1950, 74
is 1974, and 99
is
1999.
You can specify the month as either a number or a name. Month names and their abbreviations are language-specific and can be entered in uppercase, lowercase, or mixed case.
If you omit the date portion of a datetime or smalldatetime value, Adaptive Server uses the default date of January 1, 1900.
Table 1-13 describes the acceptable formats for entering the date portion of a datetime or smalldatetime value:
Date format |
Interpretation |
Sample entries |
Meaning |
---|---|---|---|
4-digit string with no separators |
Interpreted as yyyy. Date defaults to Jan 1 of the specified year. |
“1947” |
Jan 1 1947 |
6-digit string with no separators |
Interpreted as yymmdd. For yy < 50, year is 20yy. For yy >= 50, year is 19yy. |
“450128” “520128” |
Jan 28 2045 Jan 28 1952 |
8-digit string with no separators |
Interpreted as yyyymmdd. |
“19940415” |
Apr 15 1994 |
String consisting of 2-digit month, day, and year separated by slashes, hyphens, or periods, or a combination of the above. |
The dateformat and language set options determine the expected order of date parts. For us_english, the default order is mdy. For yy < 50, year is interpreted as 20yy. For yy >= 50, year is interpreted as 19yy. |
“4/15/94” “4.15.94” “4-15-94” “04.15/94” |
All of these entries are interpreted as Apr 15 1994 when the dateformat option is set to mdy. |
String consisting of 2-digit month, 2-digit day, and 4-digit year separated by slashes, hyphens, or periods, or a combination of the above. |
The dateformat and language set options determine the expected order of date parts. For us_english, the default order is mdy. |
“04/15.1994” |
Interpreted as Apr 15 1994 when the dateformat option is set to mdy. |
Month is entered in character form (either full month name or its standard abbreviation), followed by an optional comma. |
If 4-digit year is entered, date parts can be entered in any order. |
“April 15, 1994” “1994 15 apr” “1994 April 15” “15 APR 1994” |
All of these entries are interpreted as Apr 15 1994. |
If day is omitted, all 4 digits of year must be specified. Day defaults to the first day of the month. |
“apr 1994” |
Apr 1 1994 |
|
If year is only 2 digits (yy), it is expected to appear after the day. For yy < 50, year is interpreted as 20yy. For yy >= 50, year is interpreted as 19yy. |
“mar 16 17” “apr 15 94” |
Mar 16 2017 Apr 15 1994 |
|
The empty string, “” |
Date defaults to Jan 1 1900. |
“” |
Jan 1 1900 |
The time component of a datetime or smalldatetime value must be specified as follows:
hours[:minutes[:seconds[:milliseconds]] [AM | PM]
Use 12AM for midnight and 12PM for noon.
A time value must contain either a colon or an AM or PM signifier. The AM or PM can be entered in uppercase, lowercase, or mixed case.
The seconds specification can include either a decimal portion preceded by a decimal point or a number of milliseconds preceded by a colon. For example, “12:30:20:1” means twenty seconds and one millisecond past 12:30; “12:30:20.1” means twenty and one-tenth of a second past 12:30.
If you omit the time portion of a datetime or smalldatetime value, Adaptive Server uses the default time of 12:00:00:000AM.
The display format for datetime and smalldatetime values is “Mon dd yyyy hh:mmAM” (or “PM”); for example, “Apr 15 1988 10:23PM”. To display seconds and milliseconds, and to obtain additional date styles and date-part orders, use the convert function to convert the data to a character string. Adaptive Server may round or truncate millisecond values.
Table 1-14 lists some examples of datetime entries and their display values:
Entry |
Value Displayed |
---|---|
“1947” |
Jan 1 1947 12:00AM |
“450128 12:30:1PM” |
Jan 28 2045 12:30PM |
“12:30.1PM 450128” |
Jan 28 2045 12:30PM |
“14:30.22” |
Jan 1 1900 2:30PM |
“4am” |
Jan 1 1900 4:00AM |
Use the like keyword to look for dates that match a particular pattern. If you use the equality operator (=) to search datetime values for a particular month, day, and year, Adaptive Server returns only those values for which the time is precisely 12:00:00:000AM.
For example, if you insert the value “9:20” into a column named arrival_time, Adaptive Server converts the entry into “Jan 1 1900 9:20AM”. If you look for this entry using the equality operator, it is not found:
where arrival_time = "9:20" /* does not match */
You can find the entry using the like operator:
where arrival_time like "%9:20%"
When using like, Adaptive Server first converts the dates to datetime format and then to varchar. The display format consists of the 3-character month in the current language, 2 characters for the day, 4 characters for the year, the time in hours and minutes, and “AM” or “PM.”
When searching with like, you cannot use the wide variety of input formats that are available for entering the date portion of datetime and smalldatetime values. Since the standard display formats do not include seconds or milliseconds, you cannot search for seconds or milliseconds with like and a match pattern, unless you are also using style 9 or 109 and the convert function.
If you are using like, and the day of the month is a number between 1 and 9, insert 2 spaces between the month and the day to match the varchar conversion of the datetime value. Similarly, if the hour is less than 10, the conversion places 2 spaces between the year and the hour. The following clause with 1 space between “May” and “2”) finds all dates from May 20 through May 29, but not May 2:
like May 2%
You do not need to insert the extra space with other date comparisons, only with like, since the datetime values are converted to varchar only for the like comparison.
You can do some arithmetic calculations on datetime values with the built-in date functions. See “Date functions”.