This is the multi-page printable view of this section. Click here to print.

Return to the regular view of this page.

Date/time functions

Date and time functions perform conversion, extraction, or manipulation operations on date and time data types and can return date and time information.

Date and time functions perform conversion, extraction, or manipulation operations on date and time data types and can return date and time information.

Usage

Functions that take TIME or TIMESTAMP inputs come in two variants:

  • TIME WITH TIME ZONE or TIMESTAMP WITH TIME ZONE

  • TIME WITHOUT TIME ZONE or TIMESTAMP WITHOUT TIME ZONE

For brevity, these variants are not shown separately.

The + and * operators come in commutative pairs; for example, both DATE + INTEGER and INTEGER + DATE. We show only one of each such pair.

Daylight savings time considerations

When adding an INTERVAL value to (or subtracting an INTERVAL value from) a TIMESTAMP WITH TIME ZONE value, the days component advances (or decrements) the date of the TIMESTAMP WITH TIME ZONE by the indicated number of days. Across daylight saving time changes (with the session time zone set to a time zone that recognizes DST), this means INTERVAL '1 day' does not necessarily equal INTERVAL '24 hours'.

For example, with the session time zone set to CST7CDT:

TIMESTAMP WITH TIME ZONE '2014-04-02 12:00-07' + INTERVAL '1 day'

produces

TIMESTAMP WITH TIME ZONE '2014-04-03 12:00-06'

Adding INTERVAL '24 hours' to the same initial TIMESTAMP WITH TIME ZONE produces

TIMESTAMP WITH TIME ZONE '2014-04-03 13:00-06',

This result occurs because there is a change in daylight saving time at 2014-04-03 02:00 in time zone CST7CDT.

Date/time functions in transactions

Certain date/time functions such as CURRENT_TIMESTAMP and NOW return the start time of the current transaction; for the duration of that transaction, they return the same value. Other date/time functions such as TIMEOFDAY always return the current time.

See also

Template patterns for date/time formatting

1 - ADD_MONTHS

Adds the specified number of months to a date and returns the sum as a DATE.

Adds the specified number of months to a date and returns the sum as a DATE. In general, ADD_MONTHS returns a date with the same day component as the start date. For example:

=> SELECT ADD_MONTHS ('2015-09-15'::date, -2) "2 Months Ago";
 2 Months Ago
--------------
 2015-07-15
(1 row)

Two exceptions apply:

  • If the start date's day component is greater than the last day of the result month, ADD_MONTHS returns the last day of the result month. For example:

    => SELECT ADD_MONTHS ('31-Jan-2016'::TIMESTAMP, 1) "Leap Month";
     Leap Month
    ------------
     2016-02-29
    (1 row)
    
  • If the start date's day component is the last day of that month, and the result month has more days than the start date month, ADD_MONTHS returns the last day of the result month. For example:

    => SELECT ADD_MONTHS ('2015-09-30'::date,-1) "1 Month Ago";
     1 Month Ago
    -------------
     2015-08-31
    (1 row)
    

Behavior type

  • Immutable if the start-date argument is a TIMESTAMP or DATE

  • Stable if the start-date argument is a TIMESTAMPTZ

Syntax

ADD_MONTHS ( start-date, num-months );

Parameters

start-date
The date to process, an expression that evaluates to one of the following data types:
  • DATE

  • TIMESTAMP

  • TIMESTAMPTZ

num-months
An integer expression that specifies the number of months to add to or subtract from start-date.

Examples

Add one month to the current date:

=> SELECT CURRENT_DATE Today;
   Today
------------
 2016-05-05
(1 row)

VMart=> SELECT ADD_MONTHS(CURRENT_TIMESTAMP,1);
 ADD_MONTHS
------------
 2016-06-05
(1 row)

Subtract four months from the current date:

=> SELECT ADD_MONTHS(CURRENT_TIMESTAMP, -4);
 ADD_MONTHS
------------
 2016-01-05
(1 row)

Add one month to January 31 2016:

=> SELECT ADD_MONTHS('31-Jan-2016'::TIMESTAMP, 1) "Leap Month";
 Leap Month
------------
 2016-02-29
(1 row)

The following example sets the timezone to EST; it then adds 24 months to a TIMESTAMPTZ that specifies a PST time zone, so ADD_MONTHS takes into account the time change:

=> SET TIME ZONE 'America/New_York';
SET
VMart=> SELECT ADD_MONTHS('2008-02-29 23:30 PST'::TIMESTAMPTZ, 24);
 ADD_MONTHS
------------
 2010-03-01
(1 row)

2 - AGE_IN_MONTHS

Returns the difference in months between two dates, expressed as an integer.

Returns the difference in months between two dates, expressed as an integer.

Behavior type

  • Immutable if both date arguments are of data type TIMESTAMP

  • Stable if either date is a TIMESTAMPTZ or only one argument is supplied

Syntax

AGE_IN_MONTHS ( [ date1,] date2 )

Parameters

date1
date2
Specify the boundaries of the period to measure. If you supply only one argument, Vertica sets date2 to the current date. Both parameters must evaluate to one of the following data types:
  • DATE

  • TIMESTAMP

  • TIMESTAMPTZ

If date1 < date2, AGE_IN_MONTHS returns a negative value.

Examples

Get the age in months of someone born March 2 1972, as of June 21 1990:

=> SELECT AGE_IN_MONTHS('1990-06-21'::TIMESTAMP, '1972-03-02'::TIMESTAMP);
  AGE_IN_MONTHS
---------------
           219
(1 row)

If the first date is less than the second date, AGE_IN_MONTHS returns a negative value

=> SELECT AGE_IN_MONTHS('1972-03-02'::TIMESTAMP, '1990-06-21'::TIMESTAMP);
AGE_IN_MONTHS
---------------
-220
(1 row)

Get the age in months of someone who was born November 21 1939, as of today:

=> SELECT AGE_IN_MONTHS ('1939-11-21'::DATE);
 AGE_IN_MONTHS
---------------
           930
(1 row)

3 - AGE_IN_YEARS

Returns the difference in years between two dates, expressed as an integer.

Returns the difference in years between two dates, expressed as an integer.

Behavior type

  • Immutable if both date arguments are of data type TIMESTAMP

  • Stable if either date is a TIMESTAMPTZ or only one argument is supplied

Syntax

AGE_IN_YEARS( [ date1,] date2 )

Parameters

date1
date2
Specify the boundaries of the period to measure. If you supply only one argument, Vertica sets date1 to the current date. Both parameters must evaluate to one of the following data types:
  • DATE

  • TIMESTAMP

  • TIMESTAMPTZ

If date1 < date2, AGE_IN_YEARS returns a negative value.

Examples

Get the age of someone born March 2 1972, as of June 21 1990:

=> SELECT AGE_IN_YEARS('1990-06-21'::TIMESTAMP, '1972-03-02'::TIMESTAMP);
 AGE_IN_YEARS
--------------
           18
(1 row)

If the first date is earlier than the second date, AGE_IN_YEARS returns a negative number:

=> SELECT AGE_IN_YEARS('1972-03-02'::TIMESTAMP, '1990-06-21'::TIMESTAMP);
AGE_IN_YEARS
--------------
          -19
(1 row)

Get the age of someone who was born November 21 1939, as of today:

=> SELECT AGE_IN_YEARS('1939-11-21'::DATE);
 AGE_IN_YEARS
--------------
           77
(1 row)

4 - CLOCK_TIMESTAMP

Returns a value of type TIMESTAMP WITH TIMEZONE that represents the current system-clock time.

Returns a value of type TIMESTAMP WITH TIMEZONE that represents the current system-clock time.

CLOCK_TIMESTAMP uses the date and time supplied by the operating system on the server to which you are connected, which should be the same across all servers. The value changes each time you call it.

Behavior type

Volatile

Syntax

CLOCK_TIMESTAMP()

Examples

The following command returns the current time on your system:

SELECT CLOCK_TIMESTAMP() "Current Time";
         Current Time
------------------------------
 2010-09-23 11:41:23.33772-04
(1 row)

Each time you call the function, you get a different result. The difference in this example is in microseconds:

SELECT CLOCK_TIMESTAMP() "Time 1", CLOCK_TIMESTAMP() "Time 2";
            Time 1             |            Time 2
-------------------------------+-------------------------------
 2010-09-23 11:41:55.369201-04 | 2010-09-23 11:41:55.369202-04
(1 row)

See also

5 - CURRENT_DATE

Returns the date (date-type value) on which the current transaction started.

Returns the date (date-type value) on which the current transaction started.

Behavior type

Stable

Syntax

CURRENT_DATE()

Examples

SELECT CURRENT_DATE;
  ?column?
------------
 2010-09-23
(1 row)

6 - CURRENT_TIME

Returns a value of type TIME WITH TIMEZONE that represents the start of the current transaction.

