TIMESTAMP-to-DATE Conversion - Teradata Database

SQL Functions, Operators, Expressions, and Predicates

Product
Teradata Database
Release Number
15.00
Language
English (United States)
Last Update
2018-09-24
dita:id
B035-1145
lifecycle
previous
Product Category
Teradata® Database

TIMESTAMP-to-DATE Conversion

Purpose

Convert TIMESTAMP data to a DATE value.

CAST Syntax

where:

 

Syntax element …

Specifies …

timestamp_expression

the TIMESTAMP expression to be converted. timestamp_expression may include an AT clause.

AT LOCAL

that the time zone displacement based on the current session time zone is used.

This is the default.

AT SOURCE [TIME ZONE]

that the time zone associated with timestamp_expression is used in the following cases:

  • AT SOURCE TIME ZONE is specified.
  • AT SOURCE is specified without TIME ZONE and there is no column named source in the scope.
  • Otherwise, if AT SOURCE is specified without TIME ZONE and a column named source exists, then SOURCE references this column, and the value of the column is used as the time zone displacement for the CAST. If needed, the column value is implicitly converted to type INTERVAL HOUR(2) TO MINUTE. For details, see “AT LOCAL and AT TIME ZONE Time Zone Specifiers” on page 827. If there are multiple columns named source in the scope, an error is returned.

    AT [TIME ZONE] expression

    that the time zone displacement defined by expression is used. The data type of expression should be INTERVAL HOUR(2) TO MINUTE or it must be a data type that can be implicitly converted to INTERVAL HOUR(2) TO MINUTE. For details, see “AT LOCAL and AT TIME ZONE Time Zone Specifiers” on page 827.

    AT [TIME ZONE] time_zone_string

    that time_zone_string is used to determine the time zone displacement used for the CAST. For details, see “AT LOCAL and AT TIME ZONE Time Zone Specifiers” on page 827.

    date_data_attribute

    any of the following optional data attributes:

  • FORMAT
  • NAMED
  • TITLE
  • ANSI Compliance

    This is ANSI SQL:2011 compliant.

    As an extension to ANSI, CAST permits the use of DATE data attribute phrases, such as FORMAT that enables an alternative format.

    The AT clause is ANSI SQL:2011 compliant.

    As an extension to ANSI, the AT clause is supported when using CAST to convert from TIMESTAMP to DATE. In addition, you can specify the time zone displacement using additional expressions besides an INTERVAL expression.

    Note: TIMESTAMP (without time zone) is not ANSI SQL:2011 compliant. Teradata Database internally converts a TIMESTAMP value to UTC based on the current session time zone or on a specified time zone.

    Teradata Conversion Syntax

    where:

     

    Syntax element …

    Specifies …

    timestamp_expression

    the TIMESTAMP expression to be converted. timestamp_expression may include an AT clause.

    data_attribute

    any of the following optional data attributes:

  • FORMAT
  • NAMED
  • TITLE
  • AT LOCAL

    that the time zone displacement based on the current session time zone is used.

    This is the default.

    AT SOURCE [TIME ZONE]

    that the time zone associated with timestamp_expression is used in the following cases:

  • AT SOURCE TIME ZONE is specified.
  • AT SOURCE is specified without TIME ZONE and there is no column named source in the scope.
  • Otherwise, if AT SOURCE is specified without TIME ZONE and a column named source exists, then SOURCE references this column, and the value of the column is used as the time zone displacement in the conversion. If needed, the column value is implicitly converted to type INTERVAL HOUR(2) TO MINUTE. For details, see “AT LOCAL and AT TIME ZONE Time Zone Specifiers” on page 827. If there are multiple columns named source in the scope, an error is returned.

    AT [TIME ZONE] expression

    that the time zone displacement defined by expression is used. The data type of expression should be INTERVAL HOUR(2) TO MINUTE or it must be a data type that can be implicitly converted to INTERVAL HOUR(2) TO MINUTE. For details, see “AT LOCAL and AT TIME ZONE Time Zone Specifiers” on page 827.

    AT [TIME ZONE] time_zone_string

    that time_zone_string is used to determine the time zone displacement used in the conversion. For details, see “AT LOCAL and AT TIME ZONE Time Zone Specifiers” on page 827.

    ANSI Compliance

    This is a Teradata extension to the ANSI SQL:2011 standard.

    The AT clause is ANSI SQL:2011 compliant.

    As an extension to ANSI, the AT clause is supported when using Teradata Conversion Syntax to convert from TIMESTAMP to DATE. In addition, you can specify the time zone displacement using additional expressions besides an INTERVAL expression.

    Note: TIMESTAMP (without time zone) is not ANSI SQL:2011 compliant. Teradata Database internally converts a TIMESTAMP value to UTC based on the current session time zone or on a specified time zone.

    Usage Notes

    The following table shows the result of the CAST function or Teradata conversion based on the various options specified. Note that the time zone adjustment may change the YEAR, MONTH, and DAY fields of the DATE value.

     

    IF you specify...

    AND the data type of timestamp_expression is...

    THEN...

    AT LOCAL

    with or without TIME ZONE

    the result is the date portion of the source timestamp_expression after adjusting its UTC value by adding the time zone displacement based on the current session time zone.

    This is the same as not specifying the AT clause.

    AT SOURCE

    (where SOURCE is a keyword and not a column reference)

    WITH TIME ZONE

    the result is the date portion of the source timestamp_expression after adjusting its UTC value by adding the time zone displacement associated with timestamp_expression.

    AT SOURCE

    (where SOURCE is a keyword and not a column reference)

    without TIME ZONE

    an error is returned.

    AT SOURCE TIME ZONE

    WITH TIME ZONE

    the result is the date portion of the source timestamp_expression after adjusting its UTC value by adding the time zone displacement associated with timestamp_expression.

    AT SOURCE TIME ZONE

    without TIME ZONE

    an error is returned.

    AT expression
    or
    AT TIME ZONE expression

    with or without TIME ZONE

    the result is the date portion of the source timestamp_expression after adjusting its UTC value by adding the time zone displacement defined by expression.

    AT time_zone_string
    or
    AT TIME ZONE time_zone_string

    with or without TIME ZONE

    the result is the date portion of the source timestamp_expression after adjusting its UTC value by adding the time zone displacement based on time_zone_string. The time zone displacement is determined based on time_zone_string and the TIMESTAMP value of timestamp_expression at UTC.

    Implicit TIMESTAMP-to-DATE Conversion

    Teradata Database performs implicit conversion from TIMESTAMP types to DATE in some cases. See “Implicit Conversion of DateTime types” on page 586.

    The following conversions are supported:

     

    From source type...

    To target type...

    TIMESTAMP

    DATE1

     

    TIMESTAMP WITH TIME ZONE


    1
    ANSIDate dateform mode or IntegerDate dateform mode

    The TIMESTAMP value is always converted to DATE in case of comparison.

    Example  

    A single column table has three rows of type TIMESTAMP(0) WITH TIME ZONE.

    A query that requests the field values and CASTs them as DATE is performed during a session that has its Local Time Zone defined as -’08:00’.

    The results table is as follows.

       TimeStampWithTimeZone     CastAsDate
       -------------------------------------------------
       1997-10-07 15:43:00+08:00 1997-10-06
       1997-10-07 15:47:52-08:00 1997-10-07
       1997-10-07 15:43:00-00:00 1997-10-07

    Notice that the difference between the stored Time Zone and the Local Time Zone is 16 hours in the first row, but at the same time the TimeStamp value is 15:43, which is less than 16.

    This puzzling result can be clarified using a similar query that casts TIMESTAMP(0) WITH TIME ZONE as TIMESTAMP(0), omitting the Time Zone information.

    The results table for this query is as follows.

       TimeStampWithTimeZone     CastAsTimeStamp
       -------------------------------------------------
       1997-10-07 15:43:00+08:00 1997-10-06 23:43:00
       1997-10-07 15:47:52-08:00 1997-10-07 15:47:52
       1997-10-07 15:43:00-00:00 1997-10-07 07:43:00

    After the CAST, the values are all displayed at Local Time Zone, and the value in the first row indicates that the 16 hour adjustment rolled the date back 1, to a time near the end of that date.

    Example  

    Consider the following statements:

       SET TIME ZONE INTERVAL '01:00' HOUR TO MINUTE;
     
       SELECT CAST(TIMESTAMP '2008-05-31 22:30:00-08:00' 
          AS DATE AT SOURCE TIME ZONE);
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00' AT '-08:00' 
          (DATE, AT SOURCE);
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00' (DATE, AT -8);
       SELECT TIMESTAMP '2008-06-01 07:30:00' (DATE, AT -8);

    These SELECT statements return the date for time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE; that is, the statements return '08/05/31'. If the SELECT statements were specified without an AT clause or with an AT LOCAL clause, these statements would return '08/06/01' for the current session time zone displacement, INTERVAL '01:00' HOUR TO MINUTE.

    The following shows the results of the SELECT statements if the AT clause was not specified:

       SET TIME ZONE INTERVAL '01:00' HOUR TO MINUTE;
     
       SELECT CAST(TIMESTAMP '2008-05-31 22:30:00-08:00' AS DATE);
     
       2008-05-31 22:30:00-08:00
       -------------------------
                        08/06/01
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00'
          AT TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE;
     
       2008-06-01 06:30:00+00:00 AT TIME ZONE INTERVAL -8:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                  2008-05-31 22:30:00-08:00
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00'
          AT TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE (DATE);
     
       2008-06-01 06:30:00+00:00 AT TIME ZONE INTERVAL -8:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/06/01
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00' (DATE);
     
       2008-06-01 06:30:00+00:00
       -------------------------
                        08/06/01
     
       SELECT TIMESTAMP '2008-06-01 07:30:00' (DATE);
     
       2008-06-01 07:30:00
       -------------------
                  08/06/01

    The following shows the results of the SELECT statements if the AT clause was not specified, and the current session time zone displacement is INTERVAL -'08:00' HOUR TO MINUTE.

       SET TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE;
     
       SELECT CAST(TIMESTAMP '2008-05-31 22:30:00-08:00' AS DATE);
     
       2008-05-31 22:30:00-08:00
       -------------------------
                        08/05/31
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00'
          AT TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE (DATE);
     
       2008-06-01 06:30:00+00:00 AT TIME ZONE INTERVAL -8:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/05/31
     
       SELECT TIMESTAMP '2008-06-01 06:30:00+00:00' (DATE);
     
       2008-06-01 06:30:00+00:00
       -------------------------
                        08/05/31
     
       SELECT CAST(TIMESTAMP '2008-06-01 07:30:00+01:00' 
          AS TIMESTAMP(0)) (DATE);
     
       2008-06-01 07:30:00+01:00
       -------------------------
                        08/05/31

    Example  

    Consider the following statements:

       SET TIME ZONE INTERVAL '01:00' HOUR TO MINUTE;
     
       SELECT CAST(TIMESTAMP '2008-06-02 04:30:00+09:00' 
          AS DATE AT SOURCE TIME ZONE);
     
       SELECT TIMESTAMP '2008-06-01 20:30:00+01:00' 
          AT TIME ZONE INTERVAL '09' HOUR (DATE, AT SOURCE);
     
       SELECT TIMESTAMP '2008-06-01 20:30:00' (DATE, AT +9);

    These SELECT statements return the date for time zone displacement, INTERVAL '09:00' HOUR TO MINUTE; that is, the statements return '08/06/02'. If the SELECT statements were specified without an AT clause or with an AT LOCAL clause, these statements would return '08/06/01' for the current session time zone displacement, INTERVAL '01:00' HOUR TO MINUTE.

    The following shows the results of the SELECT statements if the AT clause was not specified:

       SET TIME ZONE INTERVAL '01:00' HOUR TO MINUTE;
     
       SELECT CAST(TIMESTAMP '2008-06-02 04:30:00+09:00' AS DATE);
     
       2008-06-02 04:30:00+09:00
       -------------------------
                        08/06/01
     
       SELECT TIMESTAMP '2008-06-01 20:30:00+01:00'
          AT TIME ZONE INTERVAL '09:00' HOUR TO MINUTE;
     
       2008-06-01 20:30:00+01:00 AT TIME ZONE INTERVAL  9:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                  2008-06-02 04:30:00+09:00
     
       SELECT TIMESTAMP '2008-06-01 20:30:00+01:00'
          AT TIME ZONE INTERVAL '09:00' HOUR TO MINUTE (DATE);
     
       2008-06-01 20:30:00+01:00 AT TIME ZONE INTERVAL  9:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/06/01
     
       SELECT TIMESTAMP '2008-06-01 20:30:00' (DATE);
     
       2008-06-01 20:30:00
       -------------------
                  08/06/01

    The following shows the results of the SELECT statements if the AT clause was not specified, and the current session time zone displacement is INTERVAL '09:00' TO MINUTE.

       SET TIME ZONE INTERVAL '09:00' HOUR TO MINUTE;
     
       SELECT CAST(TIMESTAMP '2008-06-02 04:30:00+09:00' AS DATE);
     
       2008-06-02 04:30:00+09:00
       -------------------------
                        08/06/02
     
       SELECT TIMESTAMP '2008-06-01 20:30:00+01:00'
          AT TIME ZONE INTERVAL '09:00' HOUR TO MINUTE (DATE);
     
       2008-06-01 20:30:00+01:00 AT TIME ZONE INTERVAL  9:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/06/02
     
       SELECT CAST(TIMESTAMP '2008-06-01 20:30:00+01:00' 
          AS TIMESTAMP(0)) (DATE);
     
       2008-06-01 20:30:00+01:00
       -------------------------
                        08/06/02

    Example  

    Consider the following statements:

       SET TIME ZONE INTERVAL '10:00' HOUR TO MINUTE;
     
       SELECT CAST((TIMESTAMP '2008-06-01 18:30:00+01:00' AT '05:45')
          AS DATE AT SOURCE);
     
       SELECT CAST((TIMESTAMP '2008-06-01 18:30:00+01:00' AT 5.75)
          AS DATE AT SOURCE);
     
       SELECT TIMESTAMP '2008-06-01 23:15:00+05:45' 
          (DATE, AT SOURCE TIME ZONE);
     
       SELECT TIMESTAMP '2008-06-02 03:30:00' (DATE, AT '05:45');
       SELECT TIMESTAMP '2008-06-02 03:30:00' (DATE, AT 5.75);

    These SELECT statements return the date for time zone displacement, INTERVAL '05:45' HOUR TO MINUTE; that is, the statements return '08/06/01'. If the SELECT statements were specified without an AT clause or with an AT LOCAL clause, these statements would return '08/06/02' for the current session time zone displacement, INTERVAL '10:00' HOUR TO MINUTE.

    The following shows the results of the SELECT statements if the AT clause was not specified:

       SET TIME ZONE INTERVAL '10:00' HOUR TO MINUTE;
     
       SELECT TIMESTAMP '2008-06-01 18:30:00+01:00'
          AT TIME ZONE INTERVAL '05:45' HOUR TO MINUTE;
     
       2008-06-01 18:30:00+01:00 AT TIME ZONE INTERVAL  5:45 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                  2008-06-01 23:15:00+05:45
     
       SELECT CAST((TIMESTAMP '2008-06-01 18:30:00+01:00'
          AT TIME ZONE INTERVAL '05:45' HOUR TO MINUTE) AS DATE);
     
       2008-06-01 18:30:00+01:00 AT TIME ZONE INTERVAL  5:45 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/06/02
     
       SELECT TIMESTAMP '2008-06-01 23:15:00+05:45' (DATE);
     
       2008-06-01 23:15:00+05:45
       -------------------------
                        08/06/02
     
       SELECT TIMESTAMP '2008-06-02 03:30:00' (DATE);
     
       2008-06-02 03:30:00
       -------------------
                  08/06/02

    The following shows the results of the SELECT statements if the AT clause was not specified, and the current session time zone displacement is INTERVAL '05:45' HOUR TO MINUTE.

       SET TIME ZONE INTERVAL '05:45' HOUR TO MINUTE;
     
       SELECT CAST((TIMESTAMP '2008-06-01 18:30:00+01:00'
          AT TIME ZONE INTERVAL'05:45' HOUR TO MINUTE) AS DATE);
     
       2008-06-01 18:30:00+01:00 AT TIME ZONE INTERVAL  5:45 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/06/01
     
       SELECT TIMESTAMP '2008-06-01 23:15:00+05:45' (DATE);
     
       2008-06-01 23:15:00+05:45
       -------------------------
                        08/06/01
     
       SELECT CAST(TIMESTAMP '2008-06-02 03:30:00+10:00'
          AS TIMESTAMP(0)) (DATE);
     
       2008-06-02 03:30:00+10:00
       -------------------------
                        08/06/01

    Example  

    Consider the following statements:

       SET TIME ZONE +1;
       SELECT CAST((TIMESTAMP '2008-06-01 08:30:00' AT TIME ZONE -8)
          AS DATE AT SOURCE TIME ZONE);

    This SELECT statement returns the date for time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE; that is, the statement returns '08/05/31'. If the SELECT statement was specified without an AT clause or with an AT LOCAL clause, the statement would return '08/06/01' for the current session time zone displacement, INTERVAL HOUR '01:00' MINUTE.

    The following shows the result of the SELECT statement if the AT clause was not specified:

       SET TIME ZONE INTERVAL '01:00' HOUR TO MINUTE;
     
       SELECT TIMESTAMP '2008-06-01 08:30:00'
          AT TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE;
     
       2008-06-01 08:30:00 AT TIME ZONE INTERVAL -8:00 HOUR TO MINUTE
       --------------------------------------------------------------
                                            2008-05-31 23:30:00-08:00
     
       SELECT CAST((TIMESTAMP '2008-06-01 08:30:00'
          AT TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE) AS DATE);
     
       2008-06-01 08:30:00 AT TIME ZONE INTERVAL -8:00 HOUR TO MINUTE
       --------------------------------------------------------------
                                                             08/06/01
     

    The following shows the result of the SELECT statement if the AT clause was not specified, and the current session time zone displacement is INTERVAL -'08:00' HOUR TO MINUTE.

       SET TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE;
     
       SELECT CAST((CAST(TIMESTAMP '2008-06-01 08:30:00+01:00' 
          AS TIMESTAMP(0)) AT TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE) 
          AS DATE);
     
       2008-06-01 08:30:00+01:00 AT TIME ZONE INTERVAL -8:00 HOUR TO MINUTE
       --------------------------------------------------------------------
                                                                   08/05/31

    Example  

    In this example, the current timestamp is:

                   Current TimeStamp(6)
       --------------------------------
       2010-03-09 19:23:27.620000+00:00

    The following statement converts the TIMESTAMP value '2010-03-09 22:30:00-08:00' to a DATE value, where the time zone displacement is based on the time zone string, 'America Pacific'.

       SELECT CAST(TIMESTAMP '2010-03-09 22:30:00-08:00' AS DATE 
          AT 'America Pacific');

    The result of the query is:

       2010-03-09 22:30:00-08:00
       -------------------------
                        10/03/09

    Example  

    The following SELECT statements return an error because the source expression does not have a TIMESTAMP WITH TIME ZONE data type.

       SELECT CAST(TIMESTAMP '2008-06-01 08:30:00' AS DATE AT SOURCE);
       SELECT CAST(TIME '08:30:00+03:00' AS DATE AT SOURCE TIME ZONE);
       SELECT CAST(TIME '08:30:00' AS DATE AT SOURCE);
       SELECT CAST(DATE '2008-06-01' AS DATE AT SOURCE TIME ZONE);

    Related Topics

    For details on data types and data attributes, see SQL Data Types and Literals.