Interval data types - Amazon Redshift

Interval data types

You can use an interval data type to specify periods or ranges of time, such as 12 hours, 6 weeks, or 1 month. INTERVAL data types let you specify periods or ranges of time, such as 12 hours, 6 weeks, or 1 month. You can use interval data types in calculations, such as calculating differences between datestimes or intervals, sums of intervals, or sums of a datetime and an interval.

The following intervals are supported:

  • YEAR TO MONTH

  • DAY TO SECOND

Syntax

To create an interval of type YEAR TO MONTH:

INTERVAL <year_to_month_qualifier>

To create an interval literal of type YEAR TO MONTH:

INTERVAL <interval-string> <qualifier>

Use the following syntax to create an interval of type DAY TO SECOND. The fractional_precision parameter is only necessary if your interval contains SECOND.

INTERVAL <qualifier> [ <fractional_precision> ]

Use the following syntax to create an interval literal of type DAY TO SECOND.

INTERVAL <interval-string> <qualifier> [ <fractional_precision> ]

Arguments

Interval-string

Specifies the value of the interval. Only required if creating an interval constant

Qualifier

Specifies the range of the interval. If you use a qualifier and create an interval with time units smaller than the qualifier, Amazon Redshift truncates and discards the smaller parts of the interval. The following example demonstrates using a MINUTE qualifier, and Amazon Redshift discards the time units smaller than MINUTE.

INTERVAL '1 day 1 hour 1 minute 1.123 seconds' MINUTE

gets truncated to

'1 day 01:01:00'
Fractional_precision

Optional parameter that specifies the number of fractional digits allowed in the interval. For example, SECOND (3) creates an interval that allows only three fractional digits, such as 1.234 seconds. Applicable only to DAY TO SECOND intervals that contain seconds. The maximum number of digits supported is six.

The YEAR TO MONTH data type supports the following qualifiers:

  • YEAR

  • MONTH

  • YEAR TO MONTH

The DAY TO SECOND data type supports the following qualifiers:

  • DAY

  • HOUR

  • MINUTE

  • SECOND

  • DAY TO HOUR

  • DAY TO MINUTE

  • DAY TO SECOND

  • HOUR TO MINUTE

  • HOUR TO SECOND

  • MINUTE TO SECOND

Examples

The following example demonstrates how to create an INTERVAL constant of 1 year.

INTERVAL '1' YEAR

If you specify an interval string that exceeds the qualifier, remaining units of time are truncated from the interval. In the following example, an interval of 13 months becomes 1 year and 1 month, but the remaining 1 month is left out because of the YEAR qualifier.

INTERVAL '13 months' YEAR '1 year'

If you use a qualifier lower than your interval string, leftover units are included.

INTERVAL '13 months' MONTH '1 year 1 month'

Specifying a precision in your interval truncates the number of fractional digits to the specified precision.

INTERVAL '1.234567' SECOND (3) '00:00:01.234'

If you don't specify a precision, Amazon Redshift uses the maximum precision of 6.

INTERVAL '1.23456789' SECOND '00:00:01.234567'

The following example demonstrates how to create a ranged interval.

INTERVAL '2:2' MINUTE TO SECOND '00:02:02'

Qualifiers dictate the units that you're specifying. For example, even though the following example uses the same interval string of '2:2' as the previous example, Amazon Redshift recognizes it uses different units of time because of the qualifier

INTERVAL '2:2' HOUR TO MINUTE '02:02:00'

Abbreviations and plurals of each unit are also supported; for example: 5s, 5 second, and 5 seconds are equivalent intervals. Supported units are years, months, hours, minutes, and seconds.

INTERVAL '5s' SECOND '00:00:05' INTERVAL '5 second' SECOND '00:00:05' INTERVAL '5 HOURS' HOUR '05:00:00' INTERVAL '5 h' HOUR '05:00:00

The following examples demonstrate how to use INTERVAL data types with tables

create table sample_intervals (y2m interval month, m2s interval hour to minute); insert into sample_intervals values (interval '20' month, interval '2 days 1:1:1.123456' day to second); select y2m::text, m2s::text from sample_intervals; y2m | m2s ---------------+----------------- 1 year 8 mons | 2 days 01:01:00
update sample_intervals set y2m = interval '2' year where y2m = interval '1-8' year to month; select * from sample_intervals; y2m | m2s ---------+----------------- 2 years | 2 days 01:01:00
delete from sample_intervals where m2s = interval '2 1:1:0' day to second; select * from sample_intervals; y2m | m2s -----+-----

Interval arithmetic

You can use interval values with other datetime objects to perform arithmetic operations. The table below describes the available operations and what results you would get from each operation.

Date Timestamp Interval Numeric
Interval - N/A N/A Interval N/A
+ Date Date/Timestamp Interval N/A
* N/A N/A N/A Interval
/ N/A N/A N/A Interval
Date - Numeric Interval Date/Timestamp Date
+ N/A N/A N/A N/A
Timestamp - Interval Interval Timestamp Timestamp
+ N/A N/A N/A N/A

Interval styles

You can use the SET command to change the output format of your interval strings. Available options are: postgres, sql_standard, and postgres_verbose. The default is postgres. Examples of each output format are below.

sql_standard output format

Interval year to month values are formatted as the following. Specifying negative before the interval indicates the interval is a negative value and applies to the entire interval.

'[-]yy-mm'

Interval day to second values are formatted as the following.

'[-]dd hh:mm:ss.ffffff'
INTERVAL '1-2' YEAR TO MONTH outputs as '1-2' INTERVAL '1 2:3:4.5678' DAY TO SECOND outputs as '1 2:03:04.5678'

postgres output format

The following is the output format for postgres. Each numeric value can be negative.

[@] '<numeric> <unit> [, <numeric> <unit> ...]'
INTERVAL '1-2' YEAR TO MONTH outputs as '1 year 2 mons' INTERVAL '1 2:3:4.5678' DAY TO SECOND outputs as '1 day 02:03:04.5678'

postgres_verbose output format

postgres_verbose syntax is similar to postgres, but postgres_verbose outputs also contain the unit of time.

'[@] <numeric> <unit> [, <numeric> <unit> ...] [direction]'
INTERVAL '1-2' YEAR TO MONTH outputs as '@ 1 year 2 mons' INTERVAL '1 2:3:4.5678' DAY TO SECOND outputs as '@ 1 day 2 hours 3 mins 4.5678 secs'

The following command demonstrates how to set set the interval style to sql_standard.

SET intervalstyle to 'sql_standard';

Limitations

This prerelease INTERVAL feature has the following limitations:

  • If you're using the JDBC driver, you can't use the year to month and day to second intervals as parameters to PREPARE statements.

  • The JDBC driver interprets all interval values as strings, so you can only get the returned intervals from a SELECT query by using the getString method.

  • Stored Procedures do not accept interval values as function parameters.

  • You can't perform cast a numeric to an interval.