Date and Time Processing Functions and Operators
Date and Time Operators
For details about the time and date operators, see Table 1.
When the user uses date and 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.
1
|
SELECT date '2001-10-01' - '7' AS RESULT; |
Operator |
Example |
||
---|---|---|---|
+ |
NOTE:
|
||
|
|||
|
|||
|
|||
|
|||
|
|||
- |
|
||
|
|||
|
|||
|
|||
|
|||
|
|||
|
|||
|
|||
* |
|
||
|
|||
|
|||
/ |
|
Time and Date Functions
- age(timestamp, timestamp)
Description: Subtracts parameters, producing a result in YYYY-MM-DD format. If the result is negative, the returned result is also negative. The input parameters can contain timezone or not.
Return type: interval
Example:
1 2 3 4 5
gaussdb=# SELECT age(timestamp '2001-04-10', timestamp '1957-06-13'); age ------------------------- 43 years 9 mons 27 days (1 row)
- age(timestamp)
Description: Subtracts the parameter value from the system time when the current SQL statement starts to be executed. The input parameter may or may not contain a time zone.
Return type: interval
Example:
1 2 3 4 5
gaussdb=# SELECT age(timestamp '1957-06-13'); age ------------------------- 60 years 2 mons 18 days (1 row)
- clock_timestamp()
Description: Returns the timestamp of the system time when the current function is called. The volatile function obtains the latest timestamp for each scan. Therefore, the result of each call in a query is different.
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT clock_timestamp(); clock_timestamp ------------------------------- 2017-09-01 16:57:36.636205+08 (1 row)
- current_date
Description: Returns the system date when the current SQL statement starts.
Return type: date
Example:
1 2 3 4 5
gaussdb=# SELECT current_date; date ------------ 2017-09-01 (1 row)
When a_format_version is set to 10c and a_format_dev_version is set to s2 in an ORA-compatible database, the return value type is timestamp.
- current_time
Description: Specifies the system time when the current transaction starts.
Return type: time with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT current_time; timetz -------------------- 16:58:07.086215+08 (1 row)
- current_timestamp
Description: Returns the system time when the current SQL execution starts. This is a statement-level timestamp. The returned results within the same statement remain unchanged.
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT current_timestamp; pg_systimestamp ------------------------------ 2017-09-01 16:58:19.22173+08 (1 row)
- current_timestamp(precision)
Description: Returns the system time when the current SQL statement is started, and rounds the microseconds of the result to the specified decimal places.
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT current_timestamp(1); timestamptz ------------------------------ 2017-09-01 16:58:19.2+08 (1 row)
- When a_format_version is set to 10c and a_format_dev_version is set to s2 in an ORA-compatible database, the precision parameter can be an integer of the numeric type. Otherwise, only the int type is supported.
- Zeros at the end of microseconds are not displayed. For example, 2017-09-01 10:32:19.212000 is displayed as 2017-09-01 10:32:19.212.
- pg_systimestamp()
Description: Current date and time (start of the current statement).
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT pg_systimestamp(); pg_systimestamp ------------------------------- 2015-10-14 11:21:28.317367+08 (1 row)
- date_part(text, timestamp)
Retrieves fields such as year or hour from date/time values.
It is equivalent to extract(field from timestamp).
Timestamp types: abstime, date, interval, reltime, time with time zone, time without time zone, timestamp with time zone, timestamp without time zone
Return type: double precision
Example:
1 2 3 4 5
gaussdb=# SELECT date_part('hour', timestamp '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
- date_part(text, interval)
Description: Obtains the month. If the value is greater than 12, obtain the remainder after it is divided by 12. It is equivalent to extract(field from timestamp).
Return type: double precision
Example:
1 2 3 4 5
gaussdb=# 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: interval, timestamp with time zone, timestamp without time zone
Example:
1 2 3 4 5
gaussdb=# SELECT date_trunc('hour', timestamp '2001-02-16 20:38:40'); date_trunc --------------------- 2001-02-16 20:00:00 (1 row)
- trunc(timestamp)
Description: Truncates to day by default.
Example:
1 2 3 4
gaussdb=# SELECT trunc(timestamp '2001-02-16 20:38:40'); trunc --------------------- 2001-02-16 00:00:00 (1 row)
- trunc(arg1, arg2)
Description: Truncates to the precision specified by arg2.
- Type of arg1: interval, timestamp with time zone, timestamp without time zone
- Type of arg2: text
Return type: interval, timestamp with time zone, timestamp without time zone
Example:
1 2 3 4
gaussdb=# SELECT trunc(timestamp '2001-02-16 20:38:40', 'hour'); trunc --------------------- 2001-02-16 20:00:00 (1 row)
- round(arg1, arg2)
Description: Rounds off to the precision specified by arg2.
Type of arg1: timestamp without time zone
Type of arg2: text
Return type: timestamp without time zone
Example:
1 2 3 4
gaussdb=# SELECT round(timestamp '2001-02-16 20:38:40', 'hour'); round --------------------- 2001-02-16 21:00:00 (1 row)
This function is valid only when the value of a_format_version is 10c and that of a_format_dev_version is s1 in an ORA-compatible database.
- daterange(arg1, arg2)
Description: Obtains time boundary information.
arg1 type: date
arg2 type: date
Return type: daterange
Example:
1 2 3 4 5
gaussdb=# select daterange('2000-05-06','2000-08-08'); daterange ------------------------- [2000-05-06,2000-08-08) (1 row)
- daterange(arg1, arg2, text)
Description: Obtains time boundary information.
arg1 type: date
arg2 type: date
text type: text
Return type: daterange
Example:
1 2 3 4 5
gaussdb=# select daterange('2000-05-06','2000-08-08','[]'); daterange ------------------------- [2000-05-06,2000-08-09) (1 row)
- extract(field from timestamp)
Description: Obtains the hour.
Return type: double precision
Example:
1 2 3 4 5
gaussdb=# 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:
1 2 3 4 5
gaussdb=# SELECT extract(month from interval '2 years 3 months'); date_part ----------- 3 (1 row)
- isfinite(date)
Description: Checks whether a date is a finite value. If yes, t is returned. Otherwise, f is returned.
Return type: Boolean
Example:
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT isfinite(date '2001-02-16'); isfinite ---------- t (1 row) gaussdb=# SELECT isfinite(date 'infinity'); isfinite ---------- f (1 row)
- isfinite(timestamp)
Description: Checks whether a timestamp is a finite value. If yes, t is returned. Otherwise, f is returned.
Return type: Boolean
Example:
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT isfinite(timestamp '2001-02-16 21:28:30'); isfinite ---------- t (1 row) gaussdb=# SELECT isfinite(timestamp 'infinity'); isfinite ---------- f (1 row)
- isfinite(interval)
Description: Checks whether the interval is a finite value. If yes, t is returned. Currently, f cannot be returned. If 'infinity' is entered, an error is reported.
Return type: Boolean
Example:
1 2 3 4 5
gaussdb=# SELECT isfinite(interval '4 hours'); isfinite ---------- t (1 row)
- justify_days(interval)
Description: Adjusts intervals to 30-day time periods, which are represented as months.
Return type: interval
Example:
1 2 3 4 5
gaussdb=# 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:
1 2 3 4 5
gaussdb=# 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:
1 2 3 4 5
gaussdb=# SELECT JUSTIFY_INTERVAL(INTERVAL '1 MON -1 HOUR'); justify_interval ------------------ 29 days 23:00:00 (1 row)
- localtime
Description: Specifies the system time when the current transaction starts.
Return type: time
Example:
1 2 3 4 5
gaussdb=# SELECT localtime AS RESULT; result ---------------- 16:05:55.664681 (1 row)
- localtimestamp
Description: Returns the system date and time when the current SQL query execution starts.
Return type: timestamp
Example:
1 2 3 4 5
gaussdb=# SELECT localtimestamp; timestamp ---------------------------- 2017-09-01 17:03:30.781902 (1 row)
- now()
Description: Returns the system date and time when the current transaction starts. The results returned in the same transaction are the same.
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT now(); now ------------------------------- 2017-09-01 17:03:42.549426+08 (1 row)
- timenow()
Description: Returns the system date and time when the current SQL query execution starts.
Return type: abstime
Example:
1 2 3 4 5
gaussdb=# select timenow(); timenow ------------------------ 2020-06-23 20:36:56+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 GUC parameter IntervalStyle to ORA to be compatible with the interval output format of the function in the Oracle database.
Return type: interval
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13
gaussdb=# SELECT numtodsinterval(100, 'HOUR'); numtodsinterval ----------------- 100:00:00 (1 row) gaussdb=# SET intervalstyle = oracle; SET gaussdb=# SELECT numtodsinterval(100, 'HOUR'); numtodsinterval ------------------------------- +000000004 04:00:00.000000000 (1 row)
When a_format_version is set to 10c and a_format_dev_version is set to s2 in an ORA-compatible database, an error is reported if interval_unit is set to 'DAY' and num is set to a value greater than 1000000000.
- numtoyminterval(num, interval_unit)
Description: Converts a number to the interval type. num is a number of the numeric type, and interval_unit is a string of the fixed format ('YEAR'|'MONTH').
You can set the GUC parameter IntervalStyle to ORA to be compatible with the interval output format in the Oracle database.
Return type: interval
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13
gaussdb=# SELECT numtoyminterval(100, 'MONTH'); numtoyminterval ----------------- 8 years 4 mons (1 row) gaussdb=# SET intervalstyle = oracle; SET gaussdb=# SELECT numtodsinterval(100, 'MONTH'); numtoyminterval ----------------- 8-4 (1 row)
This function is valid only when the value of a_format_version is 10c and the value of a_format_dev_version is s2 in an ORA-compatible database.
- new_time(date, timezone1,timezone2)
Description: Returns the date and time of the time zone specified by timezone2 when the date and time of the time zone specified by timezone1 are date.
Return type: timestamp
Example:
1 2 3 4 5 6 7 8 9 10
gaussdb=# select new_time('1997-10-10','AST','EST'); new_time --------------------- 1997-10-09 23:00:00 (1 row) gaussdb=# SELECT NEW_TIME(TO_TIMESTAMP ('10-Sep-02 14:10:10.123000','DD-Mon-RR HH24:MI:SS.FF'), 'AST', 'PST'); new_time ------------------------- 2002-09-10 10:10:10.123 (1 row)
This function is valid only when the value of a_format_version is 10c and the value of a_format_dev_version is s2 in an ORA-compatible database.
- sessiontimezone
Description: Returns the time zone of the current session. There is no input parameter.
Return type: text
Example:
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT SESSIONTIMEZONE; session_time_zone ------------------- PST8PDT (1 row) gaussdb=# SELECT LOWER(SESSIONTIMEZONE); lower ----------- @ 8 hours (1 row)
This function is valid only when the value of a_format_version is 10c and the value of a_format_dev_version is s2 in an ORA-compatible database.
When the value of set session time zone is in the GMT+08:00/GMT-08:00 format, the verification fails and an error is reported. This behavior meets the expectation. If the value is 's2' and the "ERROR:invalid value for parameter "TimeZone" :"GMT-08:00"" error is reported when you use JDBC to create a connection, the application where the driver is located sends the same time zone parameter in GMT format to GaussDB. You can use either of the following methods to solve the problem:
Method 1: Adjust the time zone of the OS on the application side and set the local time zone to the region format, for example, Asia/Shanghai.
Method 2: Use the JDBC driver that matches the version on the application side. The JDBC driver changes the GMT time zone to a time zone format that can be identified by the database.
- sys_extract_utc(timestamp| timestamptz)
Description: Extracts Coordinated Universal Time (UTC, also formerly known as Greenwich Mean Time) from a date-time value with a time zone offset or time zone region name. If no time zone is specified, the date and time are associated with the session time zone. The input parameter can be in timestmp or timestamp format.
Return type: timestamp
Example:
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT SYS_EXTRACT_UTC(TIMESTAMP '2000-03-28 11:30:00.00'); sys_extract_utc --------------------- 2000-03-28 03:30:00 (1 row) gaussdb=# SELECT SYS_EXTRACT_UTC(TIMESTAMPTZ '2000-03-28 11:30:00.00 -08:00'); sys_extract_utc --------------------- 2000-03-28 19:30:00 (1 row)
This function is valid only when the value of a_format_version is 10c and the value of a_format_dev_version is s2 in an ORA-compatible database.
- tz_offset('time_zone_name' | '(+/-)hh:mi' | SESSIONTIMEZONE | DBTIMEZONE)
Description: Returns the UTC offset of the time zone indicated by the input parameter. The input parameter has the preceding four formats.
Return type: text
Example:
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT TZ_OFFSET('US/Pacific'); tz_offset ----------- -08:00 (1 row) gaussdb=# SELECT TZ_OFFSET(sessiontimezone); tz_offset ----------- +08:00 (1 row)
This function is valid only when the value of a_format_version is 10c and the value of a_format_dev_version is s2 in an ORA-compatible database.
- pg_sleep(seconds)
Description: Specifies the delay time of the server thread in unit of second. Note that when the database calls this function, the corresponding transaction snapshot is obtained, which is equivalent to a long transaction. If the input parameter time is too long, the database oldestxmin may fail to be executed, affecting the table recycling and query performance.
Return type: void
Example:
1 2 3 4 5
gaussdb=# SELECT pg_sleep(10); pg_sleep ---------- (1 row)
- statement_timestamp()
Description: Current date and time (start of the current statement).
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# SELECT statement_timestamp(); statement_timestamp ------------------------------- 2017-09-01 17:04:39.119267+08 (1 row)
- sysdate
Description: Returns the system date and time when the current SQL statement is executed.
Return type: timestamp
Example:
1 2 3 4 5
gaussdb=# SELECT sysdate; sysdate --------------------- 2017-09-01 17:04:49 (1 row)
- current_sysdate
Description: Returns the system date and time when the current SQL query execution starts.
Return type: timestamp
Example:
1 2 3 4 5
gaussdb=# SELECT current_sysdate(); current_sysdate --------------------- 2023-06-20 20:09:02 (1 row)
- timeofday()
Description: Returns the timestamp (such as clock_timestamp, but the return type is text) of the system time when the current function is called.
Return type: text
Example:
1 2 3 4 5
gaussdb=# SELECT timeofday(); timeofday ------------------------------------- Fri Sep 01 17:05:01.167506 2017 CST (1 row)
- transaction_timestamp()
Description: Specifies the system date and time when the current transaction starts.
Return type: timestamp with time zone
Example:
1 2 3 4 5
gaussdb=# 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.
d: indicates the value of the timestamp type and the value that can be implicitly converted to the timestamp type.
n: indicates the value of the INTEGER type and the value that can be implicitly converted to the INTEGER type.
Return type: timestamp
Example:
1 2 3 4 5
gaussdb=# SELECT add_months(to_date('2017-5-29', 'yyyy-mm-dd'), 11) FROM sys_dummy; add_months --------------------- 2018-04-29 00:00:00 (1 row)
In the scenario where this function is in an ORA-compatible database, the value of a_format_version is 10c, and that of a_format_dev_version is s1:- If the calculation result is greater than 9999, an error is reported.
- If the value of n is a decimal, the value is truncated instead of being rounded off.
- last_day(d)
Description: Returns the date of the last day of the month that contains date.
Return type: timestamp
Example:
1 2 3 4 5
gaussdb=# SELECT last_day(to_date('2017-01-01', 'YYYY-MM-DD')) AS cal_result; cal_result --------------------- 2017-01-31 00:00:00 (1 row)
- months_between(d1, d2)
Description: Calculates the month difference between time points d1 and d2. If both dates are the end of a month or are the same day, an integer is returned. Otherwise, the return value is a decimal and is calculated as 31 days per month.
Return type: numeric
Example:
gaussdb=# SELECT months_between(to_date('2022-10-31', 'yyyy-mm-dd'), to_date('2022-09-30', 'yyyy-mm-dd')); months_between ---------------- 1 (1 row) gaussdb=# SELECT months_between(to_date('2022-10-30', 'yyyy-mm-dd'), to_date('2022-09-30', 'yyyy-mm-dd')); months_between ---------------- 1 (1 row) gaussdb=# SELECT months_between(to_date('2022-10-29', 'yyyy-mm-dd'), to_date('2022-09-30', 'yyyy-mm-dd')); months_between ----------------------- .96774193548387096774 (1 row)
This function is valid only when the value of a_format_version is 10c and that of a_format_dev_version is s1 in an ORA-compatible database.
- next_day(x,y)
Description: Calculates the time of the next week y started from x.
Return type: timestamp
Example:
1 2 3 4 5
gaussdb=# SELECT next_day(timestamp '2017-05-25 00:00:00','Sunday')AS cal_result; cal_result --------------------- 2017-05-28 00:00:00 (1 row)
- tinterval(abstime, abstime)
Description: Creates a time interval with two pieces of absolute time.
Return type: tinterval
Example:
1 2 3 4 5
gaussdb=# call tinterval(abstime 'May 10, 1947 23:59:12', abstime 'Mon May 1 00:30:30 1995'); tinterval ----------------------------------------------------- ["1947-05-10 23:59:12+08" "1995-05-01 00:30:30+08"] (1 row)
- tintervalend(tinterval)
Description: Returns the end time of tinterval.
Return type: abstime
Example:
1 2 3 4 5
gaussdb=# SELECT tintervalend('["Sep 4, 1983 23:59:12" "Oct4, 1983 23:59:12"]'); tintervalend ------------------------ 1983-10-04 23:59:12+08 (1 row)
-
Description: Calculates and returns the relative time of tinterval.
Return type: reltime
Example:
1 2 3 4 5
gaussdb=# SELECT tintervalrel('["Sep 4, 1983 23:59:12" "Oct4, 1983 23:59:12"]'); tintervalrel -------------- 1 mon (1 row)
- smalldatetime_ge
Description: Determines whether the first parameter is greater than the second.
Parameter: smalldatetime, smalldatetime
Return type: Boolean
- smalldatetime_cmp
Description: Compares two smalldatetime values to check whether they are the same.
Parameter: smalldatetime, smalldatetime
Return type: integer
- smalldatetime_eq
Description: Compares two smalldatetime values to check whether they are the same.
Parameter: smalldatetime, smalldatetime
Return type: Boolean
- smalldatetime_gt
Description: Determines whether the first parameter is less than the second parameter.
Parameter: smalldatetime, smalldatetime
Return type: Boolean
- smalldatetime_hash
Description: Calculates the hash value corresponding to a timestamp.
Parameter: smalldatetime
Return type: integer
- smalldatetime_in
Description: Inputs a timestamp.
Parameter: cstring, oid, integer
Return type: smalldatetime
- smalldatetime_larger
Description: Returns a larger timestamp.
Parameter: smalldatetime, smalldatetime
Return type: smalldatetime
- smalldatetime_le
Description: Determines whether the first parameter is less than the second parameter.
Parameter: smalldatetime, smalldatetime
Return type: Boolean
- smalldatetime_lt
Description: Determines whether the first parameter is greater than the second.
Parameter: smalldatetime, smalldatetime
Return type: Boolean
- smalldatetime_ne
Description: Compares two timestamps to check whether they are different.
Parameter: smalldatetime, smalldatetime
Return type: Boolean
- smalldatetime_out
Description: Converts a timestamp into the external form.
Parameter: smalldatetime
Return type: cstring
- smalldatetime_send
Description: Converts a timestamp to the binary format.
Parameter: smalldatetime
Return type: bytea
- smalldatetime_smaller
Description: Returns a smaller smalldatetime.
Parameter: smalldatetime, smalldatetime
Return type: smalldatetime
- smalldatetime_to_abstime
Description: Converts smalldatetime to abstime.
Parameter: smalldatetime
Return type: abstime
- smalldatetime_to_time
Description: Converts smalldatetime to time.
Parameter: smalldatetime
Return type: time without time zone
- smalldatetime_to_timestamp
Description: Converts smalldatetime to timestamp.
Parameter: smalldatetime
Return type: timestamp without time zone
- smalldatetime_to_timestamptz
Description: Converts smalldatetime to timestamptz.
Parameter: smalldatetime
Return type: timestamp with time zone
- smalldatetime_to_varchar2
Description: Converts smalldatetime to varchar2.
Parameter: smalldatetime
Return type: character varying
There are multiple methods for obtaining the current time. Select an appropriate API based on the actual service scenario.
- The following APIs return values based on the start time of the current transaction:
CURRENT_DATE CURRENT_TIME CURRENT_TIME(precision) CURRENT_TIMESTAMP(precision) LOCALTIME LOCALTIMESTAMP LOCALTIME(precision) LOCALTIMESTAMP(precision) transaction_timestamp() now()
The values transferred by CURRENT_TIME and CURRENT_TIMESTAMP(precision) contain time zone information. The values transferred by LOCALTIME and LOCALTIMESTAMP do not contain time zone information. CURRENT_TIME, LOCALTIME, and LOCALTIMESTAMP can specify a precision parameter, which rounds the seconds field of the result to the decimal place. If there is no precision parameter, the result is given the full precision that can be obtained.
Because these functions all return results by the start time of the current transaction, their values do not change throughout the transaction. We think this is a feature with the purpose to allow a transaction to have a consistent concept at the "current" time, so that multiple modifications in the same transaction can maintain the same timestamp.
transaction_timestamp() is equivalent to CURRENT_TIMESTAMP(precision), indicating the start time of the transaction where the current statement is located. now() is equivalent to transaction_timestamp().
- The following APIs return the start time of the current statement:
statement_timestamp()
statement_timestamp() returns the start time of the current statement (more accurately, the time when the last instruction is received from the client). The return values of statement_timestamp() and transaction_timestamp() are the same during the execution of the first instruction of a transaction, but may be different in subsequent instructions.
- The following APIs return the actual current time when the function is called:
clock_timestamp() timeofday()
clock_timestamp() returns the actual current time, and its value changes even in the same SQL command. Similar to clock_timestamp(), timeofday() also returns the actual current time. However, the result of timeofday() is a formatted text string instead of a timestamp with time zone information.
- The following APIs return values based on the start time of the current transaction:
Table 2 shows the templates for truncating date/time values.
Item |
Format |
Description |
---|---|---|
Microsecond |
MICROSECON |
Truncates date/time values, accurate to the microsecond (000000–999999). |
US |
||
USEC |
||
USECOND |
||
Millisecond |
MILLISECON |
Truncates date/time values, accurate to the millisecond (000–999). |
MS |
||
MSEC |
||
MSECOND |
||
Second |
S |
Truncates date/time values, accurate to the second (00–59). |
SEC |
||
SECOND |
||
Minute |
M |
Truncates date/time values, accurate to the minute (00–59). |
MI |
||
MIN |
||
MINUTE |
||
Hour |
H |
Truncates date/time values, accurate to the hour (00–23). |
HH |
||
HOUR |
||
HR |
||
Day |
D |
Truncates date/time values, accurate to the day (01-01 to 12–31) |
DAY |
||
DD |
||
DDD |
||
J |
||
Week |
W |
Truncates date/time values, accurate to the week (the first day of the current week). |
WEEK |
||
Month |
MM |
Truncates date/time values, accurate to the month (the first day of the current month). |
MON |
||
MONTH |
||
Quarter |
Q |
Truncates date/time values, accurate to the quarter (the first day of the current quarter). |
QTR |
||
QUARTER |
||
Year |
Y |
Truncates date/time values, accurate to the year (the first day of the current year). |
YEAR |
||
YR |
||
YYYY |
||
Decade |
DEC |
Truncates date/time values, accurate to the decade (the first day of the current decade). |
DECADE |
||
Century |
C |
Truncates date/time values, accurate to the century (the first day of the current century). |
CC |
||
CENT |
||
CENTURY |
||
Millennium |
MIL |
Truncates date/time values, accurate to the millennium (the first day of the current millennium). |
MILLENNIA |
||
MILLENNIUM |
Item |
Format |
Description |
---|---|---|
Minute |
M |
Truncated or rounded off, accurate to minute (00–59). |
MI |
||
MIN |
||
MINUTE |
||
Hour |
H |
Truncated or rounded off, accurate to hour (00–23). |
HH |
||
HOUR |
||
HR |
||
HH12 |
||
HH24 |
||
Day |
DD |
Truncated or rounded off, accurate to day (01-01 to 12-31). |
DDD |
||
J |
||
ISO week |
IW |
Truncated or rounded off, accurate to week (the first day of the week is Monday). |
Week |
DAY |
Truncated or rounded off, accurate to week (the first day of the week is Sunday). |
DY |
||
D |
||
Week of the month |
W |
Truncated or rounded off, accurate to week (the first day of the week is the first day of the month). |
Week of the year |
WW |
Truncated or rounded off, accurate to week (the first day of the week is the first day of the year). |
Month |
MM |
Truncated or rounded off, accurate to month (the first day of the month). |
MON |
||
MONTH |
||
RM |
||
Quarter |
Q |
Truncated or rounded off, accurate to quarter (the first day of the quarter). |
QTR |
||
QUARTER |
||
Year |
Y |
Truncated or rounded off, accurate to year (the first day of the current year). |
YEAR |
||
YR |
||
YYYY |
||
SYYYY |
||
YYY |
||
YY |
||
SYEAR |
||
Decade |
DEC |
Truncated or rounded off, accurate to decade (the first day of the current decade). |
DECADE |
||
Century |
C |
Truncated or rounded off, accurate to the century (the first day of the century). |
CC |
||
CENT |
||
CENTURY |
||
SCC |
||
Millennium |
MIL |
Truncated or rounded off, accurate to millennium (the first day of the millennium). |
MILLENNIA |
||
MILLENNIUM |
The behaviors of Table 3 are valid only when the value of a_format_version is 10c and that of a_format_dev_version is s1 in an ORA-compatible database.
- timestamp_diff(text, timestamp, timestamp)
Description: Calculates the difference between two timestamps and truncates the difference to the precision specified by text.
Return type: int64
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45
gaussdb=# SELECT timestamp_diff('year','2018-01-01','2020-04-01'); timestamp_diff ---------------- 2 (1 row) gaussdb=# SELECT timestamp_diff('month','2018-01-01','2020-04-01'); timestamp_diff ---------------- 27 (1 row) gaussdb=# SELECT timestamp_diff('quarter','2018-01-01','2020-04-01'); timestamp_diff ---------------- 9 (1 row) gaussdb=# SELECT timestamp_diff('week','2018-01-01','2020-04-01'); timestamp_diff ---------------- 117 (1 row) gaussdb=# SELECT timestamp_diff('day','2018-01-01','2020-04-01'); timestamp_diff ---------------- 821 (1 row) gaussdb=# SELECT timestamp_diff('hour','2018-01-01 10:10:10','2018-01-01 12:12:12'); timestamp_diff ---------------- 2 (1 row) gaussdb=# SELECT timestamp_diff('minute','2018-01-01 10:10:10','2018-01-01 12:12:12'); timestamp_diff ---------------- 122 (1 row) gaussdb=# SELECT timestamp_diff('second','2018-01-01 10:10:10','2018-01-01 10:12:12'); timestamp_diff ---------------- 122 (1 row) gaussdb=# SELECT timestamp_diff('microsecond','2018-01-01 10:10:10','2018-01-01 10:12:12'); timestamp_diff ---------------- 122000000 (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 specifies the unit of the difference between two dates.
This function is equivalent to timestamp_diff(text, timestamp, timestamp).
This function is valid only when GaussDB is compatible with MySQL (that is, dbcompatibility is set to 'MYSQL').
- quarter
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(QUARTER, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 8 (1 row)
- month
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(MONTH, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 24 (1 row)
- week
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(WEEK, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 104 (1 row)
- day
- hour
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(HOUR, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 1 (1 row)
- minute
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(MINUTE, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 61 (1 row)
- second
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(SECOND, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 3661 (1 row)
- microseconds
The second field, including fractional parts, is multiplied by 1,000,000.
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(MICROSECOND, '2020-01-01 10:10:10.000000', '2020-01-01 10:10:10.111111'); timestamp_diff ---------------- 111111 (1 row)
- timestamp_expr with the time zone
1 2 3 4 5
gaussdb=# SELECT TIMESTAMPDIFF(HOUR,'2020-05-01 10:10:10-01','2020-05-01 10:10:10-03'); timestamp_diff ---------------- 2 (1 row)
EXTRACT
- EXTRACT(field FROM source)
The extract function retrieves fields 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 field 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:
1 2 3 4 5
gaussdb=# 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) field (1–31)
1 2 3 4 5
gaussdb=# SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 16 (1 row)
- For interval values, the number of days
1 2 3 4 5
gaussdb=# SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute'); date_part ----------- 40 (1 row)
- For timestamp values, the day (of the month) field (1–31)
- decade
1 2 3 4 5
gaussdb=# 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)
1 2 3 4 5
gaussdb=# 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)
1 2 3 4 5
gaussdb=# 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-00 UTC (can be negative).
For date and timestamp values, the number of seconds since 1970-01-01 00:00:00-00 local time.
For interval values, the total number of seconds in the interval.
1 2 3 4 5
gaussdb=# SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08'); date_part -------------- 982384720.12 (1 row)
1 2 3 4 5
gaussdb=# SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours'); date_part ----------- 442800 (1 row)
- Way to convert an epoch value back to a timestamp
1 2 3 4 5
gaussdb=# SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second' AS RESULT; result --------------------------- 2001-02-17 12:38:40.12+08 (1 row)
- For timestamp with time zone values, the number of seconds since 1970-01-01 00:00:00-00 UTC (can be negative).
- hour
1 2 3 4 5
gaussdb=# SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
- isodow
Monday is 1 and Sunday is 7.
This is identical to dow except for Sunday.
1 2 3 4 5
gaussdb=# 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 week for more information.
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01'); date_part ----------- 2005 (1 row) gaussdb=# SELECT EXTRACT(WEEK FROM TIMESTAMP '2006-01-01 00:00:40'); date_part ----------- 52 (1 row)
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02'); date_part ----------- 2006 (1 row) gaussdb=# SELECT EXTRACT(WEEK FROM TIMESTAMP '2006-01-02 00:00:40'); date_part ----------- 1 (1 row)
- microseconds
The second field, including fractional parts, is multiplied by 1,000,000.
1 2 3 4 5
gaussdb=# 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.
1 2 3 4 5
gaussdb=# SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 3 (1 row)
- milliseconds
Second field, including fractional parts, is multiplied by 1000. Note that this includes full seconds.
1 2 3 4 5
gaussdb=# SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5'); date_part ----------- 28500 (1 row)
- minute
1 2 3 4 5
gaussdb=# SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 38 (1 row)
- month
For timestamp values, the specific month in the year (1–12).
1 2 3 4 5
gaussdb=# 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).
1 2 3 4 5
gaussdb=# 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.
1 2 3 4 5
gaussdb=# SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 1 (1 row)
- second
Second field, including fractional parts (0–59).
1 2 3 4 5
gaussdb=# SELECT EXTRACT(SECOND FROM TIME '17:12:28.5'); date_part ----------- 28.5 (1 row)
- timezone
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
- timezone_minute
- week
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, 2006-01-01 is the 52nd week of 2005, and 2006-01-02 is the first week of 2006. You are advised to use the columns isoyear and week together to ensure consistency.
1 2 3 4 5 6 7 8 9 10
gaussdb=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01'); date_part ----------- 2005 (1 row) gaussdb=# SELECT EXTRACT(WEEK FROM TIMESTAMP '2006-01-01 00:00:40'); date_part ----------- 52 (1 row)
gaussdb=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02'); date_part ----------- 2006 (1 row) gaussdb=# SELECT EXTRACT(WEEK FROM TIMESTAMP '2006-01-02 00:00:40'); date_part ----------- 1 (1 row)
- year
1 2 3 4 5
gaussdb=# 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 date_part are the same as for extract. For details, see EXTRACT.
Example:
1 2 3 4 5 |
gaussdb=# SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 16 (1 row) |
1 2 3 4 5 |
gaussdb=# SELECT date_part('hour', INTERVAL '4 hours 3 minutes'); date_part ----------- 4 (1 row) |
Table 4 specifies the schema for formatting date and time values.
Category |
Format |
Description |
---|---|---|
Hour |
HH |
Number of hours in one day (01–12) |
HH12 |
Number of hours in one day (01–12) |
|
HH24 |
Number of hours in one day (00–23) |
|
Minute |
MI |
Minute (00–59) |
Second |
SS |
Second (00–59) |
FF |
Microsecond (000000–999999) |
|
FF1 |
Microsecond (0-9) |
|
FF2 |
Microsecond (00-99) |
|
FF3 |
Microsecond (000-999) |
|
FF4 |
Microsecond (0000-9999) |
|
FF5 |
Microsecond (00000-99999) |
|
FF6 |
Microsecond (000000–999999) |
|
SSSSS |
Second after midnight (0–86399) |
|
Morning and afternoon |
AM or A.M. |
Morning identifier |
PM or P.M. |
Afternoon identifier |
|
Year |
Y,YYY |
Year with comma (with four digits or more) |
SYYYY |
Year with four digits BC |
|
YYYY |
Year (with four digits or more) |
|
YYY |
Last three digits of a year |
|
YY |
Last two digits of a year |
|
Y |
Last one digit of a year |
|
IYYY |
ISO year (with four digits or more) |
|
IYY |
Last three digits of an ISO year |
|
IY |
Last two digits of an ISO year |
|
I |
Last one digit of an ISO year |
|
RR |
Last two digits of a year (A year of the 20th century can be stored in the 21st century.) |
|
RRRR |
Capable of receiving a year with four digits or two digits. If there are 2 digits, the value is the same as the returned value of RR. If there are 4 digits, the value is the same as YYYY. |
|
|
Era indicator Before Christ (BC) and After Christ (AD) |
|
Month |
MONTH |
Full spelling of a month in uppercase (9 characters are filled in if the value is empty.) |
MON |
Month in abbreviated format in uppercase (with three characters) |
|
MM |
Month (01–12) |
|
RM |
Month in Roman numerals (I–XII; I=JAN) and uppercase |
|
Day |
DAY |
Full spelling of a date in uppercase (9 characters are filled in if the value is empty.) |
DY |
Day in abbreviated format in uppercase (with three characters) |
|
DDD |
Day in a year (001–366) |
|
DD |
Day in a month (01–31) |
|
D |
Day in a week (1–7). |
|
Week |
W |
Week in a month (1–5) (The first week starts from the first day of the month.) |
WW |
Week in a year (1–53) (The first week starts from the first day of the year.) |
|
IW |
Week in an ISO year (The first Thursday is in the first week.) |
|
Century |
CC |
Century (with two digits) (The 21st century starts from 2001-01-01.) |
Julian date |
J |
Julian date (starting from January 1 of 4712 BC) |
Quarter |
Q |
Quarter |
Item |
Format |
Description |
---|---|---|
Century |
SCC |
Century. A hyphen (-) will be displayed before BC years. |
Year |
SYYYY |
Returns a numeric year. A hyphen (-) will be displayed before BC years. |
RR |
Returns the two-digit year of a date. |
|
RRRR |
Returns the four-digit year of a date. |
|
YEAR |
Returns the year of the character type. |
|
SYEAR |
Returns the year of the character type. A hyphen (-) will be displayed before BC years. |
|
Date Format |
DL |
Returns the date in the specified long date format. |
DS |
Returns the date in the specified short date format. |
|
TS |
Returns the time in the specified time format. |
|
Second |
FF7 |
Microsecond (0000000-9999990) |
FF8 |
Microsecond (00000000-99999900) |
|
FF9 |
Microsecond (000000000-999999000) |
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 are 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.
- The to_date and to_timestamp functions support the FX pattern (the input strictly corresponds to a pattern) and the X pattern (decimal point).
- The input pattern can appear only once, indicating that the patterns of the same information cannot appear at the same time. For example, SYYYY and BC cannot be used together.
- The pattern is case insensitive.
- You are advised to use a separator between the input and the pattern. Otherwise, the behavior may not be compatible with database O.
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot