Developing Time-Oriented Applications in SQL | Richard T. Snodgrass |
This document outlines temporal data type support for the IBM DB2 Universal Database DBMS, as described in Chapters 2 & 3. It follows the general outline of the book and is arranged in the following manner.
Data Type Support
DB2 supports the DATE, TIME, and TIMESTAMP data types. These types are very similar to their DATE, TIME, and TIMESTAMP counterparts in SQL 92, with a few exceptions:
The TIME data type does not include a "fractional digits of a second" field.
The precision of the TIMESTAMP data type is fixed at 6. (Hence, the finest time granularity supported by DB2 is one microsecond.)
Time zone information is not supported.
Timestamp strings are of the form 'yyyy-mm-dd-hh.mm.ss.zzzzzz', where z represents the number of microseconds.
The most significant departure from SQL 92 occurs in DB2's handling of intervals. Intervals are not "first-class objects" in DB2; there is no dedicated interval data type. Instead, DB2 uses "durations", which are decimal numbers representing intervals of time. There are three kinds of durations that can be represented as decimal numbers:
A date duration represents a number of years, months, and days, expressed as a DECIMAL(8,0) number of the form yyyymmdd. The result of subtracting one DATE value from another is a date duration.
A time duration represents a number of hours, minutes, and seconds, expressed as a DECIMAL(6,0) number of the form hhmmss. The result of subtracting one TIME value from another is a time duration.
A timestamp duration represents a number of years, months, days, hours, minutes, seconds, and microseconds, expressed as a DECIMAL(20,6) number of the form yyyymmddhhmmss.zzzzzz, where z represents the number of microseconds. The result of subtracting one TIMESTAMP value from another is a timestamp duration.
In addition to the above duration types, DB2 provides labelled durations. These are used to represent "hardcoded" intervals within expressions; they do not, however, have any existence outside expressions. A labelled duration represents a specific unit of time as expressed by a number (which can be the result of an expression) followed by one of the seven duration keywords: YEARS, MONTHS, DAYS, HOURS, MINUTES, SECONDS, or MICROSECONDS. The number specified is converted as if it were assigned to a DECIMAL(15,0) number. A labelled duration can only be used as an operand of an arithmetic operator in which the other operand is a value of data type DATE, TIME, or TIMESTAMP. An example of an expression involving a labelled duration is: DATE('1997-01-01') + 3 MONTHS + 14 DAYS.
Operations
We now present a summary of the SQL-92 operations in DB2; in the table below, d represents a datetime value, and i represents an interval (or, in DB2's case, a duration). Note that some items are marked Embedded SQL only; these functionalities are not supported via SQL strictly speaking, though they are possible when DB2 is used from within an Embedded SQL environment. A sample query is provided to demonstrate each table entry; click on the "Query" links next to the table entries to access the sample queries. Click here for SQL code which constructs the database used by the sample queries. Click here for a Makefile which will build the sample query application. Click here to see the results of the sample queries.
SQL-92
IBM DB2 Universal Database Equivalent
Types: DATE DATE (Query 1) TIME TIME (precision fixed at 0) (Query 1) TIMESTAMP TIMESTAMP (precision fixed at 6) (Query 1) TIME WITH TIME ZONE No equivalent - store UTC, use CURRENT TIMEZONE special register on retrieval. (Query 37) TIMESTAMP WITH TIME ZONE No equivalent - store UTC, use CURRENT TIMEZONE special register on retrieval. (Query 34) INTERVAL YEAR TO MONTH A date duration (DECIMAL(8,0)), with a 0 DAY field. Or a labelled duration of the form y YEARS + m MONTHS (only useful within an expression). (Query 6, Query 38) INTERVAL DAY TO SECOND A timestamp duration with 0 YEAR, MONTH, and MICROSECOND fields. Or a labelled duration of the form d DAYS + h HOURS + m MINUTES + s SECONDS (only useful within an expression). Negative values not available. (Query 11, Query 39) Literals: DATE '1997-01-01' DATE('1997-01-01') (Query 1) TIME '12:34:56' TIME('12:34:56') (Query 2) TIMESTAMP '1997-01-01 12:34:56' TIMESTAMP('1997-01-01-12.34.56.000000') (Query 2) INTERVAL '3-4' YEAR TO MONTH Date duration of the form 30400., or a labelled duration (only useful within an expression) of the form 3 YEARS + 4 MONTHS (or, alternatively, 40 MONTHS). (Query 65, Query 38) INTERVAL '1 23:45:12' DAY TO SECOND Timestamp duration of the form 1234512.000000, or a labelled duration of the form 1 DAYS + 23 HOURS + 45 MINUTES + 12 SECONDS (or, alternatively, 171912 SECONDS). (Query 66, Query 39) Predicates: d1 = d2 d1 = d2 (Query 2) d1 < d2 d1 < d2 (Query 3) d1 <> d2 d1 <> d2 (Query 3) d1 BETWEEN d2 AND d3 d2 <= d1 AND d1 <= d3 (Query 4) i1 = i2 i1 = i2 (Query 6) i1 < i2 i1 < i2 (Query 7) i1 <> i2 i1 <> i2 (Query 8) i1 BETWEEN i2 AND i3 i2 <= i1 AND i1 <= i3 (Query 9) d IS NULL d IS NULL (Query 5) i IS NULL i IS NULL (needless check, however, since there's no way a duration can be NULL) (Query 9) (d1, i2) OVERLAPS (d3, d4) d1 <= d4 AND d3 <= (d1 + i2) (Query 10) Datetime Constructors: d + i d + i (Query 40) i + d i + d (Query 41) d - i d - i (Query 42) d AT i d + i (Query 43) d AT LOCAL d + CURRENT TIMEZONE (Query 37) CURRENT_DATE CURRENT DATE special register (Query 14) CURRENT_TIME CURRENT TIME special register (Query 16) CURRENT_TIMESTAMP CURRENT TIMESTAMP special register (Query 16) Interval Constructors: i1 + i2 Not supported i1 - i2 Not supported d1 - d2 qual TIMESTAMPDIFF(itype, CHAR(d1 - d2)), where d1 and d2 are TIMESTAMPs, and itype is determined based on qual. (Query 17) d1 - d2 MONTH TIMESTAMPDIFF(64, CHAR(d1 - d2)), where d1 and d2 are TIMESTAMPs. (Query 18) i * n Not supported n * i Not supported i / i Not supported + i Not supported - i Negative values not available Other Operators: CAST(d AS DATE) CAST(d AS DATE) (supported only if d is DATE or TIMESTAMP) (Query 12) CAST(d AS TIME) CAST(d AS TIME) (supported only if d is TIME or TIMESTAMP) (Query 12) CAST(d AS TIMESTAMP) (where d is a DATE) Extract year, month, day from DATE, then build TIMESTAMP based on those values (see sample query). (Query 13) Embedded SQL only CAST(d AS TIMESTAMP) (where d is a TIME) Extract hour, minute, second from TIME, then build TIMESTAMP based on those values (see sample query). (Query 14) Embedded SQL only CAST(i AS INTERVAL YEAR TO MONTH) Not possible CAST(i AS INTERVAL DAY TO SECOND) Not possible CAST(d AS CHAR) CHAR(d) (Query 15) CAST(i AS CHAR) Not possible if i is a labelled duration. If i is a date or timestamp duration, then extract year, months, and days from i and format them as desired. (Query 44) Embedded SQL only CAST(i AS INTEGER) (where i is YEAR TO DAY) Not possible if i is a labelled duration. If i is a timestamp or date duration, then (365.25 * YEAR(i)) + (30.417 * MONTH(i)) + DAY(i). (Query 48, Query 49) CAST(i AS INTEGER) (where i is DAY TO HOUR) Not possible if i is a labelled or date duration. If i is a timestamp duration, then (3600 * HOUR(i)) + (60 * MINUTE(i)) + SECOND(i). (Query 46) CAST(i AS INTEGER) (where i is DAY TO MINUTE) Not possible if i is a labelled or date duration. If i is a timestamp duration, then (60 * MINUTE(i)) + SECOND(i). (Query 45) CAST(i AS INTEGER) (where i is DAY TO SECOND) Not possible if i is a labelled or date duration. If i is a timestamp duration, then SECOND(i). (Query 48) EXTRACT(DAY from d) DAY(d) (supported only if d is DATE or TIMESTAMP) (Query 13) EXTRACT(DAY from i) Not possible if i is a labelled duration. If i is a timestamp or date duration, then DAY(i). (Query 48, Query 49) EXTRACT(HOUR from i) Not possible if i is a labelled or date duration. If i is a timestamp duration, then HOUR(i). (Query 46) Operators not in SQL-92: Convert d to Julian day JULIAN_DAY(d) (Query 19)
Data Type Support
Though DB2 does not provide explicit support for periods, we simulate a closed-open representation via a pair of TIMESTAMP's.
Operations
We now present a summary of the period operations in DB2. In the table below, a and b represent datetime values, and p and q represent periods. Note that some items are marked Embedded SQL only; these functionalities are not supported via SQL strictly speaking, though they are possible when DB2 is used from within an Embedded SQL environment. A sample query is provided to demonstrate each table entry; click on the "Query" links next to the table entries to access the sample queries. Click here for SQL code which constructs the database used by the sample queries. Click here for a Makefile which will build the sample query application. Click here to see the results of the sample queries.
SQL-92
IBM DB2 Universal Database Equivalent
Types: period [TIMESTAMP, TIMESTAMP) (Query 20) Predicates: p equals q p1 = q1 AND p2 = q2 (Query 20) p before q p2 < q1 (Query 21) p before-1 q q2 < p1 (Query 22) p meets q p2 = q1 (Query 23) p meets-1 q q2 = p1 (Query 24) p overlaps q p1 < q2 AND q1 < p2 (Query 57)--this is incorrect p overlaps-1 q q1 < p1 AND p1 < q2 (Query 26)--this is incorrect p during q q1 < p1 AND p2 < q2 (Query 27) p during-1 q p1 < q1 AND q2 < p2 (Query 28) p starts q p1 = q1 AND p2 < q2 (Query 29) p starts-1 q p1 = q1 AND q2 < p2 (Query 30) p finishes q q1 < p1 AND p2 = q2 (Query 31) p finishes-1 q p1 < q1 AND p2 = q2 (Query 32) p OVERLAPS q p overlaps q (Query 57) p IS NULL p1 IS NULL (Query 33) Datetime Constructors: beginning(p) p1 (Query 50) previous(p) p1 - 1 MICROSECOND (Query 51) last(p) p2 - 1 MICROSECOND (Query 52) ending(p) p2 (Query 53) Interval Constructors: duration(p) p2 - p1 (returns a timestamp duration) (Query 36) extract_time_zone(p) Not supported Period Constructors: p + i [p1 + i, p2 + i) (Query 54) i + p [i + p1, i + p2) (Query 55) p - i [p1 - i, p2 - i) (Query 56) a extend b [a, b + 1 MICROSECOND) (Query 59) p extend q [min(p1, q1), max(p2, q2)) (Query 60) Embedded SQL only p extend a [min(p1, q1), max(p2, q2)) (Query 61) Embedded SQL only a extend p [min(a, p1), max(a, p2)) (Query 61) Embedded SQL only p INTERSECT q [max(p1, q1), min(p2, q2)) (Query 63) Embedded SQL only p - q [q2, p2) if p starts-1 q or p overlaps-1 q;
[p1, q1) if p finishes-1 q or p overlaps q;
p otherwise. (Query 64) Embedded SQL onlyp UNION q p extend q (Query 60) p AT TIME ZONE i Not supported p AT LOCAL (p1 + CURRENT TIMEZONE, p2 + CURRENT TIMEZONE) (Query 34) Other Operators: CAST(a AS PERIOD) [a, a + 1 MICROSECOND) (Query 62) CAST(p AS CHAR) '[' CONCAT CHAR(p1) CONCAT ', ' CONCAT CHAR(p2) CONCAT ')' (Query 35)
Brad W. Traweek, Department of Computer Science,
University of Arizona (traweek@cs.arizona.edu)
Rachana R. Shah, Department of Computer Science,
University of Arizona (rachana@cs.arizona.edu)
Jian Yang, Department of Computer Science, University of
Arizona (yangjian@cs.arizona.edu)
April 27, 1999 (Last Update)
Brad W. Traweek, Department of Computer Science,
University of Arizona (traweek@cs.arizona.edu)
December 16, 1997 (Last Update)