Returns a value of type TIME WITH TIMEZONE that represents the start of the current transaction.

The return value does not change during the transaction. Thus, multiple calls to CURRENT_TIME within the same transaction return the same timestamp.

Behavior type

Stable

Syntax

CURRENT_TIME  [ ( precision ) ]

Parameters

precision
An integer value between 0-6, specifies to round the seconds fraction field result to the specified number of digits.

Examples


=> SELECT CURRENT_TIME(1) AS Time;
     Time
---------------
 06:51:45.2-07
(1 row)
=> SELECT CURRENT_TIME(5) AS Time;
       Time
-------------------
 06:51:45.18435-07
(1 row)

7 - CURRENT_TIMESTAMP

Returns a value of type TIME WITH TIMEZONE that represents the start of the current transaction.

Returns a value of type TIME WITH TIMEZONE that represents the start of the current transaction.

The return value does not change during the transaction. Thus, multiple calls to CURRENT_TIMESTAMP within the same transaction return the same timestamp.

Behavior type

Stable

Syntax

CURRENT_TIMESTAMP ( precision )

Parameters

precision
An integer value between 0-6, specifies to round the seconds fraction field result to the specified number of digits.

Examples


=> SELECT CURRENT_TIMESTAMP(1) AS time;
           time
--------------------------
 2017-03-27 06:50:49.7-07
(1 row)
=> SELECT CURRENT_TIMESTAMP(5) AS time;
             time
------------------------------
 2017-03-27 06:50:49.69967-07
(1 row)

8 - DATE

Converts the input value to a DATE data type.

Converts the input value to a DATE data type.

Behavior type

  • Immutable if the input value is a TIMESTAMP, DATE, VARCHAR, or integer

  • Stable if the input value is a TIMESTAMPTZ

Syntax

DATE ( value )

Parameters

value
The value to convert, one of the following:
  • TIMESTAMP, TIMESTAMPTZ, VARCHAR, or another DATE.

  • Integer: Vertica treats the integer as the number of days since 01/01/0001 and returns the date.

Examples

=> SELECT DATE (1);
    DATE
------------
 0001-01-01
(1 row)

=> SELECT DATE (734260);
    DATE
------------
 2011-05-03
(1 row)

=> SELECT DATE('TODAY');
    DATE
------------
 2016-12-07
(1 row)

See also

9 - DATE_PART

Extracts a sub-field such as year or hour from a date/time expression, equivalent to the the SQL-standard function EXTRACT.

Extracts a sub-field such as year or hour from a date/time expression, equivalent to the the SQL-standard function EXTRACT.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or INTERVAL

  • Stable if the specified date is a TIMESTAMPTZ

Syntax

DATE_PART ( 'field', date )

Parameters

field
A constant value that specifies the sub-field to extract from date (see Field Values below).
date
The date to process, an expression that evaluates to one of the following data types:

Field values

CENTURY
The century number.

The first century starts at 0001-01-01 00:00:00 AD. This definition applies to all Gregorian calendar countries. There is no century number 0, you go from –1 to 1.

DAY
The day (of the month) field (1–31).
DECADE
The year field divided by 10.
DOQ
The day within the current quarter. DOQ recognizes leap year days.
DOW
Zero-based day of the week, where Sunday=0.
DOY
The day of the year (1–365/366)
EPOCH
Specifies to return one of the following:
  • For DATE and TIMESTAMP values: the number of seconds before or since 1970-01-01 00:00:00-00 (if before, a negative number).

  • For INTERVAL values, the total number of seconds in the interval.

HOUR
The hour field (0–23).
ISODOW
The ISO day of the week, an integer between 1 and 7 where Monday is 1.
ISOWEEK
The ISO week of the year, an integer between 1 and 53.
ISOYEAR
The ISO year.
MICROSECONDS
The seconds field, including fractional parts, multiplied by 1,000,000. This includes full seconds.
MILLENNIUM
The millennium number, where the first millennium is 1 and each millenium starts on 01-01-y001. For example, millennium 2 starts on 01-01-1001.
MILLISECONDS
The seconds field, including fractional parts, multiplied by 1000. This includes full seconds.
MINUTE
The minutes field (0 - 59).
MONTH
For TIMESTAMP values, the number of the month within the year (1 - 12) ; for interval values the number of months, modulo 12 (0 - 11).
QUARTER
The calendar quarter of the specified date as an integer, where the January-March quarter is 1, valid only for TIMESTAMP values.
SECOND
The seconds field, including fractional parts, 0–59, or 0-60 if the operating system implements leap seconds.
TIME ZONE
The time zone offset from UTC, in seconds. Positive values correspond to time zones east of UTC, negative values to zones west of UTC.
TIMEZONE_HOUR
The hour component of the time zone offset.
TIMEZONE_MINUTE
The minute component of the time zone offset.
WEEK
The number of the week of the calendar year that the day is in.
YEAR
The year field. There is no 0 AD, so subtract BC years from AD years accordingly.

Notes

According to the ISO-8601 standard, the week starts on Monday, and the first week of a year contains January 4. Thus, an early January date can sometimes be in the week 52 or 53 of the previous calendar year. For example:

=> SELECT YEAR_ISO('01-01-2016'::DATE), WEEK_ISO('01-01-2016'), DAYOFWEEK_ISO('01-01-2016');
 YEAR_ISO | WEEK_ISO | DAYOFWEEK_ISO
----------+----------+---------------
     2015 |       53 |             5
(1 row)

Examples

Extract the day value:

SELECT DATE_PART('DAY', TIMESTAMP '2009-02-24 20:38:40') "Day";
  Day
-----
  24
(1 row)

Extract the month value:

SELECT DATE_PART('MONTH', '2009-02-24 20:38:40'::TIMESTAMP) "Month";
  Month
-------
     2
(1 row)

Extract the year value:

SELECT DATE_PART('YEAR', '2009-02-24 20:38:40'::TIMESTAMP) "Year";
  Year
------
 2009
(1 row)

Extract the hours:

SELECT DATE_PART('HOUR', '2009-02-24 20:38:40'::TIMESTAMP) "Hour";
  Hour
------
   20
(1 row)

Extract the minutes:

SELECT DATE_PART('MINUTES', '2009-02-24 20:38:40'::TIMESTAMP) "Minutes";
  Minutes
---------
      38
(1 row)

Extract the day of quarter (DOQ):

SELECT DATE_PART('DOQ', '2009-02-24 20:38:40'::TIMESTAMP) "DOQ";
 DOQ
-----
  55
(1 row)

See also

TO_CHAR

10 - DATE_TRUNC

Truncates date and time values to the specified precision.

Truncates date and time values to the specified precision. The return value is the same data type as the input value. All fields that are less than the specified precision are set to 0, or to 1 for day and month.

Behavior type

Stable

Syntax

DATE_TRUNC( precision, trunc-target )

Parameters

precision
A string constant that specifies precision for the truncated value. See Precision Field Values below. The precision must be valid for the trunc-target date or time.
trunc-target
Valid date/time expression.

Precision field values

MILLENNIUM
The millennium number.
CENTURY
The century number.

The first century starts at 0001-01-01 00:00:00 AD. This definition applies to all Gregorian calendar countries.

DECADE
The year field divided by 10.
YEAR
The year field. Keep in mind there is no 0 AD, so subtract BC years from AD years with care.
QUARTER
The calendar quarter of the specified date as an integer, where the January-March quarter is 1.
MONTH
For timestamp values, the number of the month within the year (1–12) ; for interval values the number of months, modulo 12 (0–11).
WEEK
The number of the week of the year that the day is in.

According to the ISO-8601 standard, the week starts on Monday, and the first week of a year contains January 4. Thus, an early January date can sometimes be in the week 52 or 53 of the previous calendar year. For example:

=> SELECT YEAR_ISO('01-01-2016'::DATE), WEEK_ISO('01-01-2016'), DAYOFWEEK_ISO('01-01-2016');
 YEAR_ISO | WEEK_ISO | DAYOFWEEK_ISO
----------+----------+---------------
     2015 |       53 |             5
(1 row)
DAY
The day (of the month) field (1–31).
HOUR
The hour field (0–23).
MINUTE
The minutes field (0–59).
SECOND
The seconds field, including fractional parts (0–59) (60 if leap seconds are implemented by the operating system).
MILLISECONDS
The seconds field, including fractional parts, multiplied by 1000. Note that this includes full seconds.
MICROSECONDS
The seconds field, including fractional parts, multiplied by 1,000,000. This includes full seconds.

Examples

The following example sets the field value as hour and returns the hour, truncating the minutes and seconds:

=> SELECT DATE_TRUNC('HOUR', TIMESTAMP '2012-02-24 13:38:40') AS HOUR;
        HOUR
---------------------
 2012-02-24 13:00:00
(1 row)

