TIMESTAMP-to-TIME Conversion
Purpose
Convert TIMESTAMP data to a TIME value.
CAST Syntax
where:
Syntax element … |
Specifies … |
timestamp_expression |
the TIMESTAMP expression to be converted. |
fractional_seconds_precision |
a single digit representing the number of significant digits in the fractional portion of the SECOND field. Values for fractional_seconds_precision range from 0 through 6 inclusive. The default precision is 6. |
AT LOCAL |
that the time zone displacement based on the current session time zone is used. |
AT SOURCE [TIME ZONE] |
that the time zone associated with timestamp_expression is used in the following cases: 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. |
time_data_attribute |
one of the following optional data attributes: |
ANSI Compliance
This is ANSI SQL:2011 compliant.
As an extension to ANSI, CAST permits the use of TIME data attribute phrases.
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 TIME. In addition, you can specify the time zone displacement using additional expressions besides an INTERVAL expression.
Note: TIME (without time zone) and TIMESTAMP (without time zone) are not ANSI SQL:2011 compliant. Teradata Database internally converts a TIME or 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. |
data_attribute |
one of the following optional data attributes: |
fractional_seconds_precision |
a single digit representing the number of significant digits in the fractional portion of the SECOND field. Values for fractional_seconds_precision range from 0 through 6 inclusive. The default precision is 6. |
AT LOCAL |
that the time zone displacement based on the current session time zone is used. |
AT SOURCE [TIME ZONE] |
that the time zone associated with timestamp_expression is used in the following cases: 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 TIME. In addition, you can specify the time zone displacement using additional expressions besides an INTERVAL expression.
Note: TIME (without time zone) and TIMESTAMP (without time zone) are not ANSI SQL:2011 compliant. Teradata Database internally converts a TIME or TIMESTAMP value to UTC based on the current session time zone or on a specified time zone.
Usage Notes
If you specify an AT clause for a TIME[(n)] without time zone target data type, an error is returned.
If you specify an AT clause for a TIME[(n)] WITH TIME ZONE target data type, the following table shows the result of the CAST function or Teradata conversion based on the various options specified. If the target precision is higher than the source precision, trailing zeros are added in the result to adjust the precision. If the target precision is lower than the source precision, an error is returned.
IF you specify... |
AND the data type of timestamp_expression is... |
THEN... |
AT LOCAL |
with or without TIME ZONE |
the result is formed from the source timestamp_expression (in UTC) and the time zone displacement based on the current session time zone. If the data type of timestamp_expression is without 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 formed from the time portion of the source timestamp_expression (in UTC) and the time zone displacement associated with timestamp_expression. Note that this is the same as not specifying the AT clause. |
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 formed from the time portion of the source timestamp_expression (in UTC) and the time zone displacement associated with timestamp_expression. Note that this is the same as not specifying the AT clause. |
AT SOURCE TIME ZONE |
without TIME ZONE |
an error is returned. |
AT expression |
with or without TIME ZONE |
the result is formed from the time portion of the source timestamp_expression (in UTC) and the time zone displacement defined by expression. |
AT time_zone_string |
with or without TIME ZONE |
the result is formed from the time portion of the source timestamp_expression (in UTC) and 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-TIME Conversion
Teradata Database performs implicit conversion from TIMESTAMP to TIME data types in some cases. However, implicit conversion from TIMESTAMP to TIME is not supported for comparisons. See “Implicit Conversion of DateTime types” on page 586.
The following conversions are supported:
From source type... |
To target type... |
TIMESTAMP |
TIME |
TIME WITH TIME ZONE |
|
TIMESTAMP WITH TIME ZONE
|
TIME |
TIME WITH TIME ZONE |
Example
In this example, the current session time zone displacement, INTERVAL '01:00' HOUR TO MINUTE, is used to determine the UTC value, '2008-06-01 07:30:00', of the TIMESTAMP literal.
The result of the CAST is the time formed from the time portion of the source expression value '2008-06-01 07:30:00' at UTC and the current time zone displacement, INTERVAL '01:00' HOUR TO MINUTE.
The result value of the CAST '07:30:00' at UTC is adjusted to its time zone displacement, INTERVAL '01:00' HOUR TO MINUTE, and the result of the SELECT statements is: TIME '08:30:00+01:00'.
The result of the SELECT statements is equal to TIME '07:30:00+00:00' since values are compared based on their UTC values.
SET TIME ZONE INTERVAL '01:00' HOUR TO MINUTE;
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00' AS TIME(0)
WITH TIME ZONE);
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00' AS TIME(0)
WITH TIME ZONE AT LOCAL);
Example
In this example, the time zone displacement specified in the literal, INTERVAL '04:00' HOUR TO MINUTE, is used to determine the UTC value '2008-06-01 04:30:00' for the TIMESTAMP literal.
The result of the CAST is the time formed from the time portion of the source expression value '2008-06-01 04:30:00' at UTC and the current session time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE.
The result value of the CAST '04:30:00' at UTC is adjusted to its time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE, and the result of the SELECT statement is: TIME '20:30:00-08:00'.
The result of the SELECT statement is equal to TIME '04:30:00+00:00'.
SET TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE;
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00+04:00'
AS TIME(0) WITH TIME ZONE AT LOCAL);
Example
The following SELECT statement return an error because the source expression does not have a time zone displacement.
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00'
AS TIME(0) WITH TIME ZONE AT SOURCE);
Example
In this example, the time zone displacement specified in the literal, INTERVAL '04:00' HOUR TO MINUTE, is used to determine the UTC value '2008-06-01 04:30:00' for the TIMESTAMP literal.
The result of the CAST is the time formed from the time portion of the source expression value '2008-06-01 04:30:00' at UTC, and the time zone displacement of the source expression, INTERVAL '04:00' HOUR TO MINUTE.
The result value of the CAST '04:30:00' at UTC is adjusted to its time zone displacement, INTERVAL '04:00' HOUR TO MINUTE, and the result of the SELECT statements is: TIME '08:30:00+04:00'.
The result of the SELECT statements is equal to TIME '04:30:00+00:00'. The current session time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE, has no effect.
SET TIME ZONE INTERVAL -'08:00' HOUR TO MINUTE;
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00+04:00'
AS TIME(0) WITH TIME ZONE);
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00+04:00'
AS TIME(0) WITH TIME ZONE AT SOURCE TIME ZONE);
Example
In this example, the current session time zone displacement, INTERVAL ‑'04:00' HOUR TO MINUTE, is used to determine the UTC value '2008-06-01 12:30:00' for the TIMESTAMP literal.
The result of the CAST is the time formed from the time portion of the source expression value '2008-06-01 12:30:00' at UTC, and the specified time zone displacement, INTERVAL ‑'08:00' HOUR TO MINUTE.
The result value of the CAST '12:30:00' at UTC is adjusted to its time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE, and the result of the SELECT statement is: TIME '04:30:00-08:00'.
The result of the SELECT statement is equal to TIME '12:30:00+00:00'.
SET TIME ZONE INTERVAL -'04:00' HOUR TO MINUTE;
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00'
AS TIME(0) WITH TIME ZONE AT -8);
Example
In this example, the time zone displacement specified in the literal, INTERVAL '04:00' HOUR TO MINUTE, is used to determine the UTC value '2008-06-01 04:30:00' for the TIMESTAMP literal.
The result of the CAST is the time formed from the time portion of the source expression value '2008-06-01 04:30:00' at UTC, and the specified time zone displacement, INTERVAL ‑'08:00' HOUR TO MINUTE.
The result value of the CAST '04:30:00' at UTC is adjusted to its time zone displacement, INTERVAL -'08:00' HOUR TO MINUTE, and the result of the SELECT statement is: TIME '20:30:00-08:00'.
This result of the SELECT statement is equal to TIME '04:30:00+00:00'. The current session time zone displacement, INTERVAL '08:00' HOUR TO MINUTE, has no effect.
SET TIME ZONE INTERVAL '08:00' HOUR TO MINUTE;
SELECT CAST(TIMESTAMP '2008-06-01 08:30:00+04:00'
AS TIME(0) WITH TIME ZONE AT -8);
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 08:30:00' to a TIME WITH TIME ZONE value, where the time zone displacement is based on the time zone string, 'America Pacific'.
SELECT CAST(TIMESTAMP '2010-03-09 08:30:00' AS TIME(0) WITH TIME ZONE
AT 'America Pacific');
The result of the query is:
2010-03-09 08:30:00
-------------------
00:30:00-08:00
Related Topics
For details on data types and data attributes, see SQL Data Types and Literals.