Home Page for the TeradataForum
 

 

Library: White Papers


 

Dates and Times in Teradata
(thru V2R4.1)

Written by Geoffrey Rommel
(Sears, Roebuck and Co.)


Dates, times, and timestamps in Teradata (V2R4.1) can be a little tricky. This document explains how to do various things that you may want to do.


Preliminaries

The examples below use Teradata syntax, so they assume that you are running in BTEQ. If you are using Queryman, be sure to uncheck the option box "Allow use of ODBC SQL Extensions in queries".

datecol means a column defined as DATE.


Defining columns and formats

Times and timestamps can be defined with any number of decimal places from 0 to 6 (time(0), timestamp(6), etc.). As it turns out, however, the Teradata hardware doesn't keep track of anything beyond 2 decimal places (hundredths of seconds), so it is useless to define columns with more than 2 decimal places. The formats for all columns are described in the SQL Reference, Volume 3, Chapter 8. For dates, various combinations of YYYY, MM, DD, and so on are recognized, because those elements can be arranged in different ways. For instance, you can ask for a format of 'YYYY-MM-DD' or 'MMMbDD,bYYYY'. Time and timestamp fields have default formats that cannot be changed, because the order of the elements is fixed: hours always appear first, then minutes, and so on. Here are some guidelines:


Date Type
Length after Formatting
(characters)
 time(0) 8
 time(2) 11
 timestamp(0) 19
 timestamp(2) 22


Dates

Number of days between two dates



datecol - datecol will return the number of days between two dates.

select date '2003-08-15' - date '2003-01-01';

(2003-08-15-2003-01-01)
-----------------------
                    226

Adding or subtracting months



Generally speaking, you should use the ADD_MONTHS function to add months to a date (or to subtract months). Your project may require adding a number of days, but if calendar months are required, ADD_MONTHS is the way to go.

select add_months(current_date, 3);

ADD_MONTHS(Date, 3)
-------------------
         2003-07-22

select add_months(current_date, -2);

ADD_MONTHS(Date, -2)
--------------------
          2003-02-22

/*** Last day of the month is still the last day ***/
select add_months(date '2002-01-31', 1);

ADD_MONTHS(2002-01-31, 1)
-------------------------
               2002-02-28

Computing the day of the week



Computing the day of the week for a given date is not easy in SQL. If you need a weekday, I recommend that you look it up in the view sys_calendar.calendar (or join to it), thus:

select day_of_week
   from sys_calendar.calendar
   where calendar_date = date '2003-05-01';

day_of_week
-----------
          5  [i.e. Thursday]

Computing the first day of a month



select datecol - extract(day from datecol) + 1

This subtracts the number of days since the beginning of the month, taking you to "day 0", or the day before the first of the month; then adds 1.


Computing the last day of a month



select add_months((datecol - extract(day from datecol)+1),1)-1

Same idea, but this computes the first day of the following month and then subtracts 1.


Special calendars



Your business may have special requirements, such as a retail calendar that is always a multiple of weeks. Such data must be stored in a table and joined to in your queries.


Times

Changing floats to times



Some Data Dictionary tables have time columns that are defined as FLOAT rather than TIME. Here's how to convert them to TIMEs, believe it or not:

select cast(cast(cast(TimeFld as format '99:99:99.99')
   as char(11)) as time(6))
   from DBC.EventLog ...

Time differences



First we shall address the case where your time data is defined as a number (FLOAT or DECIMAL, perhaps) in hhmmss form — e.g., 194328 for 7:43:28 p.m. If you have two such times and can be sure that they both fall within the same day, and you want to compute the difference between them in seconds, you will have to break them up into their parts like so:

select ((time02 / 10000) * 3600 +
   (time02 / 100 MOD 100) * 60 +
   (time02 MOD 100)) -
   ((time01 / 10000) * 3600 +
   (time01 / 100 MOD 100) * 60 +
   (time01 MOD 100)) as time_diff

   from dttest2;

    time_diff
-------------
        6432.  [in seconds -- about 1.8 hours]

If the earlier time could fall on one day and the later time on the next day, you may have to add 86,400 (the number of seconds in one day) to the later time, like so:

select case
   when time02 >= time01 then
      ((time02 / 10000) * 3600 +
      (time02 / 100 MOD 100) * 60 +
      (time02 MOD 100)) -
      ((time01 / 10000) * 3600 +
      (time01 / 100 MOD 100) * 60 +
      (time01 MOD 100))

   else           /*** Midnight has passed ***/
      (((time02 / 10000) * 3600 +
      (time02 / 100 MOD 100) * 60 +
      (time02 MOD 100)) + 86400) -
      ((time01 / 10000) * 3600 +
      (time01 / 100 MOD 100) * 60 +
      (time01 MOD 100))

   end  as time_diff

   from dttest2;

    time_diff
