Functions for date and time
Functions for date and time are functions for working with data of types DATE
, TIME
, TIMESTAMP
and TIMESTAMPTZ
.
current_time()
Description |
Returns the current time as a value of type |
Usage |
|
Aliases |
|
See example
SELECT
current_time AS cur_time_1,
current_time() AS cur_time_2,
get_current_time() AS cur_time_3;
+-----------------+-----------------+-----------------+
| cur_time_1 | cur_time_2 | cur_time_3 |
+-----------------+-----------------+-----------------+
| 10:33:24.016000 | 10:33:24.016000 | 10:33:24.016000 |
+-----------------+-----------------+-----------------+
now()
Description |
Returns the current time as a value of type |
Usage |
|
See example
SELECT
now() AS cur_time;
+----------------------------------+
| cur_time |
+----------------------------------+
| 2025-08-26 13:38:58.461000+00:00 |
+----------------------------------+
datepart()
Description |
Returns the specified part of the date or time value as a value of type |
Usage |
|
Aliases |
|
Arguments can be values of types: TIME
, DATE
, TIMESTAMP
, or TIMESTAMPTZ
.
Parts can be specified using the following literals
-
century
-
day
-
decade
-
hour
-
microseconds
-
millennium
-
milliseconds
-
minute
-
month
-
quarter
-
second
-
year
See examples
SELECT
datepart('milliseconds', TIMESTAMP '2025-02-25 00:00:00.1') AS milliseconds,
datepart('hour', TIME '2025-02-25 00:00:00') AS hour,
datepart('millennium', DATE '2025-02-25') AS millennium;
+--------------+------+------------+
| milliseconds | hour | millennium |
+--------------+------+------------+
| 100 | 0 | 3 |
+--------------+------+------------+
date_diff()
Description |
Returns the number of time units between two points in time as a value of type |
Usage |
|
Arguments can be values of type: TIME
, DATE
, TIMESTAMP
, or TIMESTAMPTZ
.
Units can be specified using the following literals
-
century
-
day
-
decade
-
hour
-
microseconds
-
millennium
-
milliseconds
-
minute
-
month
-
quarter
-
second
-
year
See examples
SELECT
date_diff('second', TIME '01:02:03', TIME '03:02:01') AS diff_in_seconds,
date_diff('minute', TIME '01:02:03', TIME '03:02:01') AS diff_in_minutes,
date_diff('hour', TIME '01:02:03', TIME '03:02:01') AS diff_in_hours,
date_diff('day', TIMESTAMP '2025-02-25 01:02:03', TIMESTAMP '2025-02-26 03:02:01') AS diff_in_days,
date_diff('day', TIMESTAMP '2025-02-26 01:02:03', TIMESTAMP '2025-02-25 03:02:01') AS diff_in_days,
date_diff('day', DATE '2024-02-27', DATE '2025-02-27') AS diff_in_days;
+-----------------+-----------------+---------------+--------------+--------------+--------------+
| diff_in_seconds | diff_in_minutes | diff_in_hours | diff_in_days | diff_in_days | diff_in_days |
+-----------------+-----------------+---------------+--------------+--------------+--------------+
| 7198 | 120 | 2 | 1 | -1 | 366 |
+-----------------+-----------------+---------------+--------------+--------------+--------------+
date_trunc()
Description |
Reduces a moment in time to the specified precision. |
Usage |
|
Reduces the TIMESTAMP
time moment to the specified precision unit and returns the initial time moment for that unit as a value of type TIMESTAMP
or DATE
.
Some usage examples are described in this script.
Units can be specified using the following literals
-
century
-
day
-
decade
-
hour
-
microseconds
-
millennium
-
milliseconds
-
minute
-
month
-
quarter
-
second
-
year
See examples
SELECT
date_trunc('minute', TIMESTAMP '2025-02-25 01:02:03') AS minute,
date_trunc('hour', TIMESTAMP '2025-02-25 01:02:03') AS hour,
date_trunc('day', TIMESTAMP '2025-02-25 01:02:03') AS day,
date_trunc('month', TIMESTAMP '2025-02-25 01:02:03') AS month,
date_trunc('quarter', TIMESTAMP '2025-02-25 01:02:03') AS quarter,
date_trunc('year', TIMESTAMP '2025-02-25 01:02:03') AS year;
+---------------------+---------------------+------------+------------+------------+------------+
| minute | hour | day | month | quarter | year |
+---------------------+---------------------+------------+------------+------------+------------+
| 2025-02-25 01:02:00 | 2025-02-25 01:00:00 | 2025-02-25 | 2025-02-01 | 2025-01-01 | 2025-01-01 |
+---------------------+---------------------+------------+------------+------------+------------+
strptime()
Description |
Converts text to a point in time using the specified format. |
Usage |
|
Converts text to the point in time TIMESTAMP
using the specified format. If the conversion fails, it generates an error.
Some usage examples are described in this script.
Format can be specified using the following expressions
Expression | Description | Example |
---|---|---|
|
Abbreviated weekday name. |
Sun, Mon, … |
|
Full weekday name. |
Sunday, Monday, … |
|
Abbreviated month name. |
Jan, Feb, …, Dec |
|
Full month name. |
January, February, … |
|
ISO date and time representation |
1992-03-02 10:30:20 |
|
Day of the month as a zero-padded decimal. |
01, 02, …, 31 |
|
Day of the month as a decimal number. |
1, 2, …, 30 |
|
Microsecond as a decimal number, zero-padded on the left. |
000000 - 999999 |
|
Millisecond as a decimal number, zero-padded on the left. |
000 - 999 |
|
ISO 8601 year with century representing the year that contains the greater part of the ISO week (see |
0001, 0002, …, 2013, 2014, …, 9998, 9999 |
|
Hour (24-hour clock) as a zero-padded decimal number. |
00, 01, …, 23 |
|
Hour (24-hour clock) as a decimal number. |
0, 1, …, 23 |
|
Hour (12-hour clock) as a zero-padded decimal number. |
01, 02, …, 12 |
|
Hour (12-hour clock) as a decimal number. |
1, 2, … 12 |
|
Day of the year as a zero-padded decimal number. |
001, 002, …, 366 |
|
Day of the year as a decimal number. |
1, 2, …, 366 |
|
Month as a zero-padded decimal number. |
01, 02, …, 12 |
|
Month as a decimal number. |
1, 2, …, 12 |
|
Minute as a zero-padded decimal number. |
00, 01, …, 59 |
|
Minute as a decimal number. |
0, 1, …, 59 |
|
Nanosecond as a decimal number, zero-padded on the left. |
000000000 - 999999999 |
|
Locale’s AM or PM. |
AM, PM |
|
Second as a zero-padded decimal number. |
00, 01, …, 59 |
|
Second as a decimal number. |
0, 1, …, 59 |
|
ISO 8601 weekday as a decimal number where 1 is Monday. |
1, 2, …, 7 |
|
Week number of the year. Week 01 starts on the first Sunday of the year, so there can be week 00. Note that this is not compliant with the week date standard in ISO-8601. |
00, 01, …, 53 |
|
ISO 8601 week as a decimal number with Monday as the first day of the week. Week 01 is the week containing Jan 4. Note that |
01, …, 53 |
|
Weekday as a decimal number. |
0, 1, …, 6 |
|
Week number of the year. Week 01 starts on the first Monday of the year, so there can be week 00. Note that this is not compliant with the week date standard in ISO-8601. |
00, 01, …, 53 |
|
ISO date representation |
1992-03-02 |
|
ISO time representation |
10:30:20 |
|
Year without century as a zero-padded decimal number. |
00, 01, …, 99 |
|
Year without century as a decimal number. |
0, 1, …, 99 |
|
Year with century as a decimal number. |
2013, 2019 etc. |
|
Time offset from UTC in the form ±HH:MM, ±HHMM, or ±HH. |
-0700 |
|
Time zone name. |
Europe/Amsterdam |
|
A literal |
% |
See examples
SELECT
strptime('Feb 25, 2025, 01:02:03 AM', '%b %d, %Y, %H:%M:%S %p') AS timestamp_1,
strptime('2025-02-25, 01:02:03', '%x, %X') AS timestamp_2,
strptime('01:02, 01.02.99', '%H:%M, %d.%m.%y') AS timestamp_3,
strptime('01:02%PM--01.02.99', '%H:%M%%%p--%d.%m.%y') AS timestamp_4,
strptime('1:1, 1.1.1', '%-H:%-M, %-d.%-m.%-y') AS timestamp_5,
strptime('1', '%Y') AS timestamp_6;
+---------------------+---------------------+---------------------+---------------------+---------------------+---------------------+
| timestamp_1 | timestamp_2 | timestamp_3 | timestamp_4 | timestamp_5 | timestamp_6 |
+---------------------+---------------------+---------------------+---------------------+---------------------+---------------------+
| 2025-02-25 01:02:03 | 2025-02-25 01:02:03 | 1999-02-01 01:02:00 | 1999-02-01 13:02:00 | 2001-01-01 01:01:00 | 0001-01-01 00:00:00 |
+---------------------+---------------------+---------------------+---------------------+---------------------+---------------------+
Operator +
Description |
Adds the right argument to the left argument. |
Usage |
|
If used with types for for date and time, adds the interval to the time value. Returns a value of type TIME
.
See also add()
.
See examples
SELECT
3 + 2 AS result_1,
3 + 2 + -1 AS result_2,
1.1 + 1.9 AS result_3;
+----------+----------+----------+
| result_1 | result_2 | result_3 |
+----------+----------+----------+
| 5 | 4 | 3.0 |
+----------+----------+----------+
SELECT
TIME '12:11:10' + INTERVAL 3 hours AS result_time_1,
INTERVAL '12:11:10' + TIME '1:1:1' AS result_time_2;
+---------------+---------------+
| result_time_1 | result_time_2 |
+---------------+---------------+
| 15:11:10 | 13:12:11 |
+---------------+---------------+
Operator -
Description |
Subtracts the right argument from the left argument. |
Usage |
|
If used with types for for date and time, subtracts the interval from the time value. Returns a value of type TIME
.
See also subtract()
.
See examples
SELECT
3 - 2 AS result_1,
3 - 2 - +1 AS result_2,
1.2 - 0.2 AS result_3;
+----------+----------+----------+
| result_1 | result_2 | result_3 |
+----------+----------+----------+
| 1 | 0 | 1.0 |
+----------+----------+----------+
SELECT
TIME '12:11:10' - INTERVAL 3 HOUR AS result_time_1,
TIME '12:11:10' - INTERVAL 3 HOUR - INTERVAL 1 HOUR AS result_time_2;
+---------------+---------------+
| result_time_1 | result_time_2 |
+---------------+---------------+
| 09:11:10 | 08:11:10 |
+---------------+---------------+