Developing Time-Oriented Applications in SQL Richard T. Snodgrass

DATA TYPES

Microsoft Access 2000 Implementation Examples

      

Detailed Contents

This document outlines temporal data type support for the Microsoft Access DBMS, as described in Chapters 2 & 3. It follows the general outline of the TDB book and is arranged in the following manner.

Instants and Intervals

Operations
Examples

Periods

Operations
Examples


   

Instants and Intervals (Microsoft Access 2000)

Operations

SQL-92 
 
Microsoft Access 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 simulated interval in months
INTERVAL DAY TO SECOND simulated interval in seconds
Literals:
DATE '1997-01-01' #1997-01-01# or DateValue("1997-01-01")
TIME '12:34:56' #12:34:56# or TimeValue("12:34:56")
TIMESTAMP '1997-01-01 12:34:56' #1997-01-01 12:34:56# , or Format("1997-01-01 12:34:56", "YYYY-MM-DD HH:NN:SS")
INTERVAL '3-4' YEAR TO MONTH (Simulated interval) 40 (months)
INTERVAL '1 23:45:12' DAY TO SECOND (Simulated interval) 171912 (seconds)
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 j1 = j2
i1 < i2 j1 < j2
i1 <> i2 j1 <> j2
i1 BETWEEN i2 AND i3 j1 BETWEEN j2 AND j3
d IS NULL d IS NULL
i IS NULL j IS NULL
(d1, i2) OVERLAPS (d3, d4) d1 <= d4 AND d3 <= DateAdd("d", j2, d1)
Datetime Constructors:
d + i DateAdd("d", j, d)
i + d DateAdd("d", j, d)
d - i DateAdd("d", -j, d)
d AT i not supported
d AT LOCAL not supported
CURRENT_DATE Date()
CURRENT_TIME Time()
CURRENT_TIMESTAMP Now()
Internal Constructors:
i1 + i2 j1 + j2
i1 - i2 j1 - j2
d1 - d2 qual d1 - d2 (Result is a (fractional) number of days), also DateDiff("D", d2, d1 (result is an (integer) number of days)
d1 - d2 INTERVAL MONTH DateDiff("M", d2, d1) (result is an (integer) number of months)
i * n j * n
n * i n * j
i / i j / j
+ i + j
- i - j
Other Operators:
CAST(d AS DATE) DateValue(d) or Format(d, "mm/dd/yyyy")
CAST(d AS TIME) TimeValue(d) or Format(d, "hh:mm:ss")
CAST(d AS TIMESTAMP) (where d is a DATE) Format(d, "YYYY-MM-DD HH:NN:SS")
CAST(d AS TIMESTAMP) (where d is a TIME) Format(d, "YYYY-MM-DD HH:NN:SS")
CAST(i AS INTERVAL YEAR TO MONTH) not possible
CAST(i AS INTERVAL DAY TO SECOND) not possible
CAST(d AS CHAR) Cstr(d)
CAST(i AS CHAR) Cstr(j)
CAST(i AS INTEGER) (where i is a DAY) CLng (j)
CAST(i AS INTEGER) (where i is a HOUR) CLng( j*24)
CAST(i AS INTEGER) (where i is a MINUTE) CLng( j*1440)
CAST(i AS INTEGER) (where i is a SECOND) CLng( j*86400)
EXTRACT(DAY from d) Day(d), DatePart("d", d)
EXTRACT(DAY from i) Day (j), DatePart("d", j)
EXTRACT(HOUR from i) Hour(j), DatePart("h", j)
Operators not in SQL-92:
Return a Date for a specified year, month, and day. DateSerial (year, month, day) (year-integer between 100 and 9999, or a numeric expression; month, day -any integer or numeric expression)
Return a Date containing the time for a specific hour, minute, and second TimeSerial (hour, minute, second) (hour-integer or number between 0 and 23, or any numeric expression; minute, second -any integer or numeric expression)
Return a Long integer specifying the number of time intervals between two specific dates DateDiff (interval, date1 , date2) (interval string can be year, month, weekday week ... till second)
Return an Integer containing the specified part of a given date DatePart (interval, date)
Return a Date containing a date to which a specified time interval has been added. DateAdd(interval, date)
Extract part of the date d Year (d), Month(d), Weekday (d), ...... Second (d)
Return a date CDate (expression). Any string expression or numeric expression
Note: Microsoft Access does not support INTERVAL type. j here simulates the interval and j = d - #12/30/1989 00:00:00# (number of days after "12/30/1899 00:00:00") or j denotes number of days or number of intervals indicated by interval string expression that is used in MS Access function such as DateAdd( ) function etc.

Examples

The following table lists simple query examples in MS Access SQL to show how each SQL-92 Instant and Interval operations works in MS Access DBMS. A simple data file named AccessDataTypes.mdb was created in Microsoft Access 97 to show the query examples. In the datafile table window, you can fine a Student table which was populated with student's record (Student Name; Birth Date; The Start Date that the student entered the school; the End Date that the student finished his/her school, student's address). All queries are listed in the datafile query window. The following table lists the Instant and Interval Query Examples in the Query Window. In the table, the the first column list SQL-92 Instant and Interval operation; second column the Query name; third column Query Description; and the fourth column Microsoft Access 97 equivalent SQL query.
SQL-92 
 
