ROUND_TIMESTAMP

The ROUND_TIMESTAMP function returns a timestamp that is the expression rounded to the unit specified by the format-string. If format-string is not specified, expression is rounded to the nearest day, as if 'DD' was specified for format-string.

Read syntax diagramSkip visual syntax diagramROUND_TIMESTAMP(expression ,'DD',format-string )
expression
An expression that returns a value of one of the following built-in data types: a date, a timestamp, a character-string, or a graphic-string.
If expression is a character or graphic string, its value must be a valid string representation of a date or timestamp. It is first converted to a TIMESTAMP(12) value. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
format-string
An expression that returns a built-in character string data type or graphic string data type. format-string contains a template of how expression should be rounded. For example, if format-string is 'DD', a timestamp that is represented by expression is rounded to the nearest day. Leading and trailing blanks are removed from the string, and the resulting substring must be a valid template for a timestamp. The resulting value is then folded to uppercase, so the characters in the value may be in any case. Allowable values for format-string are listed in Table 1.
The result of the function is a timestamp with a timestamp precision of:
  • p when the data type of expression is TIMESTAMP(p)
  • 0 when the data type of expression is DATE
  • 6 otherwise.

If either argument can be null, the result can be null; if either argument is null, the result is the null value.

Table 1. ROUND_TIMESTAMP and TRUNC_TIMESTAMP format models
Format model Rounding or truncating unit ROUND_TIMESTAMP example TRUNC_TIMESTAMP example
CC
SCC
Century. One greater than the first two digits of a four digit year.

For ROUND_TIMESTAMP, rounds up on the 50th year of the century.

Input value: 1897-12-04-12.22.22.000000

Result: 1901-01-01-00.00.00.000000

Input value: 1897-12-04-12.22.22.000000

Result: 1801-01-01-00.00.00.000000

YYYY
SYYYY
YEAR
SYEAR
YYY
YY
Y
Year.

For ROUND_TIMESTAMP, rounds up on July 1 to January 1st of the next year.

Input value: 1897-12-04-12.22.22.000000

Result: 1898-01-01-00.00.00.000000

Input value: 1897-12-04-12.22.22.000000

Result: 1897-01-01-00.00.00.000000

IYYY
IYY
IY
I
ISO year.

For ROUND_TIMESTAMP, rounds up on July 1 to the first day of the next ISO year. The first day of the ISO year is defined as the Monday of the first ISO week.

Input value: 1897-12-04-12.22.22.000000

Result: 1898-01-03-00.00.00.000000

Input value: 1897-12-04-12.22.22.000000

Result: 1897-01-04-00.00.00.000000

Q Quarter.

For ROUND_TIMESTAMP, rounds up on the 16th day of the second month of the quarter.

Input value: 1999-06-04-12.12.30.000000

Result: 1999-07-01-00.00.00.000000

Input value: 1999-06-04-12.12.30.000000

Result: 1999-04-01-00.00.00.000000

MONTH
MON
MM
RM
Month.

For ROUND_TIMESTAMP, rounds up on the 16th day of the month.

Input value: 1999-06-18-12.12.30.000000

Result: 1999-07-01-00.00.00.000000

Input value: 1999-06-18-12.12.30.000000

Result: 1999-06-01-00.00.00.000000

WW Same day of the week as the first day of the year.

For ROUND_TIMESTAMP, rounds up on the 12th hour of the 4th day of the week, with respect to the first day of the year.

Input value: 2000-05-05-12.12.30.000000

Result: 2000-05-06-00.00.00.000000

Input value: 2000-05-05-12.12.30.000000

Result: 2000-04-29-00.00.00.000000

IW Same day of the week as the first day of the ISO year.

For ROUND_TIMESTAMP, rounds up on the 12th hour of the 4th day of the week, with respect to the first day of the ISO year.

Input value: 2000-05-05-12.12.30.000000

Result: 2000-05-08-00.00.00.000000

Input value: 2000-05-05-12.12.30.000000

Result: 2000-05-01-00.00.00.000000

W Same day of the week as the first day of the month.

For ROUND_TIMESTAMP, rounds up on the 12th hour of the 4th day of the week, with respect to the first day of the month.

Input value: 2000-06-21-12.12.30.000000

Result: 2000-06-22-00.00.00.000000

Input value: 2000-06-21-12.12.30.000000

Result: 2000-06-15-00.00.00.000000

DDD
DD
J
Day.

For ROUND_TIMESTAMP, rounds up on the 12th hour of the day.

Input value: 2000-05-17-12.59.59.000000

Result: 2000-05-18-00.00.00.000000

Input value: 2000-05-17-12.59.59.000000

Result: 2000-05-17-00.00.00.000000

DAY
DY
D
Starting day of the week.

For ROUND_TIMESTAMP, rounds up with respect to the 12th hour of the 4th day of the week. The first day of the week is always Sunday.

Input value: 2000-05-17-12.59.59.000000

Result: 2000-05-21-00.00.00.000000

Input value: 2000-05-17-12.59.59.000000

Result: 2000-05-14-00.00.00.000000

HH
HH12
HH24
Hour.

For ROUND_TIMESTAMP, rounds up at 30 minutes.

Input value: 2000-05-17-23.59.59.000000

Result: 2000-05-18-00.00.00.000000

Input value: 2000-05-17-23.59.59.000000

Result: 2000-05-17-23.00.00.000000

MI Minute.

For ROUND_TIMESTAMP, rounds up at 30 seconds.

Input value: 2000-05-17-23.58.45.000000

Result: 2000-05-17-23.59.00.000000

Input value: 2000-05-17-23.58.45.000000

Result: 2000-05-17-23.58.00.000000

SS Second.

For ROUND_TIMESTAMP, rounds up at 500000 microseconds.

Input value: 2000-05-17-23.58.45.500000

Result: 2000-05-17-23.58.46.000000

Input value: 2000-05-17-23.58.45.500000

Result: 2000-05-17-23.58.45.000000

Note:

The ISO year starts on the first day of the first ISO week of the year. This can be up to three days before January 1st or three days after January 1st. See WEEK_ISO for details.

Example

  • Set the host variable RND_TMSTMP with the current year rounded to the nearest month value.
      SET :RND_TMSTMP = ROUND_TIMESTAMP('2000-03-18-17.30.00', 'MONTH');
    Host variable RND_TMSTMP is set with the value 2000-04-01-00.00.00.000000.