The following example returns the year from the input timestamptz '2012-02-24 13:38:40'. The function also defaults the month and day to January 1, truncates the hour:minute:second of the timestamp, and appends the time zone (-05):

=> SELECT DATE_TRUNC('YEAR', TIMESTAMPTZ '2012-02-24 13:38:40') AS YEAR;
          YEAR
------------------------
 2012-01-01 00:00:00-05
(1 row)

The following example returns the year and month and defaults day of month to 1, truncating the rest of the string:

=> SELECT DATE_TRUNC('MONTH', TIMESTAMP '2012-02-24 13:38:40') AS MONTH;
        MONTH
---------------------
 2012-02-01 00:00:00
(1 row)

11 - DATEDIFF

Returns the time span between two dates, in the intervals specified.

Returns the time span between two dates, in the intervals specified. DATEDIFF excludes the start date in its calculation.

Behavior type

  • Immutable if start and end dates are TIMESTAMP , DATE, TIME, or INTERVAL

  • Stable if start and end dates are TIMESTAMPTZ

Syntax

DATEDIFF ( datepart, start, end );

Parameters

datepart
Specifies the type of date or time intervals that DATEDIFF returns. If datepart is an expression, it must be enclosed in parentheses:
DATEDIFF((expression), start, end);

datepart must evaluate to one of the following string literals, either quoted or unquoted:

  • year | yy | yyyy

  • quarter | qq | q

  • month | mm | m

  • day | dayofyear | dd | d | dy | y

  • week | wk | ww

  • hour | hh

  • minute | mi | n

  • second | ss | s

  • millisecond | ms

  • microsecond | mcs | us

start, end
Specify the start and end dates, where start and end evaluate to one of the following data types:

If end < start, DATEDIFF returns a negative value.

Compatible start and end date data types

The following table shows which data types can be matched as start and end dates:

DATE TIMESTAMP TIMESTAMPTZ TIME INTERVAL
DATE
TIMESTAMP
TIMESTAMPTZ
TIME
INTERVAL

For example, if you set the start date to an INTERVAL data type, the end date must also be an INTERVAL, otherwise Vertica returns an error:

 SELECT DATEDIFF(day, INTERVAL '26 days', INTERVAL '1 month ');
 datediff
----------
        4
(1 row)

Date part intervals

DATEDIFF uses the datepart argument to calculate the number of intervals between two dates, rather than the actual amount of time between them. DATEDIFF uses the following cutoff points to calculate those intervals:

  • year: January 1

  • quarter: January 1, April 1, July 1, October 1

  • month: the first day of the month

  • week: Sunday at midnight (24:00)

For example, if datepart is set to year, DATEDIFF uses January 01 to calculate the number of years between two dates. The following DATEDIFF statement sets datepart to year, and specifies a time span 01/01/2005 - 06/15/2008:

SELECT DATEDIFF(year, '01-01-2005'::date, '12-31-2008'::date);
 datediff
----------
        3
(1 row)

DATEDIFF always excludes the start date when it calculates intervals—in this case, 01/01//2005. DATEDIFF considers only calendar year starts in its calculation, so in this case it only counts years 2006, 2007, and 2008. The function returns 3, although the actual time span is nearly four years.

If you change the start and end dates to 12/31/2004 and 01/01/2009, respectively, DATEDIFF also counts years 2005 and 2009. This time, it returns 5, although the actual time span is just over four years:

=> SELECT DATEDIFF(year, '12-31-2004'::date, '01-01-2009'::date);
 datediff
----------
        5
(1 row)

Similarly, DATEDIFF uses month start dates when it calculates the number of months between two dates. Thus, given the following statement, DATEDIFF counts months February through September and returns 8:

=> SELECT DATEDIFF(month, '01-31-2005'::date, '09-30-2005'::date);
 datediff
----------
        8
(1 row)

See also

TIMESTAMPDIFF

12 - DAY

Returns as an integer the day of the month from the input value.

Returns as an integer the day of the month from the input value.

Behavior type

  • Immutable if the input value is a TIMESTAMP, DATE, VARCHAR, or INTEGER

  • Stable if the specified date is a TIMESTAMPTZ

Syntax

DAY ( value )

Parameters

value
The value to convert, one of the following: TIMESTAMP, TIMESTAMPTZ, INTERVAL, VARCHAR, or INTEGER.

Examples

=> SELECT DAY (6);
 DAY
-----
   6
(1 row)

=> SELECT DAY(TIMESTAMP 'sep 22, 2011 12:34');
 DAY
-----
  22
(1 row)

=> SELECT DAY('sep 22, 2011 12:34');
 DAY
-----
  22
(1 row)

=> SELECT DAY(INTERVAL '35 12:34');
 DAY
-----
  35
(1 row)

13 - DAYOFMONTH

Returns the day of the month as an integer.

Returns the day of the month as an integer.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the target date is aTIMESTAMPTZ

Syntax

DAYOFMONTH ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT DAYOFMONTH (TIMESTAMP 'sep 22, 2011 12:34');
 DAYOFMONTH
------------
         22
(1 row)

14 - DAYOFWEEK

Returns the day of the week as an integer, where Sunday is day 1.

Returns the day of the week as an integer, where Sunday is day 1.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the target date is aTIMESTAMPTZ

Syntax

DAYOFWEEK ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT DAYOFWEEK (TIMESTAMP 'sep 17, 2011 12:34');
 DAYOFWEEK
-----------
         7
(1 row)

15 - DAYOFWEEK_ISO

Returns the ISO 8061 day of the week as an integer, where Monday is day 1.

Returns the ISO 8061 day of the week as an integer, where Monday is day 1.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the target date is aTIMESTAMPTZ

Syntax

DAYOFWEEK_ISO ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT DAYOFWEEK_ISO(TIMESTAMP 'Sep 22, 2011 12:34');
 DAYOFWEEK_ISO
---------------
             4
(1 row)

The following example shows how to combine the DAYOFWEEK_ISO, WEEK_ISO, and YEAR_ISO functions to find the ISO day of the week, week, and year:

=> SELECT DAYOFWEEK_ISO('Jan 1, 2000'), WEEK_ISO('Jan 1, 2000'),YEAR_ISO('Jan1,2000');
 DAYOFWEEK_ISO | WEEK_ISO | YEAR_ISO
---------------+----------+----------
             6 |       52 |     1999
(1 row)

See also

16 - DAYOFYEAR

Returns the day of the year as an integer, where January 1 is day 1.

Returns the day of the year as an integer, where January 1 is day 1.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

DAYOFYEAR ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT DAYOFYEAR (TIMESTAMP 'SEPT 22,2011 12:34');
 DAYOFYEAR
-----------
       265
(1 row)

17 - DAYS

Returns the integer value of the specified date, where 1 AD is 1.

Returns the integer value of the specified date, where 1 AD is 1. If the date precedes 1 AD, DAYS returns a negative integer.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

DAYS ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT DAYS (DATE '2011-01-22');
  DAYS
--------
 734159
(1 row)

=> SELECT DAYS (DATE 'March 15, 0044 BC');
  DAYS
--------
 -15997
(1 row)

18 - EXTRACT

Retrieves sub-fields such as year or hour from date/time values and returns values of type NUMERIC.

Retrieves sub-fields such as year or hour from date/time values and returns values of type NUMERIC. EXTRACT is intended for computational processing, rather than for formatting date/time values for display.

Behavior type

  • Immutable if the specified date is a TIMESTAMP, DATE, or INTERVAL

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

EXTRACT ( field FROM date )

Parameters

field
A constant value that specifies the sub-field to extract from date (see Field Values below).
date
The date to process, an expression that evaluates to one of the following data types:

Field values

CENTURY
The century number.

The first century starts at 0001-01-01 00:00:00 AD. This definition applies to all Gregorian calendar countries. There is no century number 0, you go from –1 to 1.

DAY
The day (of the month) field (1–31).
DECADE
The year field divided by 10.
DOQ
The day within the current quarter. DOQ recognizes leap year days.
DOW
Zero-based day of the week, where Sunday=0.
DOY
The day of the year (1–365/366)
EPOCH
Specifies to return one of the following:
  • For DATE and TIMESTAMP values: the number of seconds before or since 1970-01-01 00:00:00-00 (if before, a negative number).

  • For INTERVAL values, the total number of seconds in the interval.