Query Name 
 
Query Description 
 
MS Access SQL Query 
 
Types:
DATE In-Date Information on Student's birthdate using DateValue () function SELECT StudentName, DateValue(BirthDate) AS [Birth Date] FROM Student ;
TIME In-Time Information on Student's birth time using TimeValue() Function SELECT StudentName, TimeValue(BirthDate) AS [Birth Time] FROM Student ;
TIMESTAMP In-Datetime Information on Student's birth Timestamp SELECT StudentName, BirthDate AS [Birth Timestamp] FROM Student ;
TIME WITH TIME ZONE

no equivalent
TIMESTAMP WITH TIME ZONE

no equivalent
INTERVAL YEAR TO MONTH In-Literal 6 Information on student's who was born 40 months ahead "1997-01-01 00:00:00". SELECT * FROM Student WHERE DateDiff("m", BirthDate, #1997-01-01 00:00:00#)>40;
INTERVAL DAY TO SECOND In-Literal 7 Information on student's who was born 171912 seconds (1 day 23 hour 45 minutes and 12 seconds) ahead "1997-01-01 00:00:00". SELECT * FROM Student WHERE DateDiff("s", BirthDate, #1997-01-01 00:00:00#)>171912;
Literals:
DATE '1991-01-01' In-Literal 1 Information on student who born on January 1, 1970. using = and #1997-01-01# SELECT * FROM Student WHERE DateValue(BirthDate) = #1970-01-01# ;
DATE '1991-01-01' In-Literal 2 Information on student who born on January 1, 1970. using DateValue("1997-01-01") SELECT * FROM Student WHERE DateValue(BirthDate) = DateValue("1970-01-01");
TIME '12:34:56' In-Literal 3 Information on student's who was born before noon, using #12:00:00# SELECT * FROM Student WHERE TimeValue(BirthDate) < #12:00:00# ;
TIME '12:34:56' In-Literal 4 Information on student's who was born before noon, using TimeValue("12:00:00") SELECT * FROM Student WHERE TimeValue(BirthDate) < TimeValue("12:00:00");
TIMESTAMP '1997-01-01 12:34:56' In-Literal 5 Information on student's who was born 10950 days (about 30 years) ahead "1997-01-01 00:00:00", using #1997-01-01 12:00:00# SELECT * FROM Student WHERE #1997-01-01 00:00:00# - BirthDate >10950 ;
INTERVAL '3-4' YEAR TO MONTH Same as In-Literal 6

INTERVAL '9 23:45:12' DAY TO SECOND Same as In-Literal 7

Predicates:
d1 = d2 Same as In-Literal1