-------------
       18094.

Next we consider the case where your time data is defined as TIME(n). The usual way to take the difference of two times would be as follows:

select time02 - time01  hour(2) to second
   from dttest3;

(time02 - time01) HOUR TO SECOND
--------------------------------
                  5:02:40.000000

The above result has a data type of INTERVAL. If, however, you want to compute the difference in seconds, as above, you again have to split the times up:

select (extract(hour from time02) * 3600 +
   extract(minute from time02) * 60 +
   extract(second from time02)) -
   (extract(hour from time01) * 3600 +
   extract(minute from time01) * 60 +
   extract(second from time01)) as time_diff

   from dttest3;

  time_diff
-----------
      18160

/*** After midnight ... ***/
select case
   when time02 >= time01 then
      (extract(hour from time02) * 3600 +
      extract(minute from time02) * 60 +
      extract(second from time02)) -
      (extract(hour from time01) * 3600 +
      extract(minute from time01) * 60 +
      extract(second from time01))

   else
      (extract(hour from time02) * 3600 +
      extract(minute from time02) * 60 +
      extract(second from time02) + 86400) -
      (extract(hour from time01) * 3600 +
      extract(minute from time01) * 60 +
      extract(second from time01))

   end  as time_diff

   from dttest3;

  time_diff
-----------
      61360

Timestamps

Extracting the date or time portion of a timestamp



Extract the date or time portion of a timestamp thus:

select cast(ts01 as date) from dttest;

    ts01
--------
03/08/15

select cast(ts01 as time(0)) from dttest;

    ts01
--------
03:04:05

Length of time between two timestamps



You can subtract one timestamp from another. The result will be an interval, and you must specify a precision for the interval, like so:

select ts01 - ts04 day(4) to second(0)
   from dttest;

(ts01 - ts04) DAY TO SECOND
---------------------------
               226 02:02:02

select ts04 - ts01 day(4) to second(0)
   from dttest;

(ts04 - ts01) DAY TO SECOND
---------------------------
              -226 02:02:02

You can also convert this interval to seconds or minutes like so:

/*** Difference in seconds ***/
select (ts01 - ts04 day(4) to second) as tsdiff,
   (extract(day from tsdiff) * 86400)
   + (extract(hour from tsdiff) * 3600)
   + (extract(minute from tsdiff) * 60)
   + extract(second from tsdiff) as sec_diff

   from dttest;

            tsdiff         sec_diff
------------------   --------------
2 07:11:24.000000     198684.000000

/*** Difference in minutes ***/
select (ts01 - ts04 day(4) to minute) as tsdiff, (extract(day from tsdiff) * 1440) + (extract(hour from tsdiff) * 60) + extract(minute from tsdiff) as min_diff from dttest;

  tsdiff    min_diff
--------   ---------
 2 07:11        3311

Number of days between two timestamps



If you just want the number of days between two timestamps and wish to ignore the time portion, either of the following two techniques will work, but note the differences. The first technique lops off the time portion of each timestamp, so it will be equivalent to subtracting the two days; the result is an integer. The second will take the time portion into account and return an interval, so it will not count periods of time less than 24 hours. Thus, the result could be one less than with the first technique. If you use the second technique, be sure to allow enough digits for DAY.

sel cast(ts01 as date) - cast(ts04 as date)
   from dttest;

(ts01-ts04)
-----------
        226  -- type of this result is INTEGER

sel ts01 - ts04 day(4)
   from dttest;

(ts01 - ts04) DAY
-----------------
              226  -- type of this result is INTERVAL DAY

Other operations on timestamps




Operand 1

Operator

Operand 2
Result
Type
  Timestamp     + or -     Interval     Timestamp  
  Interval     +     Timestamp     Timestamp  
  Interval     + or -     Interval     Interval  
  Interval     * or /     Numeric     Interval  
  Numeric     *     Interval     Interval  

References

Teradata RDBMS SQL Reference, Volume 3: Data Types and Literals,
    B035-1101-061A (June 2001).

American National Standard for Information Technology — Database Languages — SQL-Part 2: Foundation,
    ANSI/ISO/IEC 9075-2:1999, esp. Subclause 4.7.






 
  Top Home Privacy Feedback  
 
Copyright for the TeradataForum (TDATA-L), Manta BlueSky
Copyright 2016 - All Rights Reserved
Last Modified: 28 Jun 2020