Developing Time-Oriented Applications in SQL | Richard T. Snodgrass |
This document outlines temporal data type support for the Microsoft SQL Server DBMS. It follows the general outline of the TDB book and is arranged in the following manner.
SQL-92 | Microsoft SQL Server Equivalent | |
Types: | ||
DATE | datetime, ignoring the hour, minute, and second fields | |
TIME | datetime, ignoring the century, year, month, and day fields | |
TIMESTAMP | datetime (to second granularity) | |
TIME WITH TIME ZONE | No equivalent | |
TIMESTAMP WITH TIME ZONE | No equivalent | |
INTERVAL YEAR TO MONTH | Can be simulated by int | |
INTERVAL DAY TO SECOND | Can be simulated by int | |
Literals: | ||
DATE '1991-01-01' | convert(datetime,"1997-01-01", 105) | |
TIME '12:34:56' | convert(datetime,"12:34:56") | |
TIMESTAMP '1997-01-01 12:34:56' | convert(datetime,"1997-01-01 12:34:56", 105) | |
INTERVAL '3-4' YEAR TO MONTH | 40 (months-- an integer) | |
INTERVAL '1 23:45:12' DAY TO SECOND | 171812 (seconds-- an integer) | |
Predicates: | ||
d1 = d2 | d1 = d2 | |
d1 < d2 | d1 < d2 | |
d1 <> d2 | d1 <> d2 | |
d1 BETWEEN d2 AND d3 | d1 > d2 AND d1 < d3 | |
i1 = i2 | i1 = i2 | |
i1 < i2 | i1 < i2 | |
i1 <> i2 | i1 <> i2 | |
i1 BETWEEN i2 AND i3 | i1 >= i2 AND i1 <= i3 | |
d = NULL | d = NULL | |
i = NULL | i = NULL | |
(d1, i2) OVERLAPS (d3, d4) | d1 < d4 AND d3 < dateadd (second,i2 , d1) | |
Datetime Constructors: | ||
d + i | dateadd(second,n,d) | |
i + d | dateadd (second,n,d) | |
d - i | dateadd (second,-n,d) | |
d AT i | Not supported | |
d AT LOCAL | Not supported | |
CURRENT_DATE | convert(datetime,(convert(char(3),datename(month,getdate())) + " " + convert(char(2), datename(day,getdate())) + " " + convert(char(4), datename(year,getdate())))) | |
CURRENT_TIME | convert(datetime,'1753-01-01' + " " + (convert(char(2),datename(hour,getdate())) + ":" + convert(char(2), datename(minute,getdate())) + ":" + convert(char(2), datename(second,getdate())))) | |
CURRENT_TIMESTAMP | getdate() | |
Interval Constructors: | ||
i1 + i2 | i1 + i2 | |
i1 - i2 | i1 - i2 | |
d1 - d2 qual | datediff(datepart,d1,d2) | |
d1 - d2 INTERVAL MONTH | datediff(month,d2, d1) | |
i * n | i * n | |
n * i | n * i | |
i / n | i / n | |
+ i | + i | |
- i | - i | |
Other Operators: | ||
CAST(d AS DATE) | convert(datetime,(convert(char(3),datename(month,d)) + " " + convert(char(2), datename(day,d)) + " " + convert(char(4), datename(year,d)))) | |
CAST(d AS TIME) | convert(datetime,'1753-01-01' + " " + (convert(char(2),datename(hour,d)) + ":" + convert(char(2), datename(minute,d)) + ":" + convert(char(2), datename(second,d)))) | convert as above obtaining the appropriate time fields using datename |
CAST(d AS TIMESTAMP) (where d is a DATE) | d | |
CAST(d AS TIMESTAMP) (where d is a TIME) | convert(datetime,(convert(char(3),datename(month,getdate())) + " " + convert(char(2), datename(day,getdate())) + ", " + convert(char(4), datename(year,getdate())) + " " + d)) | |
CAST(i AS INTERVAL YEAR TO MONTH) | Not possible | |
CAST(i AS INTERVAL DAY TO SECOND) | Not possible | |
CAST(d AS CHAR) | convert(char,d) | |
CAST(i AS CHAR) | convert(char,i) | |
CAST(i AS INTEGER) (where i is a DAY) | i is an integer | |
CAST(i AS INTEGER) (where i is a HOUR) | i is an integer | |
CAST(i AS INTEGER) (where i is a MINUTE) | i is an integer | |
CAST(i AS INTEGER) (where i is a SECOND) | i is an integer | |
EXTRACT(DAY from d) | datename(day,d) (returns a string) | |
EXTRACT(DAY from i) | convert(int, i/86400) | |
EXTRACT(HOUR from i) | convert(int, i/3600) |
SQL-92 | Microsoft SQL Server Equivalent |
Types: | |
period | [datetime, datetime) |
Predicates: | |
p equals q | p1 = q1 AND p2 = q2 |
p before q | p2 < q1 |
p before-1 q | q2 < p1 |
p meets q | p2 = q1 |
p meets-1 q | q2 = p1 |
p overlaps q | p1 < q1 AND q1 < p2 |
p overlaps-1 q | q1 < p1 AND p1 < q2 |
p during q | q1 < p1 AND p2 < q2 |
p during-1 q | p1 < q1 AND q2 < p2 |
p starts q | p1 = q1 AND p2 < q2 |
p starts-1 q | q1 = p1 AND q2 < p2 |
p finishes q | p2 = q2 AND p1 > q1 |
p finishes-1 q | q2 = p2 AND q1 > p1 |
p OVERLAPS q | p1 < q2 AND q1 < p2 |
p IS NULL | p1 = NULL |
Datetime Constructors: | |
beginning(p) | p1 |
previous(p) | dateadd(datepart,-1,p1) |
last(p) | dateadd(datepart,-1,p2) |
ending(p) | p2 |
Interval Constructors: | |
duration(p) | p2-p1 |
extract_time_zone(p) | not supported |
Period Constructors: | |
p + i | [dateadd(datepart,i,p1) , dateadd(datepart,i,p2) ) |
i + p | Same as above |
p - i | [dateadd(datepart,-i,p1) , dateadd(datepart,-i,p2) ) |
a extend b | [case when a < b then a else b end, case when a < b then dateadd(second,1,b) else dateadd(second,1,a) end) |
p extend q | [case when p1 < q1 then p1 else q1 end, case when p2 < q2 then q2 else p2 end) |
p extend a | [case when p1 < a then p1 else a end, case when p2 < a then dateadd(second,1,a) else p2 end) |
a extend p | [case when p1 < a then p1 else a end, case when p2 < a then dateadd(second,1,a) else p2 end) |
p INTERSECT q | [case when p2 <= q1
or q2 <= p1 then NULL else case when p1 < q1 then q1 else p1 end end, case when p2 <= q1 or q2 <= p1 then NULL else case when p2 < q2 then p2 else q2 end end) |
p - q | [case when q1 <= p1 then NULL else case when p1 < q1 and q2 < p2 then NULL else p1 end end, case when q1 <= p1 then NULL else case when p1 < q1 and q2 < p2 then NULL else case when q1 < p2 then q1 else p2 end end end) |
p UNION q | [case when p2 <= q1 or q2 <= p1 then NULL else case when p1 < q1 then p1 else q1 end end, case when p2 <= q1 or q2 <= p1 then NULL else case when p2 < q2 then q2 else p2 end end) |
p AT TIME ZONE i | Not supported |
p AT LOCAL | Not supported |
Other Operators: | |
CAST(a AS PERIOD) | [a, dateadd(second,1,a) ) |
CAST(p AS CHAR) | "[" + convert(char(11),p1) + "-" + convert(char(11),p2) + ")" |
While SQL-92 supplies six temporal types, Microsoft SQL Server, supplies just two, datetime and smalldatetime, which is similar to SQL-92's TIMESTAMP type. A Microsoft SQL Server datetime comprises of the month, the day of the month, the year, the hour, the minute, the second, and the AM/PM specifier.
The following are mentioned at the Transact-SQL reference on the SQL Server Books Online.
datetime columns hold dates between January 1, 1753 and December 31, 9999. datetime values are accurate to 1/300th of a second. 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 after January 1, 1900, and 2 bytes for the number of minutes since midnight.
The default way to enter dates is mm dd yyyy hh:mm:ss AM/PM, though there are several different ways, either numeric or alphanumeric, as well as different orders, depending on the language; you can use SET DATE FORMAT to change the ordering of the default datetime. For the different date display types, refer to the Transact-SQL reference, for datatypes on the SQL Server Books Online.
The predicates that Microsoft SQL Server supports on datetime are '=', '<', '', '<=', '=', and '<>', '!=' for not equals.
Microsoft SQL Server datetime and smalldatetime can be converted to char and varchar implicitly, and from date and smalldate time implicitly. This allows comparisons of the type Birthday="Sep 15 1976". The format of the string must much one of the several formats (called 'styles' in the Microsoft SQL Server documentation). Some of them are dd-mm-yy (style 5 if not including the century, style 105 if including it), dd.mm.yy and so on. Please note that if you provide a datetime without a century, Microsoft SQL Server will store 19 if the year is >= 50, and 20 if the year is < 50. For example, entering 97 will yield a default of 1997.
Microsoft SQL Server datetimes can be converted to character strings explicitly (char and varchar), using the convert function. For example, select convert(char(12), getdate(), 3) converts the current date to style "3", dd/mm/yy . For other possible conversions and for the full syntax of convert, refer to the Transact-SQL reference from the SQL Server Books Online.
At this point, let's mention the system provided date functions of Microsoft SQL Server. The following extract is from the Transact SQL Reference on the SQL Server Books Online.
All date functions except getdate take arguments. Function names, arguments, and results are listed in the following table.
Table 2.6.4.1 : Date functions
Function
Argument |
Result | |
getdate | () | Returns the current system date and time. |
datename | ( datepart , date ) | Returns the name of the specified part (such as the month "June") of a datetime value, as a character string. If the result is numeric, such as "23" for the day, it is still returned as a character string. |
datepart | ( datepart , date ) | Returns an integer value for the specified part of a datetime value. |
datediff | (datepart, date1, date2) | Returns date2 - date1 , measured in the specified date part. |
dateadd | (datepart, numeric_expression, date) | Returns the date produced by adding the specified number of the specified date parts to the date . numeric_expression can be any numeric type; the value is truncated to an integer. |
The following table lists the date parts, the abbreviations recognized by SQL Server, and the acceptable values.
Table 2.6.4.2: : Date parts and their values
Date Part
Abbreviation Values | ||
year | yy | 1753 - 9999 (2079 for smalldatetime ) |
quarter | 1 - 4 | |
month | mm | 1 - 12 |
week | wk | 1 - 54 |
day | dd | 1 - 31 |
dayofyear | dy | 1 - 366 |
weekday | dw | 1 - 7 (Sun.-Sat.) |
hour | hh | 0 - 23 |
minute | mi | 0 - 59 |
second | ss | 0 - 59 |
millisecond | ms | 0 - 999 |
If the year is given with two digits, <50 is the next century ("25" is "2025") and >=50 is this century ("50" is "1950"). Milliseconds can be preceded either with a colon or a period. If preceded by a colon, the number means thousandths of a second. If preceded by a period, a single digit means tenths of a second, two digits mean hundredths of a second, and three digits mean thousandths of a second. For example, "12:30:20:1" means twenty and one-thousandth of a second past 12:30; "12:30:20.1" means twenty and one-tenth of a second past 12:30. date - an argument used with dateadd , datediff , datename , and datepart . The date can be either the function getdate , a character string in one of the acceptable date formats , an expression that evaluates to a valid date format, or the name of a datetime column.
For a complete explanation of these functions refer to the Transact-SQL Reference.
Microsoft SQL Server does not have an interval datatype. We can simulate an interval by using an integer, so a 3 month interval would be the integer 3, and so would a 3 minute or a 3 second interval be. We can extract dateparts from dates using the function datepart, as discussed above, which returns an integer. It would be up to the user to create an additional column, called interval type, if (s)he wished to keep that information as well. Thus in the following tables, i stands for integer, with no "interval type" associated with it, denoting a number of seconds.
Christopher Cooper, Department of Computer Science,
University of Arizona (ccooper@cs.arizona.edu)
Rachana Shah, Department of Computer Science, University
of Arizona (rachana@cs.arizona.edu)
Inés Fernando Vega López, Department of Computer
Science, University of Arizona (ifvega@cs.arizona.edu)
Jian Yang, Department of Computer Science, University of
Arizona (yangjian@cs.arizona.edu)
April 27, 1999(Last Update)
Inés Fernando Vega López, Department of Computer
Science, University of Arizona (ifvega@cs.arizona.edu)
July 15, 1998 (Last Update)