Table 1 lists the temporal functions supported by Flink OpenSource SQL.
Function |
Return Type |
Description |
---|---|---|
DATE |
Parse the date string (yyyy-MM-dd) to a SQL date. |
|
TIME |
Parse the time string (HH:mm:ss[.fff]) to a SQL time. |
|
TIMESTAMP |
Convert the time string into a timestamp. The time string format is yyyy-MM-dd HH:mm:ss[.fff]. |
|
INTERVAL |
Parse an interval string in the following two forms:
Example: INTERVAL '10 00:00:00.004' DAY TO second indicates that the interval is 10 days and 4 milliseconds. INTERVAL '10' DAY: indicates that the interval is 10 days. INTERVAL '2-10' YEAR TO MONTH indicates that the interval is two years and ten months. |
|
DATE |
Return the SQL date of UTC time zone. |
|
TIME |
Return the SQL time of UTC time zone. |
|
TIMESTAMP |
Return the SQL timestamp of UTC time zone. |
|
TIME |
Return the SQL time of the local time zone. |
|
TIMESTAMP |
Return the SQL timestamp of the local time zone. |
|
BIGINT |
Extract part of the time point or interval. Return the part in the int type. For example, extract the date 2006-06-05 and return 5. EXTRACT(DAY FROM DATE '2006-06-05') returns 5. |
|
BIGINT |
Return the year from a SQL date. For example, YEAR(DATE'1994-09-27') returns 1994. |
|
BIGINT |
Return the quarter of a year from a SQL date. |
|
BIGINT |
Return the month of a year from a SQL date. For example, MONTH(DATE '1994-09-27') returns 9. |
|
BIGINT |
Return the week of a year from a SQL date. For example, WEEK(DATE'1994-09-27') returns 39. |
|
BIGINT |
Return the day of a year from a SQL date. For example, DAYOFYEAR(DATE '1994-09-27') is 270. |
|
BIGINT |
Return the day of a month from a SQL date. For example, DAYOFMONTH(DATE'1994-09-27') returns 27. |
|
BIGINT |
Return the day of a week from a SQL date. Sunday is set to 1. For example, DAYOFWEEK(DATE'1994-09-27') returns 3. |
|
BIGINT |
Return the hour of a day (an integer between 0 and 23) from a SQL timestamp. For example, HOUR(TIMESTAMP '1994-09-27 13:14:15') returns 13. |
|
BIGINT |
Return the minute of an hour (an integer between 0 and 59) from a SQL timestamp. For example, MINUTE(TIMESTAMP '1994-09-27 13:14:15') returns 14. |
|
BIGINT |
Returns the second of a minute (an integer between 0 and 59) from a SQL timestamp. For example, SECOND(TIMESTAMP '1994-09-27 13:14:15') returns 15. |
|
TIME |
Round a time point down to the given unit. For example, 12:44:00 is returned from FLOOR(TIME '12:44:31' TO MINUTE). |
|
TIME |
Round a time point up to the given unit. For example, CEIL(TIME '12:44:31' TO MINUTE) returns 12:45:00. |
|
BOOLEAN |
Return TRUE if two time intervals overlap. Example: (TIME '2:55:00', INTERVAL '1' HOUR) OVERLAPS (TIME '3:30:00', INTERVAL '2' HOUR) returns TRUE. (TIME '9:00:00', TIME '10:00:00') OVERLAPS (TIME '10:15:00', INTERVAL '3' HOUR) returns FALSE. |
|
STRING |
Convert a timestamp to a value of string in the format specified by the date format string. |
|
TIMESTAMP/DATE/TIME |
Return the date and time added to timepoint based on the result of interval and timeintervalunit. For example, TIMESTAMPADD(WEEK, 1, DATE '2003-01-02') returns 2003-01-09. |
|
INT |
Return the (signed) number of timepointunit between timepoint1 and timepoint2. The unit for the interval is given by the first argument, which should be one of the following values: SECOND, MINUTE, HOUR, DAY, MONTH, and YEAR. For example, TIMESTAMPDIFF(DAY, TIMESTAMP '2003-01-02 10:00:00', TIMESTAMP '2003-01-03 10:00:00') returns 1. |
|
TIMESTAMP |
Convert a datetime string1 from time zone string2 to time zone string3. For example, CONVERT_TZ('1970-01-01 00:00:00', 'UTC', 'America/Los_Angeles') returns '1969-12-31 16:00:00'. |
|
STRING |
Return a representation of the numeric argument as a value in string format. The default string format is YYYY-MM-DD hh:mm:ss. For example, FROM_UNIXTIME(44) returns 1970-01-01 09:00:44. |
|
BIGINT |
Get current Unix timestamp in seconds. |
|
BIGINT |
Convert date time string string1 in format string2 to Unix timestamp (in seconds), using the specified timezone in table config. The default format of string2 is yyyy-MM-dd HH:mm:ss. |
|
DATE |
Convert a date string string1 with format string2 to a date. The default format of string2 is yyyy-MM-dd. |
|
TIMESTAMP |
Convert date time string string1 with format string2 to a timestamp. The default format of string2 is yyyy-MM-dd HH:mm:ss. |
Returns a date parsed from string in form of yyyy-MM-dd.
DATE DATE string
Parameter |
Type |
Description |
---|---|---|
string |
STRING |
String in the SQL date format. Note that the string must be in the yyyy-MM-dd format. Otherwise, an error will be reported. |
SELECT DATE "2021-08-19" AS `result` FROM testtable;
result |
---|
2021-08-19 |
Returns a SQL time parsed from string in form of HH:mm:ss[.fff].
TIME TIME string
Parameter |
Type |
Description |
---|---|---|
string |
STRING |
Time Note that the string must be in the format of HH:mm:ss[.fff]. Otherwise, an error will be reported. |
SELECT TIME "10:11:12" AS `result`, TIME "10:11:12.032" AS `result2` FROM testtable;
result |
result2 |
---|---|
10:11:12 |
10:11:12.032 |
Converts the time string into timestamp. The time string format is yyyy-MM-dd HH:mm:ss[.fff]. The return value is of the TIMESTAMP(3) type.
TIMESTAMP(3) TIMESTAMP string
Parameter |
Type |
Description |
---|---|---|
string |
STRING |
Time Note that the string must be in the format of yyyy-MM-dd HH:mm:ss[.fff]. Otherwise, an error will be reported. |
SELECT TIMESTAMP "1997-04-25 13:14:15" AS `result`, TIMESTAMP "1997-04-25 13:14:15.032" AS `result2` FROM testtable;
result |
result2 |
---|---|
1997-04-25 13:14:15 |
1997-04-25 13:14:15.032 |
Parses an interval string.
INTERVAL INTERVAL string range
Parameter |
Type |
Description |
---|---|---|
string |
STRING |
Timestamp string used together with the range parameter. The string is in either of the following two formats:
|
range |
INTERVAL |
Interval range. This parameter is used together with the string parameter. Available values are as follows: YEAR, YEAR To Month, DAY, MINUTE, DAY TO HOUR and DAY TO SECOND. |
-- The interval is 10 days and 4 milliseconds. INTERVAL '10 00:00:00.004' DAY TO second -- The interval is 10 days. INTERVAL '10' -- The interval is 2 years and 10 months. INTERVAL '2-10' YEAR TO MONTH
Returns the current SQL time (yyyy-MM-dd) in the local time zone. The return value is of the DATE type.
DATE CURRENT_DATE
N/A
SELECT CURRENT_DATE AS `result` FROM testtable;
result |
---|
2021-10-28 |
Returns the current SQL time (HH:mm:sss.fff) in the local time zone. The return value is of the TIME type.
TIME CURRENT_TIME
N/A
SELECT CURRENT_TIME AS `result` FROM testtable;
result |
---|
08:29:19.289 |
Returns the current SQL timestamp in the local time zone. The return value is of the TIMESTAMP(3) type.
TIMESTAMP(3) CURRENT_TIMESTAMP
N/A
SELECT CURRENT_TIMESTAMP AS `result` FROM testtable;
result |
---|
2021-10-28 08:33:51.606 |
Returns the current SQL time in the local time zone. The return value is of the TIME type.
TIME LOCALTIME
N/A
SELECT LOCALTIME AS `result` FROM testtable;
result |
---|
16:39:37.706 |
Returns the current SQL timestamp in the local time zone. The return value is of the TIMESTAMP(3) type.
TIMESTAMP(3) LOCALTIMESTAMP
N/A
SELECT LOCALTIMESTAMP AS `result` FROM testtable;
result |
---|
2021-10-28 16:43:17.625 |
Returns a value extracted from the timeintervalunit part of temporal. The return value is of the BIGINT type.
BIGINT EXTRACT(timeinteravlunit FROM temporal)
Parameter |
Type |
Description |
---|---|---|
timeinteravlunit |
TIMEUNIT |
Time unit to be extracted from a time point or interval. The value can be YEAR, QUARTER, MONTH, WEEK, DAY, DOY, HOUR, MINUTE, SECOND. |
temporal |
DATE/TIME/TIMESTAMP/INTERVAL |
Time point or interval. |
Do not specify a time unit that is not of any time points or intervals. Otherwise, the job fails to be submitted.
For example, an error message is displayed when the following statement is executed because YEAR cannot be extracted from TIME.
SELECT EXTRACT(YEAR FROM TIME '12:44:31' ) AS `result` FROM testtable;
SELECT EXTRACT(YEAR FROM DATE '1997-04-25' ) AS `result`, EXTRACT(MINUTE FROM TIME '12:44:31') AS `result2`, EXTRACT(SECOND FROM TIMESTAMP '1997-04-25 13:14:15') AS `result3`, EXTRACT(YEAR FROM INTERVAL '2-10' YEAR TO MONTH) AS `result4`, FROM testtable;
result |
result2 |
result3 |
result4 |
---|---|---|---|
1997 |
44 |
15 |
2 |
Returns the year from a SQL date. The return value is of the BIGINT type.
BIGINT YEAR(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT YEAR(DATE '1997-04-25' ) AS `result` FROM testtable;
result |
---|
1997 |
Returns the quarter of a year (an integer between 1 and 4) from a SQL date. The return value is of the BIGINT type.
BIGINT QUARTER(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT QUARTER(DATE '1997-04-25' ) AS `result` FROM testtable;
Result |
---|
2 |
Returns the month of a year (an integer between 1 and 12) from a SQL date. The return value is of the BIGINT type.
BIGINT MONTH(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT MONTH(DATE '1997-04-25' ) AS `result` FROM testtable;
result |
---|
4 |
Returns the week of a year from a SQL date. The return value is of the BIGINT type.
BIGINT WEEK(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT WEEK(DATE '1997-04-25' ) AS `result` FROM testtable;
result |
---|
17 |
Returns the day of a year (an integer between 1 and 366) from SQL date. The return value is of the BIGINT type.
BIGINT DAYOFYEAR(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT DAYOFYEAR(DATE '1997-04-25' ) AS `result` FROM testtable;
result |
---|
115 |
Returns the day of a month (an integer between 1 and 31) from a SQL date. The return value is of the BIGINT type.
BIGINT DAYOFMONTH(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT DAYOFMONTH(DATE '1997-04-25' ) AS `result` FROM testtable;
Result |
---|
25 |
Returns the day of a week (an integer between 1 and 7) from a SQL date. The return value is of the BIGINT type.
Note that the start day of a week is Sunday.
BIGINT DAYOFWEEK(date)
Parameter |
Type |
Description |
---|---|---|
date |
DATE |
SQL date |
SELECT DAYOFWEEK(DATE '1997-04-25') AS `result` FROM testtable;
result |
---|
6 |
Returns the hour of a day (an integer between 0 and 23) from SQL timestamp. The return value is of the BIGINT type.
BIGINT HOUR(timestamp)
Parameter |
Type |
Description |
---|---|---|
timestamp |
TIMESTAMP |
SQL timestamp |
SELECT HOUR(TIMESTAMP '1997-04-25 10:11:12') AS `result` FROM testtable;
result |
---|
10 |
Returns the minute of an hour (an integer between 0 and 59) from a SQL timestamp. The return value is of the BIGINT type.
BIGINT MINUTE(timestamp)
Parameter |
Type |
Description |
---|---|---|
timestamp |
TIMESTAMP |
SQL timestamp |
SELECT MINUTE(TIMESTAMP '1997-04-25 10:11:12') AS `result` FROM testtable;
result |
---|
11 |
Returns the second of an hour (an integer between 0 and 59) from a SQL timestamp. The return value is of the BIGINT type.
BIGINT SECOND(timestamp)
Parameter |
Type |
Description |
---|---|---|
timestamp |
TIMESTAMP |
SQL timestamp |
SELECT SECOND(TIMESTAMP '1997-04-25 10:11:12') AS `result` FROM testtable;
result |
---|
12 |
Returns a value that rounds timepoint down to the time unit timeintervalunit.
TIME/TIMESTAMP(3) FLOOR(timepoint TO timeintervalunit)
Parameter |
Type |
Description |
---|---|---|
timepoint |
TIMESTAMP/TIME |
SQL time or SQL timestamp |
timeintervalunit |
TIMEUNIT |
Time unit. The value can be YEAR, QUARTER, MONTH, WEEK, DAY, DOY, HOUR, MINUTE, or SECOND. |
create table PrintSink ( message TIME, message2 TIME, message3 TIMESTAMP(3) ) with ( 'connector.type' = 'user-defined', 'connector.class-name' = 'com.swqtest.flink.sink.PrintSink'--Replace the class with a user-defined class. For details, see the syntax description in the userDefined result table. ); INSERT INTO PrintSink SELECT FLOOR(TIME '13:14:15' TO MINUTE) AS `result` FLOOR(TIMESTAMP '1997-04-25 13:14:15' TO MINUTE) AS `result2`, FLOOR(TIMESTAMP '1997-04-25 13:14:15' TO MINUTE) AS `result3`;
Returns a value that rounds timepoint up to the time unit timeintervalunit.
TIME/TIMESTAMP(3) CEIL(timepoint TO timeintervalunit)
Parameter |
Type |
Description |
---|---|---|
timepoint |
TIMESTAMP/TIME |
SQL time or SQL timestamp |
timeintervalunit |
TIMEUNIT |
Time unit. The value can be YEAR, QUARTER, MONTH, WEEK, DAY, DOY, HOUR, MINUTE, or SECOND. |
create table PrintSink ( message TIME, message2 TIME, message3 TIMESTAMP(3) ) with ( 'connector.type' = 'user-defined', 'connector.class-name' = 'com.swqtest.flink.sink.PrintSink'--Replace the class with a user-defined class. For details, see the syntax description in the userDefined result table. ); INSERT INTO PrintSink SELECT CEIL(TIME '13:14:15' TO MINUTE) AS `result` CEIL(TIMESTAMP '1997-04-25 13:14:15' TO MINUTE) AS `result2`, CEIL(TIMESTAMP '1997-04-25 13:14:15' TO MINUTE) AS `result3`;
result |
result2 |
result3 |
---|---|---|
13:15 |
13:15 |
1997-04-25T13:15 |
Returns TRUE if two time intervals overlap; returns FALSE otherwise.
BOOLEAN (timepoint1, temporal1) OVERLAPS (timepoint2, temporal2)
Parameter |
Type |
Description |
---|---|---|
timepoint1/timepoint2 |
DATE/TIME/TIMESTAMP |
Time point |
temporal1/temporal2 |
DATE/TIME/TIMESTAMP/INTERVAL |
Time point or interval |
SELECT (TIME '2:55:00', INTERVAL '1' HOUR) OVERLAPS (TIME '3:30:00', INTERVAL '2' HOUR) AS `result`, (TIME '2:30:00', INTERVAL '1' HOUR) OVERLAPS (TIME '3:30:00', INTERVAL '2' HOUR) AS `result2`, (TIME '2:30:00', INTERVAL '1' HOUR) OVERLAPS (TIME '3:31:00', INTERVAL '2' HOUR) AS `result3`, (TIME '9:00:00', TIME '10:00:00') OVERLAPS (TIME '10:00:00', INTERVAL '3' HOUR) AS `result4`, (TIMESTAMP '1997-04-25 12:00:00', TIMESTAMP '1997-04-25 12:20:00') OVERLAPS (TIMESTAMP '1997-04-25 13:00:00', INTERVAL '2' HOUR) AS `result5`, (DATE '1997-04-23', INTERVAL '2' DAY) OVERLAPS (DATE '1997-04-25', INTERVAL '2' DAY) AS `result6`, (DATE '1997-04-25', DATE '1997-04-23') OVERLAPS (DATE '1997-04-25', INTERVAL '2' DAY) AS `result7` FROM testtable;
result |
result2 |
result3 |
result4 |
result5 |
result6 |
result7 |
---|---|---|---|---|---|---|
true |
true |
false |
true |
false |
true |
true |
Converts a timestamp to a value of string in the format specified by the date format string.
STRING DATE_FORMAT(timestamp, dateformat)
Parameter |
Type |
Description |
---|---|---|
timestamp |
TIMESTAMP/STRING |
Time point |
dateformat |
STRING |
String in the date format |
SELECT DATE_FORMAT(TIMESTAMP '1997-04-25 10:11:12', 'yyyy-MM-dd HH:mm:ss') AS `result`, DATE_FORMAT(TIMESTAMP '1997-04-25 10:11:12', 'yyyy-MM-dd') AS `result2`, DATE_FORMAT(TIMESTAMP '1997-04-25 10:11:12', 'yy/MM/dd HH:mm') AS `result3`, DATE_FORMAT('1997-04-25 10:11:12', 'yyyy-MM-dd') AS `result4` FROM testtable;
result |
result2 |
result3 |
result4 |
---|---|---|---|
1997-04-25 10:11:12 |
1997-04-25 |
97/04/25 10:11 |
1997-04-25 |
Returns the date and time by combining interval and timeintervalunit and adding the combination to timepoint.
The return value of TIMESTAMPADD is the value of timepoint. An exception is that if the input timepoint is of the TIMESTAMP type, the return value can be inserted into a table field of the DATE type.
TIMESTAMP(3)/DATE/TIME TIMESTAMPADD(timeintervalunit, interval, timepoint)
Parameter |
Type |
Description |
---|---|---|
timeintervalunit |
TIMEUNIT |
Time unit |
interval |
INT |
Interval |
timepoint |
TIMESTAMP/DATE/TIME |
Time point |
SELECT TIMESTAMPADD(WEEK, 1, DATE '1997-04-25') AS `result`, TIMESTAMPADD(QUARTER, 1, TIMESTAMP '1997-04-25 10:11:12') AS `result2`, TIMESTAMPADD(SECOND, 2, TIME '10:11:12') AS `result3` FROM testtable;
result |
result2 |
result3 |
---|---|---|
1997-05-02 |
|
10:11:14 |
Returns the (signed) number of timepointunit between timepoint1 and timepoint2. The unit for the interval is given by the first argument.
INT TIMESTAMPDIFF(timepointunit, timepoint1, timepoint2)
Parameter |
Type |
Description |
---|---|---|
timepointunit |
TIMEUNIT |
Time unit. The value can be SECOND, MINUTE, HOUR, DAY, MONTH or YEAR. |
timepoint1/timepoint2 |
TIMESTAMP/DATE |
Time point |
SELECT TIMESTAMPDIFF(DAY, TIMESTAMP '1997-04-25 10:00:00', TIMESTAMP '1997-04-28 10:00:00') AS `result`, TIMESTAMPDIFF(DAY, DATE '1997-04-25', DATE '1997-04-28') AS `result2`, TIMESTAMPDIFF(DAY, TIMESTAMP '1997-04-27 10:00:20', TIMESTAMP '1997-04-25 10:00:00') AS `result3` FROM testtable;
result |
result2 |
result3 |
---|---|---|
3 |
3 |
-2 |
Converts a datetime string1 (with default ISO timestamp format 'yyyy-MM-dd HH:mm:ss') from time zone string2 to time zone string3.
STRING CONVERT_TZ(string1, string2, string3)
Parameter |
Type |
Description |
---|---|---|
string1 |
STRING |
SQL timestamp. If the value does not meet the format requirements, NULL is returned. |
string2 |
STRING |
Time zone before conversion. The format of time zone should be either an abbreviation such as PST, a full name such as America/Los_Angeles, or a custom ID such as GMT-08:00. |
string3 |
STRING |
Time zone after conversion. The format of time zone should be either an abbreviation such as PST, a full name such as America/Los_Angeles, or a custom ID such as GMT-08:00. |
SELECT CONVERT_TZ(1970-01-01 00:00:00, UTC, America/Los_Angeles) AS `result`, CONVERT_TZ(1997-04-25 10:00:00, UTC, GMT-08:00) AS `result2` FROM testtable;
result |
result2 |
---|---|
1969-12-31 16:00:00 |
1997-04-25 02:00:00 |
Returns a representation of the numeric argument as a value in string format.
STRING FROM_UNIXTIME(numeric[, string])
Parameter |
Type |
Description |
---|---|---|
numeric |
BIGINT |
An internal timestamp representing the number of seconds since 1970-01-01 00:00:00 UTC. The value can be generated by the UNIX_TIMESTAMP() function. |
string |
STRING |
Time. If this parameter is not specified, the default time format is yyyy-MM-dd HH:mm:ss format. |
SELECT FROM_UNIXTIME(44) AS `result`, FROM_UNIXTIME(44, 'yyyy:MM:dd') AS `result2` FROM testtable;
result |
result2 |
---|---|
1970-01-01 08:00:44 |
1970:01:01 |
Gets current Unix timestamp in seconds. The return value is of the BIGINT type.
BIGINT UNIX_TIMESTAMP()
N/A
SELECT UNIX_TIMESTAMP() AS `result` FROM table;
result |
---|
1635401982 |
Converts date time string1 in format string2 to Unix timestamp (in seconds). The return value is of the BIGINT type.
BIGINT UNIX_TIMESTAMP(string1[, string2])
Parameter |
Type |
Description |
---|---|---|
string1 |
STRING |
SQL timestamp string. An error is reported if the value does not comply with the string2 format. |
string2 |
STRING |
Time. If this parameter is not specified, the default time format is yyyy-MM-dd HH:mm:ss. |
SELECT UNIX_TIMESTAMP('1997-04-25', 'yyyy-MM-dd') AS `result`, UNIX_TIMESTAMP('1997-04-25 00:00:10', 'yyyy-MM-dd HH:mm:ss') AS `result2`, UNIX_TIMESTAMP('1997-04-25 00:00:00') AS `result3` FROM testtable;
result |
result2 |
result3 |
---|---|---|
861897600 |
861897610 |
861897600 |
Converts a date string1 with format string2 to a date.
DATE TO_DATE(string1[, string2])
Parameter |
Type |
Description |
---|---|---|
string1 |
STRING |
SQL timestamp string. If the value is not in the required format, an error is reported. |
string2 |
STRING |
Format. If this parameter is not specified, the default time format is yyyy-MM-dd. |
SELECT TO_DATE('1997-04-25') AS `result`, TO_DATE('1997:04:25', 'yyyy-MM-dd') AS `result2`, TO_DATE('1997-04-25 00:00:00', 'yyyy-MM-dd HH:mm:ss') AS `result3` FROM testtable;
result |
result2 |
result3 |
---|---|---|
1997-04-25 |
1997-04-25 |
1997-04-25 |
Converts date time string1 with format string2 to a timestamp.
TIMESTAMP TO_TIMESTAMP(string1[, string2])
Parameter |
Type |
Description |
---|---|---|
string1 |
STRING |
SQL timestamp string. If the value is not in the required format, NULL is returned. |
string2 |
STRING |
Date format. If this parameter is not specified, the default format is yyyy-MM-dd HH:mm:ss. |
SELECT TO_TIMESTAMP('1997-04-25', 'yyyy-MM-dd') AS `result`, TO_TIMESTAMP('1997-04-25 00:00:00') AS `result2`, TO_TIMESTAMP('1997-04-25 00:00:00', 'yyyy-MM-dd HH:mm:ss') AS `result3` FROM testtable;
result |
result2 |
result3 |
---|---|---|
1997-04-25 00:00 |
1997-04-25 00:00 |
1997-04-25 00:00 |