Developing Time-Oriented Applications in SQL Richard T. Snodgrass

DATA TYPES

Informix Universal Server Implementation Examples

  

Detailed Contents

This document outlines temporal data type support for the Informix DBMS. It follows the general outline of the TDB book and is arranged in the following manner.

Instants and Intervals

Operations
Examples

Periods

Operations
Examples

Overview

Support for temporal datatypes is provided by Informix through the DATE,DATETIME and the INTERVAL data types. The DATE type can be used to represent dates to the granularity of a day. It is stored internally as an INTEGER which is the number of days since 31 December 1899, so that 1 January 1900 is day 1). This occupies 4 bytes of disk space. Informix-SQL provides formatting and converting utilities for dates such as DATE, MDY, YEAR, MONTH, DAY and WEEKDAY. The DATETIME type is an equivalent of the TIMESTAMP in SQL-92 and can have various precisions such as YEAR TO MONTH, YEAR TO DAY, MONTH TO SECOND, YEAR TO SECOND etc. Thus the TIME data type in SQL-92 can be adequately represented by a DATETIME datatype of HOUR TO SECOND precision. Furthermore the time can range from HOUR down to FRACTION(5). The FRACTION qualifier has a default precision of 3 corresponding to milliseconds. One of the interesting aspects of Informix-SQL is that it provides support for INTERVAL. An INTERVAL can have components from either the set YEAR, MONTH or from the set DAY, HOUR, MINUTE, SECOND, FRACTION. The two sets cannot be mixed. The current date is given by TODAY and the current timestamp is given by CURRENT. The precision of the leading component of an INTERVAL and the final component can be specified if it is FRACTION. Unfortunately, there is no support for timezones in Informix. Another powerful construct provided by Informix is EXTEND which can be used to alter the precision of DATETIME values. This returns a DATETIME value with the year and month extracted from the corresponding values of CURRENT, and the minutes and the seconds set to zero if not provided. Thus:

EXTEND (DATETIME(16 19) DAY TO HOUR, YEAR TO SECOND )

returns '1997-12-16 19:00:00'

The EXTEND function can be used to convert strings into DATE types. Informix does not provide support for converting date types into CHAR nor can an integer be converted into a time data type. Informix supports standard predicates such as =, <, >, <>, BETWEEN. Tables 2.1.1 and 2.2.1 show how the facilities in SQL-92 can be simulated to some degree in Informix.

  

Instants and Intervals (Informix Universal Server)

Operations

SQL-92 
 
Informix Equivalent 
 
Types:
DATE DATE
TIME DATETIME HOUR TO SECOND
TIMESTAMP DATETIME YEAR TO FRACTION
TIME WITH TIME ZONE No equivalent
TIMESTAMP WITH TIME ZONE No equivalent
INTERVAL YEAR TO MONTH INTERVAL YEAR TO MONTH
INTERVAL DAY TO SECOND INTERVAL DAY TO SECOND
Literals:
DATE '1991-01-01' DATE("01/01/91")
TIME '12:34:56' DATETIME(12:34:56) HOUR TO SECOND
TIMESTAMP '1997-01-01 12:34:56' DATETIME(1997-01-01 12:34:56) YEAR TO SECOND
INTERVAL '3-4' YEAR TO MONTH INTERVAL(3-4) YEAR TO MONTH
INTERVAL '1 23:45:12' DAY TO SECOND INTERVAL(1 23:45:12) DAY TO SECOND
Predicates:
d1 = d2 d1 = d2
d1 < d2 d1 < d2
d1 <> d2 d1 <> d2
d1 BETWEEN d2 AND d3 d1 BETWEEN d2 AND d3
i1 = i2 i1 = i2
i1 < i2 i1 < i2
i1 <> i2 i1 <> i2
i1 BETWEEN i2 AND i3 i1 BETWEEN i2 AND i3
d IS NULL d IS NULL
i IS NULL i IS NULL
(d1, i2) OVERLAPS (d3, d4) d1 <= d4 AND d3 <= (d1 + i2)
Datetime Constructors:
d + i d + i
i + d Must be faked with d + i
d - i d - i
d AT i Not supported
d AT LOCAL Not supported
CURRENT_DATE TODAY
CURRENT_TIME CURRENT HOUR TO SECOND
CURRENT_TIMESTAMP CURRENT
Internal Constructors:
i1 + i2 i1 + i2
i1 - i2 i1 - i2
d1 - d2 qual d1 - d2 qual
d1 - d2 INTERVAL MONTH Not supported
i * n i * n
n * i Must be faked with i * n
i / i Not supported
+ i + i
- i - i
Other Operators:
CAST(d AS DATE) DATE(d)
CAST(d AS TIME) EXTEND(DATE(d), HOUR TO SECOND)
CAST(d AS TIMESTAMP) (where d is a DATE) EXTEND(d, YEAR TO SECOND)
CAST(d AS TIMESTAMP) (where d is a TIME) EXTEND(d, YEAR TO SECOND)
CAST(i AS INTERVAL YEAR TO MONTH) INTERVAL(i) YEAR TO MONTH
CAST(i AS INTERVAL DAY TO SECOND) INTERVAL(i) DAY TO SECOND
CAST(d AS CHAR) Not possible
CAST(i AS CHAR) Not possible
CAST(i AS INTEGER) (where i is a DAY) Not supported
CAST(i AS INTEGER) (where i is a HOUR) Not supported
CAST(i AS INTEGER) (where i is a MINUTE) Not supported
CAST(i AS INTEGER) (where i is a SECOND) Not supported
EXTRACT(DAY from d) DAY( d ) (returns an integer)
EXTRACT(DAY from i) Not possible
EXTRACT(HOUR from i) Not possible
Operators not in SQL-92:
Extract Month from d (where d is DATE) MONTH(d)
Extract Weekday from d (where d is DATE) WEEKDAY(d)
Extract Year from d (where d is DATE) YEAR(d)

Instant and Interval Examples


  

Periods (Informix Universal Server)

Operations

Periods are not currently supported in Informix, but simulation thereof is easily achievable by using two DATETIMEs to represent the inclusive start and exclusive end of the period (ie.: [DATETIME, DATETIME) ).

SQL-92 
 
Informix Equivalent 
 
Types:
period [DATETIME, DATETIME) as [p1, p2)
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 p1 = q1 AND q2 < p2
p finishes q q1 < p1 AND p2 = q2
p finishes-1 q p1 < q1 AND p2 = q2
p OVERLAPS q p1 < q2 AND q1 < p2
p IS NULL p1 IS NULL
Datetime Constructors:
beginning(p) p1
previous(p) p1 - INTERVAL(1) DAY
last(p) p2 - INTERVAL(1) DAY
ending(p) p2
Interval Constructors:
duration(p) p2 - p1
extract_time_zone(p) Not supported
Period Constructors:
p + i [p1 + i, p2 + i)
i + p [p1 + i, p2 + i)
p - i [p1-i, p2-i)
a extend b Not possible
p extend q Not possible
p extend a Not possible
a extend p Not possible
p INTERSECT q Not possible
p - q Not possible
p UNION q Not possible
p AT TIME ZONE i Not supported
p AT LOCAL Not supported
Other Operators:
CAST(a AS PERIOD) [a, a + INTERVAL(1) DAY)
CAST(p AS CHAR) Not supported

Here 1 signifies an interval of one day i.e. INTERVAL(1) DAY TO DAY

Period Examples

References

  1. 'Informix guide to SQL : reference with using triggers' Informix Software Inc. 1995
  2. 'Using INFORMIX-SQL' Jonathan Leffler, Addison-Wesley 1991
  3. 'Informix Unleashed' John McNally, Glenn Miller, Jim Prajesh, Jose' Fortuny, et al., Sams Publishing 1997

HTML Credits:

Anand Wagle, Department of Electrical & Computer Engg., University of Arizona (anand@ece.arizona.edu)
Jason Cox, Department of Computer Science, University of Arizona (jcox@cs.arizona.edu)
Jian Yang, Department of Computer Science, University of Arizona (yangjian@cs.arizona.edu)
April 27, 1999(Last Update) ;

Informix-Specific Code Credits:

Anand Wagle, Department of Electrical & Computer Engg., University of Arizona (anand@ece.arizona.edu)
Rachana Shah, Department of Computer Science, University of Arizona (rachana@cs.arizona.edu)
Jason Cox, Department of Computer Science, University of Arizona (jcox@cs.arizona.edu)
March 8, 1998 (Last Update) ;