d1 < d2 In-Predicate Date > or < Information on students born on January 1, 1970. using d1 > d2 and d1 < d2 predicates SELECT * FROM Student WHERE NOT DateValue(BirthDate) > #1970-01-01# AND NOT DateValue(BirthDate) < #1970-01-01# ;
d1 <> d2 In-Predicate Date <> Information on students born on January 1, 1970. using d1 <> d2 predicate. SELECT * FROM Student WHERE NOT DateValue(BirthDate) <> #1970-01-01# ;
d1 BETWEEN d2 AND d3 In-Predicate d1 Between d2 and d3 Information on students born on January 1, 1970. using date1 between date2 and date3 SELECT * FROM Student WHERE DateValue(BirthDate) BETWEEN #1970-01-01# AND #1970-01-01# ;
d1 BETWEEN d2 AND d3 In-Predicate Not d1 Not Between d2 and d3 Information on students born on January 1, 1970. using NOT date1 NOT between date2 and date3 SELECT * FROM Student WHERE NOT DateValue(BirthDate) NOT BETWEEN #1970-01-01# AND #1970-01-01# ;
i1 = i2 In-Predicate j1 = j2 Information on students born on January 1, 1970. using j1 = j 2 predicate. SELECT * FROM Student WHERE DateDiff("D", BirthDate, #1970-01-01#) = 0 ;
i1 < i2 In-Predicate j1 < j2 and j1> j2 Information on students born on January 1, 1970. using j1 < j2 and j1 > j2 predicates. SELECT * FROM Student WHERE NOT DateDiff("D", BirthDate, #1970-01-01#) < 0 and NOT DateDiff("D", BirthDate, #1970-01-01#) > 0;
i1 <> i2 In-Predicate j1 <> j2 Information on students born on January 1, 1970. using j1 <> j2 predicate SELECT * FROM Student WHERE NOT DateDiff("D", BirthDate, #1970-01-01#) <> 0 ;
i1 BETWEEN i2 AND i3 In-Predicate j1 between j2 and j3 Information on students born on January 1, 1970. using interval 1 between interval 2 and interval 3 SELECT * FROM Student WHERE DateDiff("D", BirthDate, #1970-01-01#) BETWEEN 0 AND 0 ;
d IS NULL In-Predicate IS NULL Information on student whose StartDate is NULL (not entered admitted date) SELECT * FROM Student WHERE StartDate = NULL ;
i IS NULL

not possible (not support interval type)
(d1, i2) OVERLAPS (d3, d4) In-Predicate OVERLAPS Information on students born on January 1, 1970. using SQL92 OVERLAPS operator SELECT * FROM Student WHERE DateValue(BirthDate) <= #1970-01-01# AND #1970-01-01# <= DateAdd("D", 0, BirthDate) ;
Datetime Constructors:
d + i In-d+i Constructor 1 Information on students born on January 1, 1970. using d+i constructor, way 1 SELECT * FROM Student WHERE DateValue(BirthDate) = DateAdd("YYYY", 0, #1970-01-01#) ;
d + i In-d+i Constructor 2 Information on students born on January 1, 1970. using d+i constructor, way 2 SELECT * FROM Student WHERE DateValue(BirthDate) = DateAdd("M", 0, #1970-01-01#) ;
d + i In-d+i Constructor 3 Information on students born on January 1, 1970. using d+i constructor, way 3 SELECT * FROM Student WHERE DateValue(BirthDate)=DateAdd("D", 0, #1970-01-01#) ;
i + d Same as In-d+i Constructor 1

d - i In-d-i Constructor 1 Information on students born on January 1, 1970. using d-i constructor, way 1 SELECT * FROM Student WHERE DateValue(BirthDate) = DateAdd("YYYY", -0, #1970-01-01#) ;
d - i In-d-i Constructor 2 Information on students born on January 1, 1970. using d-i constructor, way 2 SELECT * FROM Student WHERE DateValue(BirthDate) = DateAdd("M", -0, #1970-01-01#) ;
d - i In-d-i Constructor 3 Information on students born on January 1, 1970. using d-i constructor, way 3 SELECT * FROM Student WHERE DateValue(BirthDate) = DateAdd("D", -0, #1970-01-01#) ;
d AT i

not supported
d AT LOCAL

not supported
CURRENT_DATE In-CurrentDate Information on current Date, using Date() SELECT DISTINCT Date ( ) AS [Current Date] FROM Student;
CURRENT_TIME In-CurrentTime Information on current Time, using Time() SELECT DISTINCT Time ( ) AS [Current Time] FROM Student ;
CURRENT_ TIMESTAMP In-Current TimeStamp Information on current timestamp, using Now() SELECT DISTINCT Now ( ) AS CurrentTimestamp FROM Student ;
Internal Constructors:
i1 + i2 In-j1 + j2 Information on students born on January 1, 1970. using j1 + j2 constructor. SELECT * FROM Student WHERE DateDiff("D", BirthDate, #1970-01-01#) + 0 = 0 ;
i1 - i2 In-j1 - j2 Information on students born on January 1, 1970. using j1 - j2 constructor. SELECT * FROM Student WHERE DateDiff("D", BirthDate, #1970-01-01#) - 0 = 0;
d1 - d2 qual In-d1 - d2 Information on students of how many days studied in University using d1 - d2 SELECT StudentName, EndDate-StartDate AS [Days studied in University] FROM Student;
d1 - d2 INTERVAL MONTH In-d1 - d2 in month Information on students of how many Months studied in University using DateDiff() function. SELECT StudentName, DateDiff("M", StartDate, EndDate) AS [Months Studied in University] FROM Student;
i * n In- j*n Information on students born on January 1, 1970. using j*n constructor. SELECT * FROM Student WHERE DateDiff("D", BirthDate, #1970-01-01#) * n = 0;
n * i Same as In- j*n

i / i In-j/j Information on students born on January 1, 1970. using j/j constructor. SELECT * FROM Student WHERE DateDiff("D", BirthDate, #1970-01-01#)/ 1234567= 0;
+ i In-(+j) Information on students born on January 1, 1970. using +j constructor. SELECT * FROM Student WHERE +DateDiff("D", BirthDate, #1970-01-01#) = 0 ;
- i In-(-j) Information on students born on January 1, 1970. using -j constructor. SELECT * FROM Student WHERE - DateDiff("D", BirthDate, #1970-01-01#) = 0;
Other Operators:
CAST(d AS DATE) In-Operator 1 Information on students born on January 1, 1970. using Format function to cast date. SELECT * FROM Student WHERE Format(BirthDate, "mm/dd/yy") = Format("1970-01-01", "mm/dd/yy") ;
CAST(d AS DATE) Same as In-Literal 2

CAST(d AS TIME) Same as In-Literal 4

CAST(d AS TIMESTAMP) (where d is a DATE) In-Operator Cast Current Date as Timestamp Information on current Date, using Date(), then cast into timestamp using format function. SELECT DISTINCT Format(Date ( ), "YYYY-MM-DD HH:NN:SS") AS [TIMESTAMP casted from Current Date] FROM Student;
CAST(d AS TIMESTAMP) (where d is a TIME) In-Operator Cast Current time as TimeStamp Information on current Time, using Time(), then cast into timestamp using format function. SELECT DISTINCT Format(Time ( ), "YYYY-MM-DD HH:NN:SS") AS [TIMESTAMP casted from Current Time] FROM Student;
CAST(i AS INTERVAL YEAR TO MONTH)

not possible
CAST(i AS INTERVAL DAY TO SECOND)

not possible
CAST(d AS CHAR) In-Predicate Like 2 Information on students born on April using Like predicate and Cstr() function casting Formated "long date" BirthDate into char. SELECT * FROM Student WHERE Cstr(Format(BirthDate,"Long Date")) LIKE "*April*";
CAST(i AS CHAR) In-Predicate Like 3 Information on students born on April using Like predicate and Cstr() function casting month of BirthDate into char. SELECT * FROM Student WHERE Cstr(Month(BirthDate)) LIKE "4";
CAST(i AS INTEGER) (where i is a DAY) In-Operator CAST INTERGER 1 Cast the Day From Current Date into INTERGER day SELECT DISTINCT Date ( ) AS [Current Date], clng (Day(Date ( ))) AS [Current Day as INTERGER Day] FROM Student;
CAST(i AS INTEGER) (where i is a HOUR) In-Operator CAST INTERGER 2 Cast the Day From Current Date into INTERGER hour SELECT DISTINCT Date ( ) AS [Current Date], clng (Day(Date ( ))*24) AS [Current Day as INTERGER Hour] FROM Student;
CAST(i AS INTEGER) (where i is a MINUTE) In-Operator CAST INTERGER 3 Cast the Day From Current Date into INTERGER Minute SELECT DISTINCT Date ( ) AS [Current Date], clng (Day(Date ( ))*1440) AS [Current Day as INTERGER Minute] FROM Student;
CAST(i AS INTEGER) (where i is a SECOND) In-Operator CAST INTERGER 4 Cast the Day From Current Date into INTERGER Second SELECT DISTINCT Date ( ) AS [Current Date], clng (Day(Date ( ))*86400) AS [Current Day as INTERGER Second] FROM Student;
EXTRACT(DAY from d) In-Operator Extract 1 Extract Current Day using DatePart function. SELECT DISTINCT DatePart("D",Time ( )) AS [Current Day] FROM Student;
EXTRACT(DAY from i) In-Operator Extract 2 Extract Day from interval j = 35770.1234 using DatePart function. SELECT DISTINCT DatePart("D",35770.1234) AS Day FROM Student;
EXTRACT(HOUR from i) IN-Operator Extract 3 Extract Hour from interval j = 35770.1234 using DatePart function. SELECT DISTINCT DatePart("H", 35770.1234) AS Hour FROM Student;
Operators not in SQL-92:
Return a Date for a specified year, month, and day. In-NotInSQL92 1 Information on students born on January 1, 1970. using DateSerial () function. SELECT * FROM Student WHERE DateValue(BirthDate) = DateSerial("1970", "1","1");
Return a Date containing the time for a specific hour, minute, and second In-NotInSQL92 2 Information on current time using TimeSerial () function. SELECT DISTINCT TimeSerial(Hour(Time()), Minute(Time()), Second(Time())) FROM Student;
Return a Long integer specifying the number of time intervals between two specific dates In-NotInSQL92 3 Information on students born on January 1, 1970. using DateDiff (interval, date) function. SELECT * FROM Student WHERE DateDiff("YYYY", BirthDate, #1970-01-01#) = 0 AND DateDiff("M", BirthDate, #1970-01-01#)=0 AND DateDiff("D", BirthDate, #1970-01-01#)= 0;
Return an Integer containing the specified part of a given date In-NotInSQL92 4 Information on students born on January 1, 1970. using DatePart (interval, Date) extract function SELECT * FROM Student WHERE DatePart("YYYY", BirthDate) = 1970 AND DatePart("M", BirthDate) = 1 AND DatePart("D", BirthDate) = 1;
Return a Date containing a date to which a specified time interval has been added. In-NotInSQL92 5 Information on students born on January 1, 1970. using Year(), Month(), Day() extract function. SELECT * FROM Student WHERE Year(BirthDate) = 1970 AND Month(BirthDate)=1 AND Day(BirthDate)=1;
Others

In-Predicate d1>=d2, d1<=d2 Information on students born on January 1, 1970. using d1>=d2 and d1<=d2 predicates. SELECT * FROM Student WHERE DateValue(BirthDate) >= #1970-01-01# And DateValue(BirthDate) <= #1970-01-01#;

In-Predicate Like Information on students born on January 1, 1970. using Like predicate SELECT * FROM Student WHERE DateValue(BirthDate) Like #1970-01-01#;

In-Predicate Not Like Information on students born on January 1, 1970. using NOT LIKE predicate SELECT * FROM Student WHERE Not DateValue(BirthDate) Not Like #1970-01-01#;

In-Predicate IN Information on students born on January 1, 1970. using IN Predicate. SELECT * FROM Student WHERE DateValue(BirthDate) In (#1970-01-01#);

In-Predicate Not IN Information on students born on January 1, 1970. using NOT IN Predicate. SELECT * FROM Student WHERE Not DateValue(BirthDate) Not In (#1970-01-01#);


  

Periods (Microsoft Access 2000)

Operations

SQL-92 
 
Microsoft Access Equivalent 
 
Types:
period [Date, Date)
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 q1 < p1 AND p2 = q2
p finishes-1 q p1 < q1 AND q2 = p2
p OVERLAPS q p1 <= q2 AND q1 <= p2
p IS NULL p1 IS NULL
Datetime Constructors:
beginning(p) p1
previous(p) p1 - 1, DateAdd(interval, -1, p1)
last(p) p2 - 1, DateAdd(interval, -1, p2)
ending(p) p2
Interval Constructors:
duration(p) p2 - p1, DateDiff(interval, p1, p2)
extract_time_zone(p) not supported
Period Constructors:
p + i p1 + j or p1 = DateAdd(interval, j, p1); p2 + j or p2 = DateAdd(interval, j, p2)
i + p p1 + j or p1 = DateAdd(interval, j, p1); p2 + j or p2 = DateAdd(interval, j, p2)
p - i p1 - j or p1 = DateAdd(interval, -j, p1); p2 - j or p2 = DateAdd(interval, -j, p2)
a extend b not possible to do in MS Access SQL
p extend q not possible to do in MS Access SQL
p extend a not possible to do in MS Access SQL
a extend p not possible to do in MS Access SQL
p INTERSECT q not possible to do in MS Access SQL
p - q not possible to do in MS Access SQL
p UNION q not possible to do in MS Access SQL
p AT TIME ZONE i not supported
p AT LOCAL not supported
Other Operators:
CAST(d AS PERIOD) [d, DateAdd ("D", 1, d))
CAST(p AS CHAR) "["+ Cstr(p1)+ "-"+ Cstr(p2)+ ")"
Note: MS Access does not support INTERVAL and PERIOD data type. Two datetime fields p1, p2, which are at the second granularity, are used to simulate the close-open period p. The table here shows how the period operation can be implemented in MS Access. a and b denote MS Access datetime values, j denotes number of days or number of intervals indicated by interval string expression that is used in MS Access function such as DateAdd( ) function etc.

Examples

The following table lists simple query examples in MS Access SQL to show how each SQL-92 Period operations works in MS Access DBMS. A simple data file named AccessDataTypes.mdb was created in Microsoft Access 97 to show the query examples. In the datafile table window, you can fine a Student table which was populated with student's record (Student Name; Birth Date; The Start Date that the student entered the school; the End Date that the student finished his/her school, student's address). The [StartDate, EndDate) is used to simulate the SQL-92 period data type. All queries are listed in the datafile query window. The following table lists the Period Query Examples in the Query Window. In the table, the the first column list SQL-92 Period operation; second column the Query name; third column Query Description; and the fourth column Microsoft Access 97 equivalent SQL query.
SQL-92 
 
Query Name 
 
Query Description 
 
MS Access SQL Query 
 
Types:
period

[StartDate, EndDate) (Simulated period in MS Access)
Predicates:
p equals q Period-Equal Predicate Select Students who studied in the period that equal [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE StartDate = #8/25/90 00:00:00# And EndDate = #8/25/94 00:00:00# ;
p before q Period-Before Predicate Select Students who studied in the period that before [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE EndDate < #8/25/90 00:00:00# ;
p before-1 q Period-Before-1 Predicate Select Students who studied in the period that before -1 [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE #8/25/94 00:00:00# < StartDate ;
p meets q Period-Meets Predicate Select Students who studied in the period that meets [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE EndDate = #8/25/90 00:00:00# ;
p meets-1 q Period-Meets-1 Predicate Select Students who studied in the period that meets-1 [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE #8/25/94 00:00:00# = StartDate ;
p overlaps q Period-Overlaps Predicate Select Students who studied in the period that overlaps [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE StartDate < #8/25/94 00:00:00# AND #8/25/90 00:00:00# < EndDate ;
p overlaps-1 q Period-Overlaps-1 Predicate Select Students who studied in the period that overlaps-1 [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE #8/25/90 00:00:00# < EndDate AND StartDate < #8/25/94 00:00:00# ;
p during q Period-During Predicate Select Students who studied in the period that during [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE #8/25/90 00:00:00# < StartDate AND Enddate < #8/25/94 00:00:00# ;
p during-1 q Period-During-1 Predicate Select Students who studied in the period that during -1 [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE StartDate < #8/25/90 00:00:00# AND #8/25/94 00:00:00# < EndDate ;
p starts q Period-Starts Predicate Select Students who studied in the period that starts [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE StartDate = #8/25/90 00:00:00# AND Enddate < #8/25/94 00:00:00# ;
p starts-1 q Period-Starts-1 Predicate Select Students who studied in the period that starts-1 [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE #8/25/90 00:00:00# = StartDate AND #8/25/94 00:00:00# < EndDate ;
p finishes q Period-Finishes Predicate Select Students who studied in the period that finishes [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE #8/25/90 00:00:00# < StartDate AND Enddate = #8/25/94 00:00:00# ;
p finishes-1 q Period-Finishes-1 Predicate Select Students who studied in the period that finishes-1 [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE StartDate < #8/25/90 00:00:00# AND #8/25/94 00:00:00# = EndDate ;
p OVERLAPS q Period-OVERLAPS-SQL92 Predicate Select Students who studied in the period that OVERLAPS [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE StartDate <= #8/25/94 00:00:00# AND #8/25/90 00:00:00# <= EndDate ;
p IS NULL Period-IS NULL Select Students who studied in the period that IS NULL (Not entered the study period) SELECT Student.* FROM Student WHERE StartDate = NULL ;
Datetime Constructors:
beginning(p) Period-Beginning Constructor Select Students who studied in the period p that beginning (p)=8/25/90 SELECT Student.* FROM Student WHERE StartDate = #8/25/90 00:00:00# ;
previous(p) Period-Previous Constructor 1 Select Students who studied in the period p that previous (p)=8/24/90 SELECT Student.* FROM Student WHERE DateAdd("D", -1, StartDate) = #8/24/90 00:00:00#;
previous(p) Period-Previous Constructor 2 Select Students who studied in the period p that previous (p)=8/24/90 SELECT Student.* FROM Student WHERE StartDate-1 = #8/24/90 00:00:00#;
last(p) Period-Last Constructor 1 Select Students who studied in the period p that last (p) = 8/24/94 SELECT Student.* FROM Student WHERE DateAdd ("D", -1, EndDate) = #8/24/94 00:00:00#;
last(p) Period-Last Constructor 2 Select Students who studied in the period p that last (p) = 8/24/94 SELECT Student.* FROM Student WHERE EndDate-1 = #8/24/94 00:00:00#;
ending(p) Period-Ending Constructor Select Students who studied in the period p that ending (p) = 8/25/94 SELECT Student.* FROM Student WHERE EndDate = #8/25/94 00:00:00#;
Interval Constructors:
duration(p) Period-Duration Interval 1 Select Students who studied in the period p that Duration (p) >=1460 Days (4 years) SELECT Student.* FROM Student WHERE EndDate-StartDate >= 1460;
duration(p) Period-Duration Interval 2 Select Students who studied in the period p that Duration (p) >= 4 years (1460 Days) SELECT Student.* FROM Student WHERE DateDiff("YYYY", StartDate, EndDate) >= 4 ;
extract_time_zone(p)

not supported
Period Constructors:
p + i Period-Constructor p+i Select Students who studied in the period that 1 year ahead [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE DateAdd ("YYYY", 1, StartDate) = #8/25/90 00:00:00# AND DateAdd("YYYY", 1, EndDate) = #8/25/94 00:00:00# ;
i + p Same as above Same as above Same as above
p - i Period-Constructor p-i Select Students who studied in the period that 1 year after [8/25/90, 8/25/94) SELECT Student.* FROM Student WHERE DateAdd ("YYYY", -1, StartDate) = #8/25/90 00:00:00# AND DateAdd("YYYY", -1, EndDate) = #8/25/94 00:00:00# ;
a extend b

not possible to do in MS Access SQL
p extend q

not possible to do in MS Access SQL
p extend a

not possible to do in MS Access SQL
a extend p

not possible to do in MS Access SQL
p INTERSECT q

not possible to do in MS Access SQL
p - q

not possible to do in MS Access SQL
p UNION q

not possible to do in MS Access SQL
p AT TIME ZONE i

not supported
p AT LOCAL

not supported
Other Operators:
CAST(a AS PERIOD) Cast d as period Cast the BirthDate as PERIOD SELECT "[" + Cstr(BirthDate)+ "-" +Cstr(DateAdd("D",1,BirthDate))+")" AS BirthPeriod FROM Student;
CAST(p AS CHAR) Cast p as Char Cast the period as Char SELECT "[" + Cstr(StartDate)+ "-" +Cstr(EndDate)+")" AS StudyPeriod FROM Student;

HTML Credits:

Ze-Yuan Zou, Department of Computer Science, University of Arizona (zeyuan@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)
November 10, 1998 (Last Update)

Microsoft Access-Specific Code Credits:

Ze-Yuan Zou, Department of Computer Science, University of Arizona (zeyuan@cs.arizona.edu)
December 1, 1997 (Last Update)