HOUR
The hour field (0–23).
ISODOW
The ISO day of the week, an integer between 1 and 7 where Monday is 1.
ISOWEEK
The ISO week of the year, an integer between 1 and 53.
ISOYEAR
The ISO year.
MICROSECONDS
The seconds field, including fractional parts, multiplied by 1,000,000. This includes full seconds.
MILLENNIUM
The millennium number, where the first millennium is 1 and each millenium starts on 01-01-y001. For example, millennium 2 starts on 01-01-1001.
MILLISECONDS
The seconds field, including fractional parts, multiplied by 1000. This includes full seconds.
MINUTE
The minutes field (0 - 59).
MONTH
For TIMESTAMP values, the number of the month within the year (1 - 12) ; for interval values the number of months, modulo 12 (0 - 11).
QUARTER
The calendar quarter of the specified date as an integer, where the January-March quarter is 1, valid only for TIMESTAMP values.
SECOND
The seconds field, including fractional parts, 0–59, or 0-60 if the operating system implements leap seconds.
TIME ZONE
The time zone offset from UTC, in seconds. Positive values correspond to time zones east of UTC, negative values to zones west of UTC.
TIMEZONE_HOUR
The hour component of the time zone offset.
TIMEZONE_MINUTE
The minute component of the time zone offset.
WEEK
The number of the week of the calendar year that the day is in.
YEAR
The year field. There is no 0 AD, so subtract BC years from AD years accordingly.

Examples

Extract the day of the week and day in quarter from the current TIMESTAMP:

=> SELECT CURRENT_TIMESTAMP AS NOW;
              NOW
-------------------------------
 2016-05-03 11:36:08.829004-04
(1 row)
=> SELECT EXTRACT (DAY FROM CURRENT_TIMESTAMP);
 date_part
-----------
         3
(1 row)
=> SELECT EXTRACT (DOQ FROM CURRENT_TIMESTAMP);
 date_part
-----------
        33
(1 row)

Extract the timezone hour from the current time:

=> SELECT CURRENT_TIMESTAMP;
           ?column?
-------------------------------
 2016-05-03 11:36:08.829004-04
(1 row)

=>  SELECT EXTRACT(TIMEZONE_HOUR FROM CURRENT_TIMESTAMP);
 date_part
-----------
        -4
(1 row)

Extract the number of seconds since 01-01-1970 00:00:

=> SELECT EXTRACT(EPOCH FROM '2001-02-16 20:38:40-08'::TIMESTAMPTZ);
    date_part
------------------
 982384720.000000
(1 row)

Extract the number of seconds between 01-01-1970 00:00 and 5 days 3 hours before:

=> SELECT EXTRACT(EPOCH FROM -'5 days 3 hours'::INTERVAL);
   date_part
----------------
 -442800.000000
(1 row)

Convert the results from the last example to a TIMESTAMP:

=> SELECT 'EPOCH'::TIMESTAMPTZ -442800  * '1 second'::INTERVAL;
        ?column?
------------------------
 1969-12-26 16:00:00-05
(1 row)

19 - GETDATE

Returns the current statement's start date and time as a TIMESTAMP value.

Returns the current statement's start date and time as a TIMESTAMP value. This function is identical to SYSDATE.

GETDATE uses the date and time supplied by the operating system on the server to which you are connected, which is the same across all servers. Internally, GETDATE converts STATEMENT_TIMESTAMP from TIMESTAMPTZ to TIMESTAMP.

Behavior type

Stable

Syntax

GETDATE()

Examples

=> SELECT GETDATE();
          GETDATE
----------------------------
 2011-03-07 13:21:29.497742
(1 row)

See also

Date/time expressions

20 - GETUTCDATE

Returns the current statement's start date and time as a TIMESTAMP value.

Returns the current statement's start date and time as a TIMESTAMP value.

GETUTCDATE uses the date and time supplied by the operating system on the server to which you are connected, which is the same across all servers. Internally, GETUTCDATE converts STATEMENT_TIMESTAMP at TIME ZONE 'UTC'.

Behavior type

Stable

Syntax

GETUTCDATE()

Examples

=> SELECT GETUTCDATE();
         GETUTCDATE
----------------------------
 2011-03-07 20:20:26.193052
(1 row)

See also

21 - HOUR

Returns the hour portion of the specified date as an integer, where 0 is 00:00 to 00:59.

Returns the hour portion of the specified date as an integer, where 0 is 00:00 to 00:59.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

