Date and Time Processing Functions and Operators
Date and Time Operators
WARNING:
When the user uses date/time operators, explicit type prefixes are modified for corresponding operands to ensure that the operands parsed by the database are consistent with what the user expects, and no unexpected results occur.
For example, abnormal mistakes will occur in the following example without an explicit data type.SELECT date '2001-10-01' - '7' AS RESULT;
Table 1 Time and date operators
Time/Date Functions
age(timestamp, timestamp)
Description: Subtracts arguments, producing a result in YYYY-MM-DD format. If the result is negative, the returned result is also negative.
Return type: interval
Example:
postgres=# SELECT age(timestamp '2001-04-10', timestamp '1957-06-13'); age ------------------------- 43 years 9 mons 27 days (1 row)
age(timestamp)
Description: Subtracts from current_date
Return type: interval
Example:
postgres=# SELECT age(timestamp '1957-06-13'); age ------------------------- 60 years 2 mons 18 days (1 row)
clock_timestamp()
Description: Specifies the current timestamp of the real-time clock.
Return type: timestamp with time zone
Example:
postgres=# SELECT clock_timestamp(); clock_timestamp ------------------------------- 2017-09-01 16:57:36.636205+08 (1 row)
current_date
Description: current date
Return type: date
Example:
postgres=# SELECT current_date; date ------------ 2017-09-01 (1 row)
current_time
Description: current time
Return type: time with time zone
Example:
postgres=# SELECT current_time; timetz -------------------- 16:58:07.086215+08 (1 row)
current_timestamp
Description: Specifies the current date and time.
Return type: timestamp with time zone
Example:
postgres=# SELECT current_timestamp; pg_systimestamp ------------------------------ 2017-09-01 16:58:19.22173+08 (1 row)
date_part(text, timestamp)
Description: Obtains the value of a subdomain in date or time, for example, the year or hour. Equivalent to extract(field from timestamp).
Return type: double precision
Example:
postgres=# SELECT date_part('hour', timestamp '2001-02-16 20:38:40'); date_part
20
(1 row)
```
date_part(text, interval)
Description: Obtains the subdomain value of the date/time value. When obtaining the month value, if the value is greater than 12, obtain the remainder after it is divided by 12. Equivalent to extract(field from timestamp).
Return type: double precision
Example:
postgres=# SELECT date_part('month', interval '2 years 3 months'); date_part ----------- 3 (1 row)
date_trunc(text, timestamp)
Description: Truncates to the precision specified by text.
Return type: timestamp
Example:
postgres=# SELECT date_trunc('hour', timestamp '2001-02-16 20:38:40'); date_trunc --------------------- 2001-02-16 20:00:00 (1 row)
trunc(timestamp)
Description: By default, the data is intercepted by day.
Example:
postgres=# SELECT trunc(timestamp '2001-02-16 20:38:40'); trunc --------------------- 2001-02-16 00:00:00 (1 row)
extract(field from timestamp)
Description: Obtains the hour.
Return type: double precision
Example:
postgres=# SELECT extract(hour from timestamp '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
extract(field from interval)
Description: Obtains the month. If the value is greater than 12, obtain the remainder after it is divided by 12.
Return type: double precision
Example:
postgres=# SELECT extract(month from interval '2 years 3 months'); date_part ----------- 3 (1 row)
isfinite(date)
Description: Tests for valid date.
Return type: Boolean
Example:
postgres=# SELECT isfinite(date '2001-02-16'); isfinite ---------- t (1 row)
isfinite(timestamp)
Description: Tests for valid timestamp.
Return type: Boolean
Example:
postgres=# SELECT isfinite(timestamp '2001-02-16 21:28:30'); isfinite ---------- t (1 row)
isfinite(interval)
Description: Tests for valid interval.
Return type: Boolean
Example:
postgres=# SELECT isfinite(interval '4 hours'); isfinite ---------- t (1 row)
justify_days(interval)
Description: Sets the time interval in months (30 days as a month).
Return type: interval
Example:
postgres=# SELECT justify_days(interval '35 days'); justify_days -------------- 1 mon 5 days (1 row)
justify_hours(interval)
Description: Sets the time interval in days (24 hours is one day).
Return type: interval
Example:
postgres=# SELECT JUSTIFY_HOURS(INTERVAL '27 HOURS'); justify_hours ---------------- 1 day 03:00:00 (1 row)
justify_interval(interval)
Description: Adjusts interval using justify_days and justify_hours.
Return type: interval
Example:
postgres=# SELECT JUSTIFY_INTERVAL(INTERVAL '1 MON -1 HOUR'); justify_interval ------------------ 29 days 23:00:00 (1 row)
localtime
Description: current time
Return type: time
Example:
postgres=# SELECT localtime AS RESULT; result ---------------- 16:05:55.664681 (1 row)
localtimestamp
Description: Specifies the current date and time.
Return type: timestamp
Example:
postgres=# SELECT localtimestamp; timestamp ---------------------------- 2017-09-01 17:03:30.781902 (1 row)
now()
Description: Specifies the current date and time.
Return type: timestamp with time zone
Example:
postgres=# SELECT now(); now ------------------------------- 2017-09-01 17:03:42.549426+08 (1 row)
numtodsinterval(num, interval_unit)
Description: Converts a number to the interval type. num is a numeric-typed number. interval_unit is a string in the following format: 'DAY' | 'HOUR' | 'MINUTE' | 'SECOND'
You can set the IntervalStyle parameter to a to be compatible with the interval output format of the function.
Example:
postgres=# SELECT numtodsinterval(100, 'HOUR'); numtodsinterval ----------------- 100:00:00 (1 row) postgres=# SET intervalstyle = a; SET postgres=# SELECT numtodsinterval(100, 'HOUR'); numtodsinterval ------------------------------- +000000004 04:00:00.000000000 (1 row)
pg_sleep(seconds)
Description: Server thread delay time, in seconds.
Return type: void
Example:
postgres=# SELECT pg_sleep(10); pg_sleep ---------- (1 row)
statement_timestamp()
Description: Specifies the current date and time.
Return type: timestamp with time zone
Example:
postgres=# SELECT statement_timestamp(); statement_timestamp ------------------------------- 2017-09-01 17:04:39.119267+08 (1 row)
sysdate
Description: Specifies the current date and time.
Return type: timestamp
Example:
postgres=# SELECT sysdate; sysdate --------------------- 2017-09-01 17:04:49 (1 row)
timeofday()
Description: current date and time (like clock_timestamp, but returned as text)
Return type: text
Example:
postgres=# SELECT timeofday(); timeofday ------------------------------------- Fri Sep 01 17:05:01.167506 2017 CST (1 row)
transaction_timestamp()
Description: current date and time (equivalent to current_timestamp)
Return type: timestamp with time zone
Example:
postgres=# SELECT transaction_timestamp(); transaction_timestamp ------------------------------- 2017-09-01 17:05:13.534454+08 (1 row)
add_months(d,n)
Description: Returns the date date plus integer months.
Return type: timestamp
Example:
postgres=# SELECT add_months(to_date('2017-5-29', 'yyyy-mm-dd'), 11) FROM dual; add_months --------------------- 2018-04-29 00:00:00 (1 row)
last_day(d)
Description: Returns the date of the last day of the month that contains date.
Return type: timestamp
Example:
postgres=# select last_day(to_date('2017-01-01', 'YYYY-MM-DD')) AS cal_result; cal_result --------------------- 2017-01-31 00:00:00 (1 row)
next_day(x,y)
Description: Returns the time of the next week y started from x
Return type: timestamp
Example:
postgres=# select next_day(timestamp '2017-05-25 00:00:00','Sunday')AS cal_result; cal_result --------------------- 2017-05-28 00:00:00 (1 row)
TIMESTAMPDIFF
TIMESTAMPDIFF(unit , timestamp_expr1, timestamp_expr2)
The timestampdiff function returns the result of timestamp_expr2 - timestamp_expr1 in the specified unit. timestamp_expr1 and timestamp_expr2 must be value expressions of the timestamp, timestamptz, or date type. unit indicates the unit of the difference between two dates.
NOTE:
This function is valid only when openGauss is compatible with the MY type (that is, dbcompatibility = 'B').
year
Year.
postgres=# SELECT TIMESTAMPDIFF(YEAR, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 2 (1 row)
quarter
Quarter.
postgres=# SELECT TIMESTAMPDIFF(QUARTER, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 8 (1 row)
month
Month.
postgres=# SELECT TIMESTAMPDIFF(MONTH, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 24 (1 row)
week
Week.
postgres=# SELECT TIMESTAMPDIFF(WEEK, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 104 (1 row)
day
Day.
postgres=# SELECT TIMESTAMPDIFF(DAY, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 730 (1 row)
hour
Hour.
postgres=# SELECT TIMESTAMPDIFF(HOUR, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 1 (1 row)
minute
Minute.
postgres=# SELECT TIMESTAMPDIFF(MINUTE, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 61 (1 row)
second
Second.
postgres=# SELECT TIMESTAMPDIFF(SECOND, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 3661 (1 row)
microseconds
The seconds column, including fractional parts, multiplied by 1,000,000.
postgres=# SELECT TIMESTAMPDIFF(MICROSECOND, '2020-01-01 10:10:10.000000', '2020-01-01 10:10:10.111111'); timestamp_diff ---------------- 111111 (1 row)
EXTRACT
EXTRACT(_field _FROM source)
The extract function retrieves subcolumns such as year or hour from date/time values. source must be a value expression of type timestamp, time, or interval. (Expressions of type date are cast to timestamp and can therefore be used as well.) field is an identifier or string that selects what column to extract from the source value. The extract function returns values of type double precision. The following are valid field names:
century
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 century to 1 century.
Example:
postgres=# SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13'); date_part ----------- 20 (1 row)
day
For timestamp values, the day (of the month) column (1–31)
postgres=# SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 16 (1 row)
For interval values, the number of days
postgres=# SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute'); date_part ----------- 40 (1 row)
decade
Year column divided by 10
postgres=# SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 200 (1 row)
dow
Day of the week as Sunday(0) to Saturday (6)
postgres=# SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 5 (1 row)
doy
Day of the year (1–365 or 366)
postgres=# SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 47 (1 row)
epoch
For timestamp with time zone values, the number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
for date and timestamp values, the number of seconds since 1970-01-01 00:00:00 local time;
for interval values, the total number of seconds in the interval.
postgres=# SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08'); date_part -------------- 982384720.12 (1 row)
postgres=# SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours'); date_part ----------- 442800 (1 row)
Way to convert an epoch value back to a timestamp
postgres=# SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second' AS RESULT; result --------------------------- 2001-02-17 12:38:40.12+08 (1 row)
hour
Hour column (0–23)
postgres=# SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
isodow
Day of the week (1–7)
Monday is 1 and Sunday is 7.
NOTE:
This is identical to dow except for Sunday.postgres=# SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40'); date_part ----------- 7 (1 row)
isoyear
The ISO 8601 year that the date falls in (not applicable to intervals).
Each ISO year begins with the Monday of the week containing January 4, so in early January or late December the ISO year may be different from the Gregorian year. See the week column for more information.
postgres=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01'); date_part ----------- 2005 (1 row)
postgres=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02'); date_part ----------- 2006 (1 row)
microseconds
The seconds column, including fractional parts, multiplied by 1,000,000
postgres=# SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5'); date_part ----------- 28500000 (1 row)
millennium
Years in the 1900s are in the second millennium. The third millennium started from January 1, 2001.
postgres=# SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 3 (1 row)
milliseconds
The seconds column, including fractional parts, multiplied by 1000. Note that this includes full seconds.
postgres=# SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5'); date_part ----------- 28500 (1 row)
minute
Minutes column (0–59)
postgres=# SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 38 (1 row)
month
For timestamp values, the number of the month within the year (1–12);
postgres=# SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 2 (1 row)
For interval values, the number of months, modulo 12 (0–11)
postgres=# SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months'); date_part ----------- 1 (1 row)
quarter
Quarter of the year (1–4) that the date is in
postgres=# SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 1 (1 row)
second
Seconds column, including fractional parts (0–59)
postgres=# SELECT EXTRACT(SECOND FROM TIME '17:12:28.5'); date_part ----------- 28.5 (1 row)
timezone
The time zone offset from UTC, measured 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 year that the day is in. By definition (ISO 8601), the first week of a year contains January 4 of that year. (The ISO-8601 week starts on Monday.) In other words, the first Thursday of a year is in week 1 of that year.
Because of this, it is possible for early January dates to be part of the 52nd or 53rd week of the previous year, and late December dates to be part of the 1st week of the next year. For example, 2005-01-01 is part of the 53rd week of year 2004, 2006-01-01 is part of the 52nd week of year 2005, and 2012-12-31 is part of the 1st week of year 2013. You are advised to use the columns isoyear and week together to ensure consistency.
postgres=# SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 7 (1 row)
year
Year column
postgres=# SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 2001 (1 row)
date_part
The date_part function is modeled on the traditional Ingres equivalent to the SQL-standard function extract:
date_part('field', source)
Note that here the field parameter needs to be a string value, not a name. The valid field names for field are the same as for extract. For details, see EXTRACT.
Example:
postgres=# SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
date_part
-----------
16
(1 row)
postgres=# SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
date_part
-----------
4
(1 row)
Table 2 specifies the schema for formatting date and time values.
Table 2 Schema for formatting date and time
NOTE:
In the table, the rules for RR to calculate years are as follows:
- If the range of the input two-digit year is between 00 and 49:
If the last two digits of the current year are between 00 and 49, the first two digits of the returned year are the same as the first two digits of the current year.
If the last two digits of the current year are between 50 and 99, the first two digits of the returned year equal to the first two digits of the current year plus 1.- If the range of the input two-digit year is between 50 and 99:
If the last two digits of the current year are between 00 and 49, the first two digits of the returned year equal to the first two digits of the current year minus 1.
If the last two digits of the current year are between 50 and 99, the first two digits of the returned year are the same as the first two digits of the current year.