Date and time functions
Note
To see which AWS data source integrations support this SQL command, see Supported OpenSearch SQL commands and functions.
Function | Description |
---|---|
add_months(start_date, num_months) | Returns the date that is num_months after start_date . |
convert_timezone([sourceTz, ]targetTz, sourceTs) | Converts the timestamp without time zone sourceTs from the sourceTz time zone to targetTz . |
curdate() | Returns the current date at the start of query evaluation. All calls of curdate within the same query return the same value. |
current_date() | Returns the current date at the start of query evaluation. All calls of current_date within the same query return the same value. |
current_date | Returns the current date at the start of query evaluation. |
current_timestamp() | Returns the current timestamp at the start of query evaluation. All calls of current_timestamp within the same query return the same value. |
current_timestamp | Returns the current timestamp at the start of query evaluation. |
current_timezone() | Returns the current session local timezone. |
date_add(start_date, num_days) | Returns the date that is num_days after start_date . |
date_diff(endDate, startDate) | Returns the number of days from startDate to endDate . |
date_format(timestamp, fmt) | Converts timestamp to a value of string in the format specified by the date format fmt . |
date_from_unix_date(days) | Create date from the number of days since 1970-01-01. |
date_part(field, source) | Extracts a part of the date/timestamp or interval source. |
date_sub(start_date, num_days) | Returns the date that is num_days before start_date . |
date_trunc(fmt, ts) | Returns timestamp ts truncated to the unit specified by the format model fmt . |
dateadd(start_date, num_days) | Returns the date that is num_days after start_date . |
datediff(endDate, startDate) | Returns the number of days from startDate to endDate . |
datepart(field, source) | Extracts a part of the date/timestamp or interval source. |
day(date) | Returns the day of month of the date/timestamp. |
dayofmonth(date) | Returns the day of month of the date/timestamp. |
dayofweek(date) | Returns the day of the week for date/timestamp (1 = Sunday, 2 = Monday, ..., 7 = Saturday). |
dayofyear(date) | Returns the day of year of the date/timestamp. |
extract(field FROM source) | Extracts a part of the date/timestamp or interval source. |
from_unixtime(unix_time[, fmt]) | Returns unix_time in the specified fmt . |
from_utc_timestamp(timestamp, timezone) | Given a timestamp like '2017-07-14 02:40:00.0', interprets it as a time in UTC, and renders that time as a timestamp in the given time zone. For example, 'GMT+1' would yield '2017-07-14 03:40:00.0'. |
hour(timestamp) | Returns the hour component of the string/timestamp. |
last_day(date) | Returns the last day of the month which the date belongs to. |
localtimestamp() | Returns the current timestamp without time zone at the start of query evaluation. All calls of localtimestamp within the same query return the same value. |
localtimestamp | Returns the current local date-time at the session time zone at the start of query evaluation. |
make_date(year, month, day) | Create date from year, month and day fields. |
make_dt_interval([days[, hours[, mins[, secs]]]]) | Make DayTimeIntervalType duration from days, hours, mins and secs. |
make_interval([years[, months[, weeks[, days[, hours[, mins[, secs]]]]]]]) | Make interval from years, months, weeks, days, hours, mins and secs. |
make_timestamp(year, month, day, hour, min, sec[, timezone]) | Create timestamp from year, month, day, hour, min, sec and timezone fields. |
make_timestamp_ltz(year, month, day, hour, min, sec[, timezone]) | Create the current timestamp with local time zone from year, month, day, hour, min, sec and timezone fields. |
make_timestamp_ntz(year, month, day, hour, min, sec) | Create local date-time from year, month, day, hour, min, sec fields. |
make_ym_interval([years[, months]]) | Make year-month interval from years, months. |
minute(timestamp) | Returns the minute component of the string/timestamp. |
month(date) | Returns the month component of the date/timestamp. |
months_between(timestamp1, timestamp2[, roundOff]) | If timestamp1 is later than timestamp2 , then the result is positive. If timestamp1 and timestamp2 are on the same day of month, or both are the last day of month, time of day will be ignored. Otherwise, the difference is calculated based on 31 days per month, and rounded to 8 digits unless roundOff=false. |
next_day(start_date, day_of_week) | Returns the first date which is later than
start_date and named as indicated. The
function returns NULL if at least one of the input
parameters is NULL. |
now() | Returns the current timestamp at the start of query evaluation. |
quarter(date) | Returns the quarter of the year for date, in the range 1 to 4. |
second(timestamp) | Returns the second component of the string/timestamp. |
session_window(time_column, gap_duration) | Generates session window given a timestamp specifying column and gap duration. See 'Types of time windows' in Structured Streaming guide doc for detailed explanation and examples. |
timestamp_micros(microseconds) | Creates timestamp from the number of microseconds since UTC epoch. |
timestamp_millis(milliseconds) | Creates timestamp from the number of milliseconds since UTC epoch. |
timestamp_seconds(seconds) | Creates timestamp from the number of seconds (can be fractional) since UTC epoch. |
to_date(date_str[, fmt]) | Parses the date_str expression with the fmt expression to a date. Returns null with invalid input. By default, it follows casting rules to a date if the fmt is omitted. |
to_timestamp(timestamp_str[, fmt]) | Parses the timestamp_str expression with the
fmt expression to a timestamp. Returns null
with invalid input. By default, it follows casting rules to
a timestamp if the fmt is omitted. |
to_timestamp_ltz(timestamp_str[, fmt]) | Parses the timestamp_str expression with the fmt expression to a timestamp with local time zone. Returns null with invalid input. By default, it follows casting rules to a timestamp if the fmt is omitted. |
to_timestamp_ntz(timestamp_str[, fmt]) | Parses the timestamp_str expression with the fmt expression to a timestamp without time zone. Returns null with invalid input. By default, it follows casting rules to a timestamp if the fmt is omitted. |
to_unix_timestamp(timeExp[, fmt]) | Returns the UNIX timestamp of the given time. |
to_utc_timestamp(timestamp, timezone) | Given a timestamp like '2017-07-14 02:40:00.0', interprets it as a time in the given time zone, and renders that time as a timestamp in UTC. For example, 'GMT+1' would yield '2017-07-14 01:40:00.0'. |
trunc(date, fmt) | Returns date with the time portion of the day truncated to the unit specified by the format model fmt . |
try_to_timestamp(timestamp_str[, fmt]) | Parses the timestamp_str expression with the
fmt expression to a timestamp. |
unix_date(date) | Returns the number of days since 1970-01-01. |
unix_micros(timestamp) | Returns the number of microseconds since 1970-01-01 00:00:00 UTC. |
unix_millis(timestamp) | Returns the number of milliseconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision. |
unix_seconds(timestamp) | Returns the number of seconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision. |
unix_timestamp([timeExp[, fmt]]) | Returns the UNIX timestamp of current or specified time. |
weekday(date) | Returns the day of the week for date/timestamp (0 = Monday, 1 = Tuesday, ..., 6 = Sunday). |
weekofyear(date) | Returns the week of the year of the given date. A week is considered to start on a Monday and week 1 is the first week with >3 days. |
window(time_column, window_duration[, slide_duration[, start_time]]) | Bucketize rows into one or more time windows given a timestamp specifying column. Window starts are inclusive but the window ends are exclusive, e.g. 12:05 will be in the window [12:05,12:10) but not in [12:00,12:05). Windows can support microsecond precision. Windows in the order of months are not supported. See 'Window Operations on Event Time' in Structured Streaming guide doc for detailed explanation and examples. |
window_time(window_column) | Extract the time value from time/session window column which can be used for event time value of window. The extracted time is (window.end - 1) which reflects the fact that the the aggregating windows have exclusive upper bound - [start, end) See 'Window Operations on Event Time' in Structured Streaming guide doc for detailed explanation and examples. |
year(date) | Returns the year component of the date/timestamp. |
Examples
-- add_months SELECT add_months('2016-08-31', 1); +-------------------------+ |add_months(2016-08-31, 1)| +-------------------------+ | 2016-09-30| +-------------------------+ -- convert_timezone SELECT convert_timezone('Europe/Brussels', 'America/Los_Angeles', timestamp_ntz'2021-12-06 00:00:00'); +-------------------------------------------------------------------------------------------+ |convert_timezone(Europe/Brussels, America/Los_Angeles, TIMESTAMP_NTZ '2021-12-06 00:00:00')| +-------------------------------------------------------------------------------------------+ | 2021-12-05 15:00:00| +-------------------------------------------------------------------------------------------+ SELECT convert_timezone('Europe/Brussels', timestamp_ntz'2021-12-05 15:00:00'); +------------------------------------------------------------------------------------------+ |convert_timezone(current_timezone(), Europe/Brussels, TIMESTAMP_NTZ '2021-12-05 15:00:00')| +------------------------------------------------------------------------------------------+ | 2021-12-05 07:00:00| +------------------------------------------------------------------------------------------+ -- curdate SELECT curdate(); +--------------+ |current_date()| +--------------+ | 2024-02-24| +--------------+ -- current_date SELECT current_date(); +--------------+ |current_date()| +--------------+ | 2024-02-24| +--------------+ SELECT current_date; +--------------+ |current_date()| +--------------+ | 2024-02-24| +--------------+ -- current_timestamp SELECT current_timestamp(); +--------------------+ | current_timestamp()| +--------------------+ |2024-02-24 16:36:...| +--------------------+ SELECT current_timestamp; +--------------------+ | current_timestamp()| +--------------------+ |2024-02-24 16:36:...| +--------------------+ -- current_timezone SELECT current_timezone(); +------------------+ |current_timezone()| +------------------+ | Asia/Seoul| +------------------+ -- date_add SELECT date_add('2016-07-30', 1); +-----------------------+ |date_add(2016-07-30, 1)| +-----------------------+ | 2016-07-31| +-----------------------+ -- date_diff SELECT date_diff('2009-07-31', '2009-07-30'); +---------------------------------+ |date_diff(2009-07-31, 2009-07-30)| +---------------------------------+ | 1| +---------------------------------+ SELECT date_diff('2009-07-30', '2009-07-31'); +---------------------------------+ |date_diff(2009-07-30, 2009-07-31)| +---------------------------------+ | -1| +---------------------------------+ -- date_format SELECT date_format('2016-04-08', 'y'); +--------------------------+ |date_format(2016-04-08, y)| +--------------------------+ | 2016| +--------------------------+ -- date_from_unix_date SELECT date_from_unix_date(1); +----------------------+ |date_from_unix_date(1)| +----------------------+ | 1970-01-02| +----------------------+ -- date_part SELECT date_part('YEAR', TIMESTAMP '2019-08-12 01:00:00.123456'); +-------------------------------------------------------+ |date_part(YEAR, TIMESTAMP '2019-08-12 01:00:00.123456')| +-------------------------------------------------------+ | 2019| +-------------------------------------------------------+ SELECT date_part('week', timestamp'2019-08-12 01:00:00.123456'); +-------------------------------------------------------+ |date_part(week, TIMESTAMP '2019-08-12 01:00:00.123456')| +-------------------------------------------------------+ | 33| +-------------------------------------------------------+ SELECT date_part('doy', DATE'2019-08-12'); +---------------------------------+ |date_part(doy, DATE '2019-08-12')| +---------------------------------+ | 224| +---------------------------------+ SELECT date_part('SECONDS', timestamp'2019-10-01 00:00:01.000001'); +----------------------------------------------------------+ |date_part(SECONDS, TIMESTAMP '2019-10-01 00:00:01.000001')| +----------------------------------------------------------+ | 1.000001| +----------------------------------------------------------+ SELECT date_part('days', interval 5 days 3 hours 7 minutes); +-------------------------------------------------+ |date_part(days, INTERVAL '5 03:07' DAY TO MINUTE)| +-------------------------------------------------+ | 5| +-------------------------------------------------+ SELECT date_part('seconds', interval 5 hours 30 seconds 1 milliseconds 1 microseconds); +-------------------------------------------------------------+ |date_part(seconds, INTERVAL '05:00:30.001001' HOUR TO SECOND)| +-------------------------------------------------------------+ | 30.001001| +-------------------------------------------------------------+ SELECT date_part('MONTH', INTERVAL '2021-11' YEAR TO MONTH); +--------------------------------------------------+ |date_part(MONTH, INTERVAL '2021-11' YEAR TO MONTH)| +--------------------------------------------------+ | 11| +--------------------------------------------------+ SELECT date_part('MINUTE', INTERVAL '123 23:55:59.002001' DAY TO SECOND); +---------------------------------------------------------------+ |date_part(MINUTE, INTERVAL '123 23:55:59.002001' DAY TO SECOND)| +---------------------------------------------------------------+ | 55| +---------------------------------------------------------------+ -- date_sub SELECT date_sub('2016-07-30', 1); +-----------------------+ |date_sub(2016-07-30, 1)| +-----------------------+ | 2016-07-29| +-----------------------+ -- date_trunc SELECT date_trunc('YEAR', '2015-03-05T09:32:05.359'); +-----------------------------------------+ |date_trunc(YEAR, 2015-03-05T09:32:05.359)| +-----------------------------------------+ | 2015-01-01 00:00:00| +-----------------------------------------+ SELECT date_trunc('MM', '2015-03-05T09:32:05.359'); +---------------------------------------+ |date_trunc(MM, 2015-03-05T09:32:05.359)| +---------------------------------------+ | 2015-03-01 00:00:00| +---------------------------------------+ SELECT date_trunc('DD', '2015-03-05T09:32:05.359'); +---------------------------------------+ |date_trunc(DD, 2015-03-05T09:32:05.359)| +---------------------------------------+ | 2015-03-05 00:00:00| +---------------------------------------+ SELECT date_trunc('HOUR', '2015-03-05T09:32:05.359'); +-----------------------------------------+ |date_trunc(HOUR, 2015-03-05T09:32:05.359)| +-----------------------------------------+ | 2015-03-05 09:00:00| +-----------------------------------------+ SELECT date_trunc('MILLISECOND', '2015-03-05T09:32:05.123456'); +---------------------------------------------------+ |date_trunc(MILLISECOND, 2015-03-05T09:32:05.123456)| +---------------------------------------------------+ | 2015-03-05 09:32:...| +---------------------------------------------------+ -- dateadd SELECT dateadd('2016-07-30', 1); +-----------------------+ |date_add(2016-07-30, 1)| +-----------------------+ | 2016-07-31| +-----------------------+ -- datediff SELECT datediff('2009-07-31', '2009-07-30'); +--------------------------------+ |datediff(2009-07-31, 2009-07-30)| +--------------------------------+ | 1| +--------------------------------+ SELECT datediff('2009-07-30', '2009-07-31'); +--------------------------------+ |datediff(2009-07-30, 2009-07-31)| +--------------------------------+ | -1| +--------------------------------+ -- datepart SELECT datepart('YEAR', TIMESTAMP '2019-08-12 01:00:00.123456'); +----------------------------------------------------------+ |datepart(YEAR FROM TIMESTAMP '2019-08-12 01:00:00.123456')| +----------------------------------------------------------+ | 2019| +----------------------------------------------------------+ SELECT datepart('week', timestamp'2019-08-12 01:00:00.123456'); +----------------------------------------------------------+ |datepart(week FROM TIMESTAMP '2019-08-12 01:00:00.123456')| +----------------------------------------------------------+ | 33| +----------------------------------------------------------+ SELECT datepart('doy', DATE'2019-08-12'); +------------------------------------+ |datepart(doy FROM DATE '2019-08-12')| +------------------------------------+ | 224| +------------------------------------+ SELECT datepart('SECONDS', timestamp'2019-10-01 00:00:01.000001'); +-------------------------------------------------------------+ |datepart(SECONDS FROM TIMESTAMP '2019-10-01 00:00:01.000001')| +-------------------------------------------------------------+ | 1.000001| +-------------------------------------------------------------+ SELECT datepart('days', interval 5 days 3 hours 7 minutes); +----------------------------------------------------+ |datepart(days FROM INTERVAL '5 03:07' DAY TO MINUTE)| +----------------------------------------------------+ | 5| +----------------------------------------------------+ SELECT datepart('seconds', interval 5 hours 30 seconds 1 milliseconds 1 microseconds); +----------------------------------------------------------------+ |datepart(seconds FROM INTERVAL '05:00:30.001001' HOUR TO SECOND)| +----------------------------------------------------------------+ | 30.001001| +----------------------------------------------------------------+ SELECT datepart('MONTH', INTERVAL '2021-11' YEAR TO MONTH); +-----------------------------------------------------+ |datepart(MONTH FROM INTERVAL '2021-11' YEAR TO MONTH)| +-----------------------------------------------------+ | 11| +-----------------------------------------------------+ SELECT datepart('MINUTE', INTERVAL '123 23:55:59.002001' DAY TO SECOND); +------------------------------------------------------------------+ |datepart(MINUTE FROM INTERVAL '123 23:55:59.002001' DAY TO SECOND)| +------------------------------------------------------------------+ | 55| +------------------------------------------------------------------+ -- day SELECT day('2009-07-30'); +---------------+ |day(2009-07-30)| +---------------+ | 30| +---------------+ -- dayofmonth SELECT dayofmonth('2009-07-30'); +----------------------+ |dayofmonth(2009-07-30)| +----------------------+ | 30| +----------------------+ -- dayofweek SELECT dayofweek('2009-07-30'); +---------------------+ |dayofweek(2009-07-30)| +---------------------+ | 5| +---------------------+ -- dayofyear SELECT dayofyear('2016-04-09'); +---------------------+ |dayofyear(2016-04-09)| +---------------------+ | 100| +---------------------+ -- extract SELECT extract(YEAR FROM TIMESTAMP '2019-08-12 01:00:00.123456'); +---------------------------------------------------------+ |extract(YEAR FROM TIMESTAMP '2019-08-12 01:00:00.123456')| +---------------------------------------------------------+ | 2019| +---------------------------------------------------------+ SELECT extract(week FROM timestamp'2019-08-12 01:00:00.123456'); +---------------------------------------------------------+ |extract(week FROM TIMESTAMP '2019-08-12 01:00:00.123456')| +---------------------------------------------------------+ | 33| +---------------------------------------------------------+ SELECT extract(doy FROM DATE'2019-08-12'); +-----------------------------------+ |extract(doy FROM DATE '2019-08-12')| +-----------------------------------+ | 224| +-----------------------------------+ SELECT extract(SECONDS FROM timestamp'2019-10-01 00:00:01.000001'); +------------------------------------------------------------+ |extract(SECONDS FROM TIMESTAMP '2019-10-01 00:00:01.000001')| +------------------------------------------------------------+ | 1.000001| +------------------------------------------------------------+ SELECT extract(days FROM interval 5 days 3 hours 7 minutes); +---------------------------------------------------+ |extract(days FROM INTERVAL '5 03:07' DAY TO MINUTE)| +---------------------------------------------------+ | 5| +---------------------------------------------------+ SELECT extract(seconds FROM interval 5 hours 30 seconds 1 milliseconds 1 microseconds); +---------------------------------------------------------------+ |extract(seconds FROM INTERVAL '05:00:30.001001' HOUR TO SECOND)| +---------------------------------------------------------------+ | 30.001001| +---------------------------------------------------------------+ SELECT extract(MONTH FROM INTERVAL '2021-11' YEAR TO MONTH); +----------------------------------------------------+ |extract(MONTH FROM INTERVAL '2021-11' YEAR TO MONTH)| +----------------------------------------------------+ | 11| +----------------------------------------------------+ SELECT extract(MINUTE FROM INTERVAL '123 23:55:59.002001' DAY TO SECOND); +-----------------------------------------------------------------+ |extract(MINUTE FROM INTERVAL '123 23:55:59.002001' DAY TO SECOND)| +-----------------------------------------------------------------+ | 55| +-----------------------------------------------------------------+ -- from_unixtime SELECT from_unixtime(0, 'yyyy-MM-dd HH:mm:ss'); +-------------------------------------+ |from_unixtime(0, yyyy-MM-dd HH:mm:ss)| +-------------------------------------+ | 1970-01-01 09:00:00| +-------------------------------------+ SELECT from_unixtime(0); +-------------------------------------+ |from_unixtime(0, yyyy-MM-dd HH:mm:ss)| +-------------------------------------+ | 1970-01-01 09:00:00| +-------------------------------------+ -- from_utc_timestamp SELECT from_utc_timestamp('2016-08-31', 'Asia/Seoul'); +------------------------------------------+ |from_utc_timestamp(2016-08-31, Asia/Seoul)| +------------------------------------------+ | 2016-08-31 09:00:00| +------------------------------------------+ -- hour SELECT hour('2009-07-30 12:58:59'); +-------------------------+ |hour(2009-07-30 12:58:59)| +-------------------------+ | 12| +-------------------------+ -- last_day SELECT last_day('2009-01-12'); +--------------------+ |last_day(2009-01-12)| +--------------------+ | 2009-01-31| +--------------------+ -- localtimestamp SELECT localtimestamp(); +--------------------+ | localtimestamp()| +--------------------+ |2024-02-24 16:36:...| +--------------------+ -- make_date SELECT make_date(2013, 7, 15); +----------------------+ |make_date(2013, 7, 15)| +----------------------+ | 2013-07-15| +----------------------+ SELECT make_date(2019, 7, NULL); +------------------------+ |make_date(2019, 7, NULL)| +------------------------+ | NULL| +------------------------+ -- make_dt_interval SELECT make_dt_interval(1, 12, 30, 01.001001); +-------------------------------------+ |make_dt_interval(1, 12, 30, 1.001001)| +-------------------------------------+ | INTERVAL '1 12:30...| +-------------------------------------+ SELECT make_dt_interval(2); +-----------------------------------+ |make_dt_interval(2, 0, 0, 0.000000)| +-----------------------------------+ | INTERVAL '2 00:00...| +-----------------------------------+ SELECT make_dt_interval(100, null, 3); +----------------------------------------+ |make_dt_interval(100, NULL, 3, 0.000000)| +----------------------------------------+ | NULL| +----------------------------------------+ -- make_interval SELECT make_interval(100, 11, 1, 1, 12, 30, 01.001001); +----------------------------------------------+ |make_interval(100, 11, 1, 1, 12, 30, 1.001001)| +----------------------------------------------+ | 100 years 11 mont...| +----------------------------------------------+ SELECT make_interval(100, null, 3); +----------------------------------------------+ |make_interval(100, NULL, 3, 0, 0, 0, 0.000000)| +----------------------------------------------+ | NULL| +----------------------------------------------+ SELECT make_interval(0, 1, 0, 1, 0, 0, 100.000001); +-------------------------------------------+ |make_interval(0, 1, 0, 1, 0, 0, 100.000001)| +-------------------------------------------+ | 1 months 1 days 1...| +-------------------------------------------+ -- make_timestamp SELECT make_timestamp(2014, 12, 28, 6, 30, 45.887); +-------------------------------------------+ |make_timestamp(2014, 12, 28, 6, 30, 45.887)| +-------------------------------------------+ | 2014-12-28 06:30:...| +-------------------------------------------+ SELECT make_timestamp(2014, 12, 28, 6, 30, 45.887, 'CET'); +------------------------------------------------+ |make_timestamp(2014, 12, 28, 6, 30, 45.887, CET)| +------------------------------------------------+ | 2014-12-28 14:30:...| +------------------------------------------------+ SELECT make_timestamp(2019, 6, 30, 23, 59, 60); +---------------------------------------+ |make_timestamp(2019, 6, 30, 23, 59, 60)| +---------------------------------------+ | 2019-07-01 00:00:00| +---------------------------------------+ SELECT make_timestamp(2019, 6, 30, 23, 59, 1); +--------------------------------------+ |make_timestamp(2019, 6, 30, 23, 59, 1)| +--------------------------------------+ | 2019-06-30 23:59:01| +--------------------------------------+ SELECT make_timestamp(null, 7, 22, 15, 30, 0); +--------------------------------------+ |make_timestamp(NULL, 7, 22, 15, 30, 0)| +--------------------------------------+ | NULL| +--------------------------------------+ -- make_timestamp_ltz SELECT make_timestamp_ltz(2014, 12, 28, 6, 30, 45.887); +-----------------------------------------------+ |make_timestamp_ltz(2014, 12, 28, 6, 30, 45.887)| +-----------------------------------------------+ | 2014-12-28 06:30:...| +-----------------------------------------------+ SELECT make_timestamp_ltz(2014, 12, 28, 6, 30, 45.887, 'CET'); +----------------------------------------------------+ |make_timestamp_ltz(2014, 12, 28, 6, 30, 45.887, CET)| +----------------------------------------------------+ | 2014-12-28 14:30:...| +----------------------------------------------------+ SELECT make_timestamp_ltz(2019, 6, 30, 23, 59, 60); +-------------------------------------------+ |make_timestamp_ltz(2019, 6, 30, 23, 59, 60)| +-------------------------------------------+ | 2019-07-01 00:00:00| +-------------------------------------------+ SELECT make_timestamp_ltz(null, 7, 22, 15, 30, 0); +------------------------------------------+ |make_timestamp_ltz(NULL, 7, 22, 15, 30, 0)| +------------------------------------------+ | NULL| +------------------------------------------+ -- make_timestamp_ntz SELECT make_timestamp_ntz(2014, 12, 28, 6, 30, 45.887); +-----------------------------------------------+ |make_timestamp_ntz(2014, 12, 28, 6, 30, 45.887)| +-----------------------------------------------+ | 2014-12-28 06:30:...| +-----------------------------------------------+ SELECT make_timestamp_ntz(2019, 6, 30, 23, 59, 60); +-------------------------------------------+ |make_timestamp_ntz(2019, 6, 30, 23, 59, 60)| +-------------------------------------------+ | 2019-07-01 00:00:00| +-------------------------------------------+ SELECT make_timestamp_ntz(null, 7, 22, 15, 30, 0); +------------------------------------------+ |make_timestamp_ntz(NULL, 7, 22, 15, 30, 0)| +------------------------------------------+ | NULL| +------------------------------------------+ -- make_ym_interval SELECT make_ym_interval(1, 2); +----------------------+ |make_ym_interval(1, 2)| +----------------------+ | INTERVAL '1-2' YE...| +----------------------+ SELECT make_ym_interval(1, 0); +----------------------+ |make_ym_interval(1, 0)| +----------------------+ | INTERVAL '1-0' YE...| +----------------------+ SELECT make_ym_interval(-1, 1); +-----------------------+ |make_ym_interval(-1, 1)| +-----------------------+ | INTERVAL '-0-11' ...| +-----------------------+ SELECT make_ym_interval(2); +----------------------+ |make_ym_interval(2, 0)| +----------------------+ | INTERVAL '2-0' YE...| +----------------------+ -- minute SELECT minute('2009-07-30 12:58:59'); +---------------------------+ |minute(2009-07-30 12:58:59)| +---------------------------+ | 58| +---------------------------+ -- month SELECT month('2016-07-30'); +-----------------+ |month(2016-07-30)| +-----------------+ | 7| +-----------------+ -- months_between SELECT months_between('1997-02-28 10:30:00', '1996-10-30'); +-----------------------------------------------------+ |months_between(1997-02-28 10:30:00, 1996-10-30, true)| +-----------------------------------------------------+ | 3.94959677| +-----------------------------------------------------+ SELECT months_between('1997-02-28 10:30:00', '1996-10-30', false); +------------------------------------------------------+ |months_between(1997-02-28 10:30:00, 1996-10-30, false)| +------------------------------------------------------+ | 3.9495967741935485| +------------------------------------------------------+ -- next_day SELECT next_day('2015-01-14', 'TU'); +------------------------+ |next_day(2015-01-14, TU)| +------------------------+ | 2015-01-20| +------------------------+ -- now SELECT now(); +--------------------+ | now()| +--------------------+ |2024-02-24 16:36:...| +--------------------+ -- quarter SELECT quarter('2016-08-31'); +-------------------+ |quarter(2016-08-31)| +-------------------+ | 3| +-------------------+ -- second SELECT second('2009-07-30 12:58:59'); +---------------------------+ |second(2009-07-30 12:58:59)| +---------------------------+ | 59| +---------------------------+ -- session_window SELECT a, session_window.start, session_window.end, count(*) as cnt FROM VALUES ('A1', '2021-01-01 00:00:00'), ('A1', '2021-01-01 00:04:30'), ('A1', '2021-01-01 00:10:00'), ('A2', '2021-01-01 00:01:00') AS tab(a, b) GROUP by a, session_window(b, '5 minutes') ORDER BY a, start; +---+-------------------+-------------------+---+ | a| start| end|cnt| +---+-------------------+-------------------+---+ | A1|2021-01-01 00:00:00|2021-01-01 00:09:30| 2| | A1|2021-01-01 00:10:00|2021-01-01 00:15:00| 1| | A2|2021-01-01 00:01:00|2021-01-01 00:06:00| 1| +---+-------------------+-------------------+---+ SELECT a, session_window.start, session_window.end, count(*) as cnt FROM VALUES ('A1', '2021-01-01 00:00:00'), ('A1', '2021-01-01 00:04:30'), ('A1', '2021-01-01 00:10:00'), ('A2', '2021-01-01 00:01:00'), ('A2', '2021-01-01 00:04:30') AS tab(a, b) GROUP by a, session_window(b, CASE WHEN a = 'A1' THEN '5 minutes' WHEN a = 'A2' THEN '1 minute' ELSE '10 minutes' END) ORDER BY a, start; +---+-------------------+-------------------+---+ | a| start| end|cnt| +---+-------------------+-------------------+---+ | A1|2021-01-01 00:00:00|2021-01-01 00:09:30| 2| | A1|2021-01-01 00:10:00|2021-01-01 00:15:00| 1| | A2|2021-01-01 00:01:00|2021-01-01 00:02:00| 1| | A2|2021-01-01 00:04:30|2021-01-01 00:05:30| 1| +---+-------------------+-------------------+---+ -- timestamp_micros SELECT timestamp_micros(1230219000123123); +----------------------------------+ |timestamp_micros(1230219000123123)| +----------------------------------+ | 2008-12-26 00:30:...| +----------------------------------+ -- timestamp_millis SELECT timestamp_millis(1230219000123); +-------------------------------+ |timestamp_millis(1230219000123)| +-------------------------------+ | 2008-12-26 00:30:...| +-------------------------------+ -- timestamp_seconds SELECT timestamp_seconds(1230219000); +-----------------------------+ |timestamp_seconds(1230219000)| +-----------------------------+ | 2008-12-26 00:30:00| +-----------------------------+ SELECT timestamp_seconds(1230219000.123); +---------------------------------+ |timestamp_seconds(1230219000.123)| +---------------------------------+ | 2008-12-26 00:30:...| +---------------------------------+ -- to_date SELECT to_date('2009-07-30 04:17:52'); +----------------------------+ |to_date(2009-07-30 04:17:52)| +----------------------------+ | 2009-07-30| +----------------------------+ SELECT to_date('2016-12-31', 'yyyy-MM-dd'); +-------------------------------+ |to_date(2016-12-31, yyyy-MM-dd)| +-------------------------------+ | 2016-12-31| +-------------------------------+ -- to_timestamp SELECT to_timestamp('2016-12-31 00:12:00'); +---------------------------------+ |to_timestamp(2016-12-31 00:12:00)| +---------------------------------+ | 2016-12-31 00:12:00| +---------------------------------+ SELECT to_timestamp('2016-12-31', 'yyyy-MM-dd'); +------------------------------------+ |to_timestamp(2016-12-31, yyyy-MM-dd)| +------------------------------------+ | 2016-12-31 00:00:00| +------------------------------------+ -- to_timestamp_ltz SELECT to_timestamp_ltz('2016-12-31 00:12:00'); +-------------------------------------+ |to_timestamp_ltz(2016-12-31 00:12:00)| +-------------------------------------+ | 2016-12-31 00:12:00| +-------------------------------------+ SELECT to_timestamp_ltz('2016-12-31', 'yyyy-MM-dd'); +----------------------------------------+ |to_timestamp_ltz(2016-12-31, yyyy-MM-dd)| +----------------------------------------+ | 2016-12-31 00:00:00| +----------------------------------------+ -- to_timestamp_ntz SELECT to_timestamp_ntz('2016-12-31 00:12:00'); +-------------------------------------+ |to_timestamp_ntz(2016-12-31 00:12:00)| +-------------------------------------+ | 2016-12-31 00:12:00| +-------------------------------------+ SELECT to_timestamp_ntz('2016-12-31', 'yyyy-MM-dd'); +----------------------------------------+ |to_timestamp_ntz(2016-12-31, yyyy-MM-dd)| +----------------------------------------+ | 2016-12-31 00:00:00| +----------------------------------------+ -- to_unix_timestamp SELECT to_unix_timestamp('2016-04-08', 'yyyy-MM-dd'); +-----------------------------------------+ |to_unix_timestamp(2016-04-08, yyyy-MM-dd)| +-----------------------------------------+ | 1460041200| +-----------------------------------------+ -- to_utc_timestamp SELECT to_utc_timestamp('2016-08-31', 'Asia/Seoul'); +----------------------------------------+ |to_utc_timestamp(2016-08-31, Asia/Seoul)| +----------------------------------------+ | 2016-08-30 15:00:00| +----------------------------------------+ -- trunc SELECT trunc('2019-08-04', 'week'); +-----------------------+ |trunc(2019-08-04, week)| +-----------------------+ | 2019-07-29| +-----------------------+ SELECT trunc('2019-08-04', 'quarter'); +--------------------------+ |trunc(2019-08-04, quarter)| +--------------------------+ | 2019-07-01| +--------------------------+ SELECT trunc('2009-02-12', 'MM'); +---------------------+ |trunc(2009-02-12, MM)| +---------------------+ | 2009-02-01| +---------------------+ SELECT trunc('2015-10-27', 'YEAR'); +-----------------------+ |trunc(2015-10-27, YEAR)| +-----------------------+ | 2015-01-01| +-----------------------+ -- try_to_timestamp SELECT try_to_timestamp('2016-12-31 00:12:00'); +-------------------------------------+ |try_to_timestamp(2016-12-31 00:12:00)| +-------------------------------------+ | 2016-12-31 00:12:00| +-------------------------------------+ SELECT try_to_timestamp('2016-12-31', 'yyyy-MM-dd'); +----------------------------------------+ |try_to_timestamp(2016-12-31, yyyy-MM-dd)| +----------------------------------------+ | 2016-12-31 00:00:00| +----------------------------------------+ SELECT try_to_timestamp('foo', 'yyyy-MM-dd'); +---------------------------------+ |try_to_timestamp(foo, yyyy-MM-dd)| +---------------------------------+ | NULL| +---------------------------------+ -- unix_date SELECT unix_date(DATE("1970-01-02")); +---------------------+ |unix_date(1970-01-02)| +---------------------+ | 1| +---------------------+ -- unix_micros SELECT unix_micros(TIMESTAMP('1970-01-01 00:00:01Z')); +---------------------------------+ |unix_micros(1970-01-01 00:00:01Z)| +---------------------------------+ | 1000000| +---------------------------------+ -- unix_millis SELECT unix_millis(TIMESTAMP('1970-01-01 00:00:01Z')); +---------------------------------+ |unix_millis(1970-01-01 00:00:01Z)| +---------------------------------+ | 1000| +---------------------------------+ -- unix_seconds SELECT unix_seconds(TIMESTAMP('1970-01-01 00:00:01Z')); +----------------------------------+ |unix_seconds(1970-01-01 00:00:01Z)| +----------------------------------+ | 1| +----------------------------------+ -- unix_timestamp SELECT unix_timestamp(); +--------------------------------------------------------+ |unix_timestamp(current_timestamp(), yyyy-MM-dd HH:mm:ss)| +--------------------------------------------------------+ | 1708760216| +--------------------------------------------------------+ SELECT unix_timestamp('2016-04-08', 'yyyy-MM-dd'); +--------------------------------------+ |unix_timestamp(2016-04-08, yyyy-MM-dd)| +--------------------------------------+ | 1460041200| +--------------------------------------+ -- weekday SELECT weekday('2009-07-30'); +-------------------+ |weekday(2009-07-30)| +-------------------+ | 3| +-------------------+ -- weekofyear SELECT weekofyear('2008-02-20'); +----------------------+ |weekofyear(2008-02-20)| +----------------------+ | 8| +----------------------+ -- window SELECT a, window.start, window.end, count(*) as cnt FROM VALUES ('A1', '2021-01-01 00:00:00'), ('A1', '2021-01-01 00:04:30'), ('A1', '2021-01-01 00:06:00'), ('A2', '2021-01-01 00:01:00') AS tab(a, b) GROUP by a, window(b, '5 minutes') ORDER BY a, start; +---+-------------------+-------------------+---+ | a| start| end|cnt| +---+-------------------+-------------------+---+ | A1|2021-01-01 00:00:00|2021-01-01 00:05:00| 2| | A1|2021-01-01 00:05:00|2021-01-01 00:10:00| 1| | A2|2021-01-01 00:00:00|2021-01-01 00:05:00| 1| +---+-------------------+-------------------+---+ SELECT a, window.start, window.end, count(*) as cnt FROM VALUES ('A1', '2021-01-01 00:00:00'), ('A1', '2021-01-01 00:04:30'), ('A1', '2021-01-01 00:06:00'), ('A2', '2021-01-01 00:01:00') AS tab(a, b) GROUP by a, window(b, '10 minutes', '5 minutes') ORDER BY a, start; +---+-------------------+-------------------+---+ | a| start| end|cnt| +---+-------------------+-------------------+---+ | A1|2020-12-31 23:55:00|2021-01-01 00:05:00| 2| | A1|2021-01-01 00:00:00|2021-01-01 00:10:00| 3| | A1|2021-01-01 00:05:00|2021-01-01 00:15:00| 1| | A2|2020-12-31 23:55:00|2021-01-01 00:05:00| 1| | A2|2021-01-01 00:00:00|2021-01-01 00:10:00| 1| +---+-------------------+-------------------+---+ -- window_time SELECT a, window.start as start, window.end as end, window_time(window), cnt FROM (SELECT a, window, count(*) as cnt FROM VALUES ('A1', '2021-01-01 00:00:00'), ('A1', '2021-01-01 00:04:30'), ('A1', '2021-01-01 00:06:00'), ('A2', '2021-01-01 00:01:00') AS tab(a, b) GROUP by a, window(b, '5 minutes') ORDER BY a, window.start); +---+-------------------+-------------------+--------------------+---+ | a| start| end| window_time(window)|cnt| +---+-------------------+-------------------+--------------------+---+ | A1|2021-01-01 00:00:00|2021-01-01 00:05:00|2021-01-01 00:04:...| 2| | A1|2021-01-01 00:05:00|2021-01-01 00:10:00|2021-01-01 00:09:...| 1| | A2|2021-01-01 00:00:00|2021-01-01 00:05:00|2021-01-01 00:04:...| 1| +---+-------------------+-------------------+--------------------+---+ -- year SELECT year('2016-07-30'); +----------------+ |year(2016-07-30)| +----------------+ | 2016| +----------------+