HOUR( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT HOUR (TIMESTAMP 'sep 22, 2011 12:34');
 HOUR
------
   12
(1 row)
=> SELECT HOUR (INTERVAL '35 12:34');
 HOUR
------
   12
(1 row)
=> SELECT HOUR ('12:34');
 HOUR
------
   12
(1 row)

22 - ISFINITE

Tests for the special TIMESTAMP constant INFINITY and returns a value of type BOOLEAN.

Tests for the special TIMESTAMP constant INFINITY and returns a value of type BOOLEAN.

Behavior type

Immutable

Syntax

ISFINITE ( timestamp )

Parameters

timestamp
Expression of type TIMESTAMP

Examples

SELECT ISFINITE(TIMESTAMP '2009-02-16 21:28:30');
 ISFINITE
----------
 t
(1 row)
SELECT ISFINITE(TIMESTAMP 'INFINITY');
 ISFINITE
----------
 f
(1 row)

23 - JULIAN_DAY

Returns the integer value of the specified day according to the Julian calendar, where day 1 is the first day of the Julian period, January 1, 4713 BC (on the Gregorian calendar, November 24, 4714 BC).

Returns the integer value of the specified day according to the Julian calendar, where day 1 is the first day of the Julian period, January 1, 4713 BC (on the Gregorian calendar, November 24, 4714 BC).

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

JULIAN_DAY ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT JULIAN_DAY (DATE 'MARCH 15, 0044 BC');
 JULIAN_DAY
------------
    1705428
(1 row)

=> SELECT JULIAN_DAY (DATE '2001-01-01');
 JULIAN_DAY
------------
    2451911
(1 row)

24 - LAST_DAY

Returns the last day of the month in the specified date.

Returns the last day of the month in the specified date.

Behavior type

  • Immutable if the specified is a TIMESTAMP or DATE

  • Stable if the specified date is a TIMESTAMPTZ

Syntax

LAST_DAY ( date )

Parameters

date
The date to process, one of the following data types:

Calculating first day of month

SQL does not support any function that returns the first day in the month of a given date. You must use other functions to work around this limitation. For example:

=> SELECT DATE ('2022/07/04') - DAYOFMONTH ('2022/07/04') +1;
  ?column?
------------
 2022-07-01
(1 row)

=> SELECT LAST_DAY('1929/06/06') - (SELECT DAY(LAST_DAY('1929/06/06'))-1);
  ?column?
------------
 1929-06-01
(1 row)

Examples

The following example returns the last day of February as 29 because 2016 is a leap year:

=> SELECT LAST_DAY('2016-02-28 23:30 PST') "Last Day";
  Last Day
------------
 2016-02-29
(1 row)

The following example returns the last day of February in a non-leap year:

> SELECT LAST_DAY('2017/02/03') "Last";
    Last
------------
 2017-02-28
(1 row)

The following example returns the last day of March, after converting the string value to the specified DATE type:

=> SELECT LAST_DAY('2003/03/15') "Last";
    Last
------------
 2012-03-31
(1 row)

25 - LOCALTIME

Returns a value of type TIME that represents the start of the current transaction.

Returns a value of type TIME that represents the start of the current transaction.

The return value does not change during the transaction. Thus, multiple calls to LOCALTIME within the same transaction return the same timestamp.

Behavior type

Stable

Syntax

LOCALTIME [ ( precision ) ]

Parameters

precision
Rounds the result to the specified number of fractional digits in the seconds field.

Examples

=> CREATE TABLE t1 (a int, b int);
CREATE TABLE

=> INSERT INTO t1 VALUES (1,2);
 OUTPUT
--------
      1
(1 row)

=> SELECT LOCALTIME time;
    time
-----------------
 15:03:14.595296
(1 row)

=> INSERT INTO t1 VALUES (3,4);
 OUTPUT
--------
      1
(1 row)

=> SELECT LOCALTIME;
    time
-----------------
 15:03:14.595296
(1 row)

=> COMMIT;
COMMIT
=> SELECT LOCALTIME;
    time
-----------------
 15:03:49.738032
(1 row)

26 - LOCALTIMESTAMP

Returns a value of type TIMESTAMP/TIMESTAMPTZ that represents the start of the current transaction, and remains unchanged until the transaction is closed.

Returns a value of type TIMESTAMP/TIMESTAMPTZ that represents the start of the current transaction, and remains unchanged until the transaction is closed. Thus, multiple calls to LOCALTIMESTAMP within a given transaction return the same timestamp.

Behavior type

Stable

Syntax

LOCALTIMESTAMP [ ( precision ) ]

Parameters

precision
Rounds the result to the specified number of fractional digits in the seconds field.

Examples

=> CREATE TABLE t1 (a int, b int);
CREATE TABLE
=> INSERT INTO t1 VALUES (1,2);
 OUTPUT
--------
      1
(1 row)

=> SELECT LOCALTIMESTAMP(2) AS 'local timestamp';
    local timestamp
------------------------
 2021-03-05 10:48:58.26
(1 row)

=> INSERT INTO t1 VALUES (3,4);
 OUTPUT
--------
      1
(1 row)

=> SELECT LOCALTIMESTAMP(2) AS 'local timestamp';
    local timestamp
------------------------
 2021-03-05 10:48:58.26
(1 row)

=> COMMIT;
COMMIT
=> SELECT LOCALTIMESTAMP(2) AS 'local timestamp';
    local timestamp
------------------------
 2021-03-05 10:50:08.99
(1 row)

27 - MICROSECOND

Returns the microsecond portion of the specified date as an integer.

Returns the microsecond portion of the specified date as an integer.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, INTERVAL, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

MICROSECOND ( date )

Parameters

date
The date to process, one of the following data types:

Examples

=> SELECT MICROSECOND (TIMESTAMP 'Sep 22, 2011 12:34:01.123456');
 MICROSECOND
-------------
      123456
(1 row)

28 - MIDNIGHT_SECONDS

Within the specified date, returns the number of seconds between midnight and the date's time portion.

Within the specified date, returns the number of seconds between midnight and the date's time portion.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

MIDNIGHT_SECONDS ( date )

Parameters

date

The date to process, one of the following data types:

Examples

Get the number of seconds since midnight:

=> SELECT MIDNIGHT_SECONDS(CURRENT_TIMESTAMP);
 MIDNIGHT_SECONDS
------------------
            36480
(1 row)

Get the number of seconds between midnight and noon on March 3 2016:

=> SELECT MIDNIGHT_SECONDS('3-3-2016 12:00'::TIMESTAMP);
 MIDNIGHT_SECONDS
------------------
            43200
(1 row)

29 - MINUTE

Returns the minute portion of the specified date as an integer.

Returns the minute portion of the specified date as an integer.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, VARCHAR or INTERVAL

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

MINUTE ( date )

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT MINUTE('12:34:03.456789');
 MINUTE
--------
     34
(1 row)
=>SELECT MINUTE (TIMESTAMP 'sep 22, 2011 12:34');
 MINUTE
--------
     34
(1 row)
=> SELECT MINUTE(INTERVAL '35 12:34:03.456789');
 MINUTE
--------
     34
(1 row)

30 - MONTH

Returns the month portion of the specified date as an integer.

Returns the month portion of the specified date as an integer.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, VARCHAR or INTERVAL

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

MONTH ( date )

Parameters

date

The date to process, one of the following data types:

Examples

In the following examples, Vertica returns the month portion of the specified string. For example, '6-9' represent September 6.

=> SELECT MONTH('6-9');
 MONTH
-------
     9
(1 row)
=> SELECT MONTH (TIMESTAMP 'sep 22, 2011 12:34');
 MONTH
-------
     9
(1 row)
=> SELECT MONTH(INTERVAL '2-35' year to month);
 MONTH
-------
    11
(1 row)

31 - MONTHS_BETWEEN

Returns the number of months between two dates.

Returns the number of months between two dates. MONTHS_BETWEEN can return an integer or a FLOAT:

  • Integer: The day portions of date1 and date2 are the same, and neither date is the last day of the month. MONTHS_BETWEEN also returns an integer if both dates in date1 and date2 are the last days of their respective months. For example, MONTHS_BETWEEN calculates the difference between April 30 and March 31 as 1 month.

  • FLOAT: The day portions of date1 and date2 are different and one or both dates are not the last day of their respective months. For example, the difference between April 2 and March 1 is 1.03225806451613. To calculate month fractions, MONTHS_BETWEEN assumes all months contain 31 days.

MONTHS_BETWEEN disregards timestamp time portions.

Behavior type

  • Immutable if both date arguments are of data type TIMESTAMP or DATE

  • Stable if either date is a TIMESTAMPTZ

Syntax

MONTHS_BETWEEN ( date1 , date2 );

Parameters

date1
date2
Specify the dates to evaluate where date1 and date2 evaluate to one of the following data types:
  • DATE

  • TIMESTAMP

  • TIMESTAMPTZ

If date1 < date2, MONTHS_BETWEEN returns a negative value.

Examples

Return the number of months between April 7 2016 and January 7 2015:

=> SELECT MONTHS_BETWEEN ('04-07-16'::TIMESTAMP, '01-07-15'::TIMESTAMP);
 MONTHS_BETWEEN
----------------
             15
(1 row)

Return the number of months between March 31 2016 and February 28 2016 (MONTHS_BETWEEN assumes both months contain 31 days):

=> SELECT MONTHS_BETWEEN ('03-31-16'::TIMESTAMP, '02-28-16'::TIMESTAMP);
  MONTHS_BETWEEN
------------------
 1.09677419354839
(1 row)

Return the number of months between March 31 2016 and February 29 2016:

=> SELECT MONTHS_BETWEEN ('03-31-16'::TIMESTAMP, '02-29-16'::TIMESTAMP);
 MONTHS_BETWEEN
----------------
              1
(1 row)

32 - NEW_TIME

Converts a timestamp value from one time zone to another and returns a TIMESTAMP.

Converts a timestamp value from one time zone to another and returns a TIMESTAMP.

Behavior type

Immutable

Syntax

NEW_TIME( 'timestamp' , 'timezone1' , 'timezone2')

Parameters

timestamp
The timestamp to convert, conforms to one of the following formats:
timezone1
*`timezone2`*
Specify the source and target timezones, one of the strings defined in /opt/vertica/share/timezonesets. For example:
  • GMT: Greenwich Mean Time

  • AST / ADT: Atlantic Standard/Daylight Time

  • EST / EDT: Eastern Standard/Daylight Time

  • CST / CDT: Central Standard/Daylight Time

  • MST / MDT: Mountain Standard/Daylight Time

  • PST / PDT: Pacific Standard/Daylight Time

Examples

Convert the specified time from Eastern Standard Time (EST) to Pacific Standard Time (PST):

=> SELECT NEW_TIME('05-24-12 13:48:00', 'EST', 'PST');
      NEW_TIME
---------------------
 2012-05-24 10:48:00
(1 row)

Convert 1:00 AM January 2012 from EST to PST:

=> SELECT NEW_TIME('01-01-12 01:00:00', 'EST', 'PST');
      NEW_TIME
---------------------
 2011-12-31 22:00:00
(1 row)

Convert the current time EST to PST:


=> SELECT NOW();
              NOW
-------------------------------
 2016-12-09 10:30:36.727307-05
(1 row)

=> SELECT NEW_TIME('NOW', 'EDT', 'CDT');
          NEW_TIME
----------------------------
 2016-12-09 09:30:36.727307
(1 row)

The following example returns the year 45 before the Common Era in Greenwich Mean Time and converts it to Newfoundland Standard Time:

=>  SELECT NEW_TIME('April 1, 45 BC', 'GMT', 'NST')::DATE;
   NEW_TIME
---------------
 0045-03-31 BC
(1 row)

33 - NEXT_DAY

Returns the date of the first instance of a particular day of the week that follows the specified date.

Returns the date of the first instance of a particular day of the week that follows the specified date.

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Syntax

NEXT_DAY( 'date', 'day-string')

Parameters

date

The date to process, one of the following data types:

day-string
The day of the week to process, a CHAR or VARCHAR string or character constant. Supply the full English name such as Tuesday, or any conventional abbreviation, such as Tue or Tues. day-string is not case sensitive and trailing spaces are ignored.

Examples

Get the date of the first Monday that follows April 29 2016:

=> SELECT NEXT_DAY('4-29-2016'::TIMESTAMP,'Monday') "NEXT DAY" ;
  NEXT DAY
------------
 2016-05-02
(1 row)

Get the first Tuesday that follows today:

SELECT NEXT_DAY(CURRENT_TIMESTAMP,'tues') "NEXT DAY" ;
  NEXT DAY
------------
 2016-05-03
(1 row)

34 - NOW [date/time]

Returns a value of type TIMESTAMP WITH TIME ZONE representing the start of the current transaction.

Returns a value of type TIMESTAMP WITH TIME ZONE representing the start of the current transaction. NOW is equivalent to CURRENT_TIMESTAMP except that it does not accept a precision parameter.

The return value does not change during the transaction. Thus, multiple calls to CURRENT_TIMESTAMP within the same transaction return the same timestamp.

Behavior type

Stable

Syntax

NOW()

Examples


=> CREATE TABLE t1 (a int, b int);
CREATE TABLE
=> INSERT INTO t1 VALUES (1,2);
 OUTPUT
--------
      1
(1 row)

=> SELECT NOW();
             NOW
------------------------------
 2016-12-09 13:00:08.74685-05
(1 row)

=> INSERT INTO t1 VALUES (3,4);
 OUTPUT
--------
      1
(1 row)

=> SELECT NOW();
             NOW
------------------------------
 2016-12-09 13:00:08.74685-05
(1 row)

=> COMMIT;
COMMIT
dbadmin=> SELECT NOW();
              NOW
-------------------------------
 2016-12-09 13:01:31.420624-05
(1 row)

35 - OVERLAPS

Evaluates two time periods and returns true when they overlap, false otherwise.

Evaluates two time periods and returns true when they overlap, false otherwise.

Behavior type

  • Stable when TIMESTAMP and TIMESTAMPTZ are both used, or when TIMESTAMPTZ is used with INTERVAL

  • Immutable otherwise

Syntax

( start, end ) OVERLAPS ( start, end )
( start, interval) OVERLAPS ( start, interval )

Parameters

start
DATE, TIME, or TIMESTAMP/TIMESTAMPTZ value that specifies the beginning of a time period.
end
DATE, TIME, or TIMESTAMP/TIMESTAMPTZ value that specifies the end of a time period.
interval
Value that specifies the length of the time period.

Examples

Evaluate whether date ranges Feb 16 - Dec 21, 2016 and Oct 10 2008 - Oct 3 2016 overlap:

=> SELECT (DATE '2016-02-16', DATE '2016-12-21') OVERLAPS (DATE '2008-10-30', DATE '2016-10-30');
 overlaps
----------
 t
(1 row)

Evaluate whether date ranges Feb 16 - Dec 21, 2016 and Jan 01 - Oct 30 2008 - Oct 3, 2016 overlap:

=> SELECT (DATE '2016-02-16', DATE '2016-12-21') OVERLAPS (DATE '2008-01-30', DATE '2008-10-30');
 overlaps
----------
 f
(1 row)

Evaluate whether date range Feb 02 2016 + 1 week overlaps with date range Oct 16 2016 - 8 months:

=> SELECT (DATE '2016-02-16', INTERVAL '1 week') OVERLAPS (DATE '2016-10-16', INTERVAL '-8 months');
 overlaps
----------
 t
(1 row)

36 - QUARTER

Returns calendar quarter of the specified date as an integer, where the January-March quarter is 1.

Returns calendar quarter of the specified date as an integer, where the January-March quarter is 1.

Syntax

QUARTER ( date )

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR.

  • Stable if the specified date is aTIMESTAMPTZ

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT QUARTER (TIMESTAMP 'sep 22, 2011 12:34');
 QUARTER
---------
       3
(1 row)

37 - ROUND

Rounds the specified date or time.

Rounds the specified date or time. If you omit the precision argument, ROUND rounds to day (DD) precision.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP or DATE

  • Stable if the target date is aTIMESTAMPTZ

Syntax

ROUND( rounding-target[, 'precision'] )

Parameters

*rounding-target*
An expression that evaluates to one of the following data types:
precision
A string constant that specifies precision for the rounded value, one of the following:
  • Century: CC | SCC

  • Year: SYYY | YYYY | YEAR | YYY | YY | Y

  • ISO Year: IYYY | IYY | IY | I

  • Quarter: Q

  • Month: MONTH | MON | MM | RM

  • Same weekday as first day of year: WW

  • Same weekday as first day of ISO year: IW

  • Same weekday as first day of month: W

  • Day (default): DDD | DD | J

  • First weekday: DAY | DY | D

  • Hour: HH | HH12 | HH24

  • Minute: MI

  • Second: SS

Examples

Round to the nearest hour:

=> SELECT ROUND(CURRENT_TIMESTAMP, 'HH');
        ROUND
---------------------
 2016-04-28 15:00:00
(1 row)

Round to the nearest month:

=> SELECT ROUND('9-22-2011 12:34:00'::TIMESTAMP, 'MM');
        ROUND
---------------------
 2011-10-01 00:00:00
(1 row)

See also

TIMESTAMP_ROUND

38 - SECOND

Returns the seconds portion of the specified date as an integer.

Returns the seconds portion of the specified date as an integer.

Syntax

SECOND ( date )

Behavior type

Immutable, except for TIMESTAMPTZ arguments where it is stable.

Parameters

date
The date to process, one of the following data types:

Examples

=> SELECT SECOND ('23:34:03.456789');
 SECOND
--------
      3
(1 row)
=> SELECT SECOND (TIMESTAMP 'sep 22, 2011 12:34');
 SECOND
--------
      0
(1 row)
=> SELECT SECOND (INTERVAL '35 12:34:03.456789');
 SECOND
--------
      3
(1 row)

39 - STATEMENT_TIMESTAMP

Similar to TRANSACTION_TIMESTAMP, returns a value of type TIMESTAMP WITH TIME ZONE that represents the start of the current statement.

Similar to TRANSACTION_TIMESTAMP, returns a value of type TIMESTAMP WITH TIME ZONE that represents the start of the current statement.

The return value does not change during statement execution. Thus, different stages of statement execution always have the same timestamp.

Behavior type

Stable

Syntax

STATEMENT_TIMESTAMP()

Examples

=> SELECT foo, bar FROM (SELECT STATEMENT_TIMESTAMP() AS foo)foo, (SELECT STATEMENT_TIMESTAMP() as bar)bar;
              foo              |              bar
-------------------------------+-------------------------------
 2016-12-07 14:55:51.543988-05 | 2016-12-07 14:55:51.543988-05
(1 row)

See also

40 - SYSDATE

Returns the current statement's start date and time as a TIMESTAMP value.

Returns the current statement's start date and time as a TIMESTAMP value. This function is identical to GETDATE.

SYSDATE uses the date and time supplied by the operating system on the server to which you are connected, which is the same across all servers. Internally, GETDATE converts STATEMENT_TIMESTAMP from TIMESTAMPTZ to TIMESTAMP.

Behavior type

Stable

Syntax

SYSDATE()

Examples

=> SELECT SYSDATE;
          sysdate
----------------------------
 2016-12-12 06:11:10.699642
(1 row)

See also

Date/time expressions

41 - TIME_SLICE

Aggregates data by different fixed-time intervals and returns a rounded-up input TIMESTAMP value to a value that corresponds with the start or end of the time slice interval.

Aggregates data by different fixed-time intervals and returns a rounded-up input TIMESTAMP value to a value that corresponds with the start or end of the time slice interval.

Given an input TIMESTAMP value such as 2000-10-28 00:00:01, the start time of a 3-second time slice interval is 2000-10-28 00:00:00, and the end time of the same time slice is 2000-10-28 00:00:03.

Behavior type

Immutable

Syntax

TIME_SLICE( expression, slice-length [, 'time-unit' [, 'start-or-end' ] ] )

Parameters

expression
One of the following:
  • Column of type TIMESTAMP

  • String constant that can be parsed into a TIMESTAMP value. For example:

    '2004-10-19 10:23:54'

Vertica evaluates expression on each row.

slice-length
A positive integer that specifies the slice length.
time-unit
Time unit of the slice, one of the following:
  • HOUR

  • MINUTE

  • SECOND (default)

  • MILLISECOND

  • MICROSECOND

start-or-end
Specifies whether the returned value corresponds to the start or end time with one of the following strings:
  • START (default)

  • END

Null argument handling

TIME_SLICE handles null arguments as follows:

  • TIME_SLICE returns an error when any one of slice-length, time-unit, or start-or-end parameters is null.

  • If expression is null and *slice-length*, *time-unit*, or *start-or-end* contain legal values, TIME_SLICE returns a NULL value instead of an error.

Usage

The following command returns the (default) start time of a 3-second time slice:

=> SELECT TIME_SLICE('2009-09-19 00:00:01', 3);
     TIME_SLICE
---------------------
 2009-09-19 00:00:00
(1 row)

The following command returns the end time of a 3-second time slice:

=> SELECT TIME_SLICE('2009-09-19 00:00:01', 3, 'SECOND', 'END');
     TIME_SLICE
---------------------
 2009-09-19 00:00:03
(1 row)

This command returns results in milliseconds, using a 3-second time slice:

=> SELECT TIME_SLICE('2009-09-19 00:00:01', 3, 'ms');
       TIME_SLICE
-------------------------
 2009-09-19 00:00:00.999

(1 row)

This command returns results in microseconds, using a 9-second time slice:

=> SELECT TIME_SLICE('2009-09-19 00:00:01', 3, 'us');
         TIME_SLICE
----------------------------
 2009-09-19 00:00:00.999999
(1 row)

The next example uses a 3-second interval with an input value of '00:00:01'. To focus specifically on seconds, the example omits date, though all values are implied as being part of the timestamp with a given input of '00:00:01':

  • '00:00:00' is the start of the 3-second time slice

  • '00:00:03' is the end of the 3-second time slice.

  • '00:00:03' is also the start of the second 3-second time slice. In time slice boundaries, the end value of a time slice does not belong to that time slice; it starts the next one.

When the time slice interval is not a factor of 60 seconds, such as a given slice length of 9 in the following example, the slice does not always start or end on 00 seconds:

=> SELECT TIME_SLICE('2009-02-14 20:13:01', 9);
     TIME_SLICE
---------------------
 2009-02-14 20:12:54
(1 row)

This is expected behavior, as the following properties are true for all time slices:

  • Equal in length

  • Consecutive (no gaps between them)

  • Non-overlapping

To force the above example ('2009-02-14 20:13:01') to start at '2009-02-14 20:13:00', adjust the output timestamp values so that the remainder of 54 counts up to 60:

=> SELECT TIME_SLICE('2009-02-14 20:13:01', 9 )+'6 seconds'::INTERVAL AS time;
        time
---------------------
 2009-02-14 20:13:00
(1 row)

Alternatively, you could use a different slice length, which is divisible by 60, such as 5:

=> SELECT TIME_SLICE('2009-02-14 20:13:01', 5);
     TIME_SLICE
---------------------
 2009-02-14 20:13:00
(1 row)

A TIMESTAMPTZ value is implicitly cast to TIMESTAMP. For example, the following two statements have the same effect.

=> SELECT TIME_SLICE('2009-09-23 11:12:01'::timestamptz, 3);
     TIME_SLICE
---------------------
 2009-09-23 11:12:00
(1 row)


=> SELECT TIME_SLICE('2009-09-23 11:12:01'::timestamptz::timestamp, 3);

     TIME_SLICE
---------------------
 2009-09-23 11:12:00
(1 row)

Examples

You can use the SQL analytic functions FIRST_VALUE and LAST_VALUE to find the first/last price within each time slice group (set of rows belonging to the same time slice). This structure can be useful if you want to sample input data by choosing one row from each time slice group.

=> SELECT date_key, transaction_time, sales_dollar_amount,TIME_SLICE(DATE '2000-01-01' + date_key + transaction_time, 3),
FIRST_VALUE(sales_dollar_amount)
OVER (PARTITION BY TIME_SLICE(DATE '2000-01-01' + date_key + transaction_time, 3)
     ORDER BY DATE '2000-01-01' + date_key + transaction_time) AS first_value
FROM store.store_sales_fact
LIMIT 20;

 date_key | transaction_time | sales_dollar_amount |     time_slice      | first_value
----------+------------------+---------------------+---------------------+-------------
        1 | 00:41:16         |                 164 | 2000-01-02 00:41:15 |         164
        1 | 00:41:33         |                 310 | 2000-01-02 00:41:33 |         310
        1 | 15:32:51         |                 271 | 2000-01-02 15:32:51 |         271
        1 | 15:33:15         |                 419 | 2000-01-02 15:33:15 |         419
        1 | 15:33:44         |                 193 | 2000-01-02 15:33:42 |         193
        1 | 16:36:29         |                 466 | 2000-01-02 16:36:27 |         466
        1 | 16:36:44         |                 250 | 2000-01-02 16:36:42 |         250
        2 | 03:11:28         |                  39 | 2000-01-03 03:11:27 |          39
        3 | 03:55:15         |                 375 | 2000-01-04 03:55:15 |         375
        3 | 11:58:05         |                 369 | 2000-01-04 11:58:03 |         369
        3 | 11:58:24         |                 174 | 2000-01-04 11:58:24 |         174
        3 | 11:58:52         |                 449 | 2000-01-04 11:58:51 |         449
        3 | 19:01:21         |                 201 | 2000-01-04 19:01:21 |         201
        3 | 22:15:05         |                 156 | 2000-01-04 22:15:03 |         156
        4 | 13:36:57         |                -125 | 2000-01-05 13:36:57 |        -125
        4 | 13:37:24         |                -251 | 2000-01-05 13:37:24 |        -251
        4 | 13:37:54         |                 353 | 2000-01-05 13:37:54 |         353
        4 | 13:38:04         |                 426 | 2000-01-05 13:38:03 |         426
        4 | 13:38:31         |                 209 | 2000-01-05 13:38:30 |         209
        5 | 10:21:24         |                 488 | 2000-01-06 10:21:24 |         488
(20 rows)

TIME_SLICE rounds the transaction time to the 3-second slice length.

The following example uses the analytic (window) OVER clause to return the last trading price (the last row ordered by TickTime) in each 3-second time slice partition:

=> SELECT DISTINCT TIME_SLICE(TickTime, 3), LAST_VALUE(price)OVER (PARTITION BY TIME_SLICE(TickTime, 3)
ORDER BY TickTime ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);

In the next example, FIRST_VALUE is evaluated once for each input record and the data is sorted by ascending values. Use SELECT DISTINCT to remove the duplicates and return only one output record per TIME_SLICE:

=> SELECT DISTINCT TIME_SLICE(TickTime, 3), FIRST_VALUE(price)OVER (PARTITION BY TIME_SLICE(TickTime, 3)
ORDER BY TickTime ASC)
FROM tick_store;
     TIME_SLICE      | ?column?
---------------------+----------
 2009-09-21 00:00:06 |    20.00
 2009-09-21 00:00:09 |    30.00
 2009-09-21 00:00:00 |    10.00
(3 rows)

The information output by the above query can also return MIN, MAX, and AVG of the trading prices within each time slice.

=> SELECT DISTINCT TIME_SLICE(TickTime, 3),FIRST_VALUE(Price) OVER (PARTITION BY TIME_SLICE(TickTime, 3)
ORDER BY TickTime ASC),
  MIN(price) OVER (PARTITION BY TIME_SLICE(TickTime, 3)),
  MAX(price) OVER (PARTITION BY TIME_SLICE(TickTime, 3)),
  AVG(price) OVER (PARTITION BY TIME_SLICE(TickTime, 3))
FROM tick_store;

See also

42 - TIMEOFDAY

Returns the wall-clock time as a text string.

Returns the wall-clock time as a text string. Function results advance during transactions.

Behavior type

Volatile

Syntax

TIMEOFDAY()

Examples

=> SELECT TIMEOFDAY();
              TIMEOFDAY
-------------------------------------
 Mon Dec 12 08:18:01.022710 2016 EST
(1 row)

43 - TIMESTAMP_ROUND

Rounds the specified TIMESTAMP.

Rounds the specified TIMESTAMP. If you omit the precision argument, TIMESTAMP_ROUND rounds to day (DD) precision.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP

  • Stable if the target date is a TIMESTAMPTZ

Syntax

TIMESTAMP_ROUND ( rounding-target[, 'precision'] )

Parameters

rounding-target
An expression that evaluates to one of the following data types:
precision
A string constant that specifies precision for the rounded value, one of the following:
  • Century: CC | SCC

  • Year: SYYY | YYYY | YEAR | YYY | YY | Y

  • ISO Year: IYYY | IYY | IY | I

  • Quarter: Q

  • Month: MONTH | MON | MM | RM

  • Same weekday as first day of year: WW

  • Same weekday as first day of ISO year: IW

  • Same weekday as first day of month: W

  • Day (default): DDD | DD | J

  • First weekday: DAY | DY | D

  • Hour: HH | HH12 | HH24

  • Minute: MI

  • Second: SS

Examples

Round to the nearest hour:

=> SELECT TIMESTAMP_ROUND(CURRENT_TIMESTAMP, 'HH');
        ROUND
---------------------
 2016-04-28 15:00:00
(1 row)

Round to the nearest month:

=> SELECT TIMESTAMP_ROUND('9-22-2011 12:34:00'::TIMESTAMP, 'MM');
        ROUND
---------------------
 2011-10-01 00:00:00
(1 row)

See also

ROUND

44 - TIMESTAMP_TRUNC

Truncates the specified TIMESTAMP.

Truncates the specified TIMESTAMP. If you omit the precision argument, TIMESTAMP_TRUNC truncates to day (DD) precision.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP

  • Stable if the target date is a TIMESTAMPTZ

Syntax

TIMESTAMP_TRUNC( trunc-target[, 'precision'] )

Parameters

trunc-target
An expression that evaluates to one of the following data types:
precision
A string constant that specifies precision for the truncated value, one of the following:
  • Century: CC | SCC

  • Year: SYYY | YYYY | YEAR | YYY | YY | Y

  • ISO Year: IYYY | IYY | IY | I

  • Quarter: Q

  • Month: MONTH | MON | MM | RM

  • Same weekday as first day of year: WW

  • Same weekday as first day of ISO year: IW

  • Same weekday as first day of month: W

  • Day: DDD | DD | J

  • First weekday: DAY | DY | D

  • Hour: HH | HH12 | HH24

  • Minute: MI

  • Second: SS

Examples

Truncate to the current hour:

=> SELECT TIMESTAMP_TRUNC(CURRENT_TIMESTAMP, 'HH');
   TIMESTAMP_TRUNC
---------------------
 2016-04-29 08:00:00
(1 row)

Truncate to the month:

=> SELECT TIMESTAMP_TRUNC('9-22-2011 12:34:00'::TIMESTAMP, 'MM');
   TIMESTAMP_TRUNC
---------------------
 2011-09-01 00:00:00
(1 row)

See also

TRUNC

45 - TIMESTAMPADD

Adds the specified number of intervals to a TIMESTAMP or TIMESTAMPTZ value and returns a result of the same data type.

Adds the specified number of intervals to a TIMESTAMP or TIMESTAMPTZ value and returns a result of the same data type.

Behavior type

  • Immutable if the input date is a TIMESTAMP

  • Stable if the input date is a TIMESTAMPTZ

Syntax

TIMESTAMPADD ( datepart, count, start-date );

Parameters

datepart
Specifies the type of time intervals that TIMESTAMPADD adds to the specified start date. If datepart is an expression, it must be enclosed in parentheses:
TIMESTAMPADD((expression), interval, start;

datepart must evaluate to one of the following string literals, either quoted or unquoted:

  • year | yy | yyyy

  • quarter | qq | q

  • month | mm | m

  • day | dayofyear | dd | d | dy | y

  • week | wk | ww

  • hour | hh

  • minute | mi | n

  • second | ss | s

  • millisecond | ms

  • microsecond | mcs | us

count
Integer or integer expression that specifies the number of datepart intervals to add to start-date.
start-date
TIMESTAMP or TIMESTAMPTZ value.

Examples

Add two months to the current date:

=> SELECT CURRENT_TIMESTAMP AS Today;
           Today
-------------------------------
 2016-05-02 06:56:57.923045-04
(1 row)

=> SELECT TIMESTAMPADD (MONTH, 2, (CURRENT_TIMESTAMP)) AS TodayPlusTwoMonths;;
      TodayPlusTwoMonths
-------------------------------
 2016-07-02 06:56:57.923045-04
(1 row)

Add 14 days to the beginning of the current month:

=> SELECT TIMESTAMPADD (DD, 14, (SELECT TRUNC((CURRENT_TIMESTAMP), 'MM')));
    timestampadd
---------------------
 2016-05-15 00:00:00
(1 row)

46 - TIMESTAMPDIFF

Returns the time span between two TIMESTAMP or TIMESTAMPTZ values, in the intervals specified.

Returns the time span between two TIMESTAMP or TIMESTAMPTZ values, in the intervals specified. TIMESTAMPDIFF excludes the start date in its calculation.

Behavior type

  • Immutable if start and end dates are TIMESTAMP

  • Stable if start and end dates are TIMESTAMPTZ

Syntax

TIMESTAMPDIFF ( datepart, start, end );

Parameters

datepart
Specifies the type of date or time intervals that TIMESTAMPDIFF returns. If datepart is an expression, it must be enclosed in parentheses:
TIMESTAMPDIFF((expression), start, end );

datepart must evaluate to one of the following string literals, either quoted or unquoted:

  • year | yy | yyyy

  • quarter | qq | q

  • month | mm | m

  • day | dayofyear | dd | d | dy | y

  • week | wk | ww

  • hour | hh

  • minute | mi | n

  • second | ss | s

  • millisecond | ms

  • microsecond | mcs | us

start, end
Specify the start and end dates, where start and end evaluate to one of the following data types:

If end < start, TIMESTAMPDIFF returns a negative value.

Date part intervals

TIMESTAMPDIFF uses the datepart argument to calculate the number of intervals between two dates, rather than the actual amount of time between them. For detailed information, see DATEDIFF.

Examples

=> SELECT TIMESTAMPDIFF (YEAR,'1-1-2006 12:34:00', '1-1-2008 12:34:00');
 timestampdiff
---------------
             2
(1 row)

See also

DATEDIFF

47 - TRANSACTION_TIMESTAMP

Returns a value of type TIME WITH TIMEZONE that represents the start of the current transaction.

Returns a value of type `TIME WITH TIMEZONE` that represents the start of the current transaction.

The return value does not change during the transaction. Thus, multiple calls to TRANSACTION_TIMESTAMP within the same transaction return the same timestamp.

TRANSACTION_TIMESTAMP is equivalent to CURRENT_TIMESTAMP, except it does not accept a precision parameter.

Behavior type

Stable

Syntax

TRANSACTION_TIMESTAMP()

Examples

=> SELECT foo, bar FROM (SELECT TRANSACTION_TIMESTAMP() AS foo)foo, (SELECT TRANSACTION_TIMESTAMP() as bar)bar;
              foo              |              bar
-------------------------------+-------------------------------
 2016-12-12 08:18:00.988528-05 | 2016-12-12 08:18:00.988528-05
(1 row)

See also

48 - TRUNC

Truncates the specified date or time.

Truncates the specified date or time. If you omit the precision argument, TRUNC truncates to day (DD) precision.

Behavior type

  • Immutable if thetarget date is a TIMESTAMP or DATE

  • Stable if the target date is aTIMESTAMPTZ

Syntax

TRUNC( trunc-target[, 'precision'] )

Parameters

*trunc-target*
An expression that evaluates to one of the following data types:
precision
A string constant that specifies precision for the truncated value, one of the following:
  • Century: CC | SCC

  • Year: SYYY | YYYY | YEAR | YYY | YY | Y

  • ISO Year: IYYY | IYY | IY | I

  • Quarter: Q

  • Month: MONTH | MON | MM | RM

  • Same weekday as first day of year: WW

  • Same weekday as first day of ISO year: IW

  • Same weekday as first day of month: W

  • Day (default): DDD | DD | J

  • First weekday: DAY | DY | D

  • Hour: HH | HH12 | HH24

  • Minute: MI

  • Second: SS

Examples

Truncate to the current hour:

=> => SELECT TRUNC(CURRENT_TIMESTAMP, 'HH');
        TRUNC
---------------------
 2016-04-29 10:00:00
(1 row)

Truncate to the month:

=> SELECT TRUNC('9-22-2011 12:34:00'::TIMESTAMP, 'MM');
   TIMESTAMP_TRUNC
---------------------
 2011-09-01 00:00:00
(1 row)

See also

TIMESTAMP_TRUNC

49 - WEEK

Returns the week of the year for the specified date as an integer, where the first week begins on the first Sunday on or preceding January 1.

Returns the week of the year for the specified date as an integer, where the first week begins on the first Sunday on or preceding January 1.

Syntax

WEEK ( date )

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Parameters

date

The date to process, one of the following data types:

Examples

January 2 is on Saturday, so WEEK returns 1:

=> SELECT WEEK ('1-2-2016'::DATE);
 WEEK
------
    1
(1 row)

January 3 is the second Sunday in 2016, so WEEK returns 2:

=> SELECT WEEK ('1-3-2016'::DATE);
 WEEK
------
    2
(1 row)

50 - WEEK_ISO

Returns the week of the year for the specified date as an integer, where the first week starts on Monday and contains January 4.

Returns the week of the year for the specified date as an integer, where the first week starts on Monday and contains January 4. This function conforms with the ISO 8061 standard.

Syntax

WEEK_ISO ( date )

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Parameters

date

The date to process, one of the following data types:

Examples

The first week of 2016 begins on Monday January 4:

=> SELECT WEEK_ISO ('1-4-2016'::DATE);
 WEEK_ISO
----------
        1
(1 row)

January 3 2016 returns week 53 of the previous year (2015):

=> SELECT WEEK_ISO ('1-3-2016'::DATE);
 WEEK_ISO
----------
       53
(1 row)

In 2015, January 4 is on Sunday, so the first week of 2015 begins on the preceding Monday (December 29 2014):

=> SELECT WEEK_ISO ('12-29-2014'::DATE);
 WEEK_ISO
----------
        1
(1 row)

51 - YEAR

Returns an integer that represents the year portion of the specified date.

Returns an integer that represents the year portion of the specified date.

Syntax

YEAR( date )

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, VARCHAR, or INTERVAL

  • Stable if the specified date is aTIMESTAMPTZ

Parameters

date

The date to process, one of the following data types:

Examples

=> SELECT YEAR(CURRENT_DATE::DATE);
 YEAR
------
 2016
(1 row)

See also

YEAR_ISO

52 - YEAR_ISO

Returns an integer that represents the year portion of the specified date.

Returns an integer that represents the year portion of the specified date. The return value is based on the ISO 8061 standard.

The first week of the ISO year is the week that contains January 4.

Syntax

YEAR_ISO ( date )

Behavior type

  • Immutable if thespecified date is a TIMESTAMP, DATE, or VARCHAR

  • Stable if the specified date is aTIMESTAMPTZ

Parameters

date

The date to process, one of the following data types:

Examples

> SELECT YEAR_ISO(CURRENT_DATE::DATE);
 YEAR_ISO
----------
     2016
(1 row)

See also

YEAR