[docs] Batch10 date and time functions (#16900)

* just starting

* TIME_PARSE and TIME_FORMAT remaining

* fixing typo

* adding last two functions

* review sql-functions.md

* Apply suggestions from code review

Suggestions that were accepted as is

Co-authored-by: Katya Macedo  <38017980+ektravel@users.noreply.github.com>

* Update docs/querying/sql-functions.md

Co-authored-by: Katya Macedo  <38017980+ektravel@users.noreply.github.com>

* Update docs/querying/sql-functions.md

needed to confirm that it did indeed return as a number

Co-authored-by: Katya Macedo  <38017980+ektravel@users.noreply.github.com>

* reviewing remaining suggestions

* addressing review for time_format

* Apply suggestions from code review

Accepted as is

Co-authored-by: Katya Macedo  <38017980+ektravel@users.noreply.github.com>

* addressing final suggestion

* time_zone -> timezone

* timezone fix

---------

Co-authored-by: Katya Macedo <38017980+ektravel@users.noreply.github.com>
This commit is contained in:
Edgar Melendrez 2024-08-22 20:25:27 -07:00 committed by GitHub
parent 2f6722db63
commit c4981e34c4
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
2 changed files with 225 additions and 39 deletions

View File

@ -826,28 +826,85 @@ Returns the cumulative distribution of the current row within the window calcula
## CURRENT_DATE ## CURRENT_DATE
`CURRENT_DATE` Returns the current date in UTC time, unless you specify a different timezone in the query context.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `CURRENT_DATE`
* **Function type:** Scalar, date and time
Returns the current date in the connection's time zone. <details><summary>Example</summary>
The following example returns the current date.
```sql
SELECT CURRENT_DATE AS "current_date"
```
Returns the following:
| `current_date` |
| -- |
| `2024-08-14T00:00:00.000Z `|
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## CURRENT_TIMESTAMP ## CURRENT_TIMESTAMP
`CURRENT_TIMESTAMP` Returns the current timestamp in UTC time, unless you specify a different timezone in the query context.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions)
Returns the current timestamp in the connection's time zone. * **Syntax:** `CURRENT_TIMESTAMP`
* **Function type:** Scalar, date and time
<details><summary>Example</summary>
The following example returns the current timestamp.
```sql
SELECT CURRENT_TIMESTAMP AS "current_timestamp"
```
Returns the following:
| `current_timestamp` |
| -- |
| `2024-08-14T21:30:13.793Z` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## DATE_TRUNC ## DATE_TRUNC
`DATE_TRUNC(<CHARACTER>, <TIMESTAMP>)`
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions)
Rounds down a timestamp by a given time unit. Rounds down a timestamp by a given time unit.
* **Syntax:** `DATE_TRUNC(unit, timestamp_expr)`
* **Function type:** Scalar, date and time
<details><summary>Example</summary>
The following example truncates a timestamp from the `__time` column from the `taxi-trips` datasource to the most recent `decade`.
```sql
SELECT
"__time" AS "original_timestamp",
DATE_TRUNC('decade', "__time") AS "truncate_timestamp"
FROM "taxi-trips"
LIMIT 1
```
Returns the following:
| `original_timestamp` | `truncate_time` |
| -- | -- |
| `2013-08-01T08:14:37.000Z` | `2010-01-01T00:00:00.000Z` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## DECODE_BASE64_COMPLEX ## DECODE_BASE64_COMPLEX
`DECODE_BASE64_COMPLEX(dataType, expr)` `DECODE_BASE64_COMPLEX(dataType, expr)`
@ -2623,35 +2680,121 @@ Returns a union of Theta sketches.
## TIME_CEIL ## TIME_CEIL
`TIME_CEIL(<TIMESTAMP>, <period>, [<origin>, [<timezone>]])` Rounds up a timestamp to a given ISO 8601 time period. You can specify `origin` to provide a reference timestamp from which to start rounding. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `TIME_CEIL(timestamp_expr, period[, origin[, timezone]])`
* **Function type:** Scalar, date and time
Rounds up a timestamp by a given time period, optionally from some reference time or timezone. <details><summary>Example</summary>
The following example rounds up the `__time` column from the `taxi-trips` datasource to the nearest 45th minute in reference to the timestamp `2013-08-01 08:0:00`.
```sql
SELECT
"__time" AS "original_timestamp",
TIME_CEIL("__time", 'PT45M', TIMESTAMP '2013-08-01 08:0:00') AS "time_ceiling"
FROM "taxi-trips"
LIMIT 2
```
Returns the following:
| `original_timestamp` | `time_ceiling` |
| -- | -- |
| `2013-08-01T08:14:37.000Z` | `2013-08-01T08:45:00.000Z` |
| `2013-08-01T09:13:00.000Z` | `2013-08-01T09:30:00.000Z` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## TIME_EXTRACT ## TIME_EXTRACT
`TIME_EXTRACT(<TIMESTAMP>, [<unit>, [<timezone>]])` Extracts the value of `unit` from the timestamp and returns it as a number. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `TIME_EXTRACT(timestamp_expr[, unit[, timezone]])`
* **Function type:** Scalar, date and time
Extracts the value of some unit of the timestamp and returns the number. <details><summary>Example</summary>
The following example extracts the hour from the `__time` column in the `taxi-trips` datasource and offsets its timezone by `-04:00` hours.
```sql
SELECT
"__time" AS "original_timestamp",
TIME_EXTRACT("__time", 'hour', '-04:00') AS "extract_hour"
FROM "taxi-trips"
LIMIT 2
```
Returns the following:
| `original_timestamp` | `extract_hour` |
| -- | -- |
| `2013-08-01T08:14:37.000Z` | `4` |
| `2013-08-01T09:13:00.000Z` | `5` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## TIME_FLOOR ## TIME_FLOOR
`TIME_FLOOR(<TIMESTAMP>, <period>, [<origin>, [<timezone>]])` Rounds down a timestamp to a given ISO 8601 time period. You can specify `origin` to provide a reference timestamp from which to start rounding. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `TIME_FLOOR(timestamp_expr, period[, origin[, timezone]])`
* **Function type:** Scalar, date and time
Rounds down a timestamp by a given time period, optionally from some reference time or timezone. <details><summary>Example</summary>
The following example rounds down the `__time` column from the `taxi-trips` datasource to the nearest 45th minute in reference to the timestamp `2013-08-01 08:0:00`.
```sql
SELECT
"__time" AS "original_timestamp",
TIME_FLOOR("__time", 'PT45M', TIMESTAMP '2013-08-01 08:0:00') AS "time_floor"
FROM "taxi-trips"
LIMIT 2
```
Returns the following:
| `original_timestamp` | `time_floor` |
| -- | -- |
| `2013-08-01T08:14:37.000Z` | `2013-08-01T08:00:00.000Z` |
| `2013-08-01T09:13:00.000Z` | `2013-08-01T08:45:00.000Z` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## TIME_FORMAT ## TIME_FORMAT
`TIME_FORMAT(<TIMESTAMP>, [<pattern>, [<timezone>]])` Formats a timestamp as a string in a provided [Joda DateTimeFormat pattern](http://www.joda.org/joda-time/apidocs/org/joda/time/format/DateTimeFormat.html). If no pattern is provided, `pattern` defaults to ISO 8601. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `TIME_FORMAT(timestamp_expr[, pattern[, timezone]])`
* **Function type:** Scalar, date and time
Formats a timestamp as a string. <details><summary>Example</summary>
The following example formats the `__time` column from the `flight-carriers` datasource into a string format and offsets the result's timezone by `-05:00` hours.
```sql
SELECT
"__time" AS "original_time",
TIME_FORMAT( "__time", 'dd-MM-YYYY hh:mm aa zzz', '-05:00') AS "string"
FROM "taxi-trips"
LIMIT 1
```
Returns the following:
| `original_time` | `string` |
| -- | -- |
| `2013-08-01T08:14:37.000Z` | `01-08-2013 03:14 AM -05:00` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## TIME_IN_INTERVAL ## TIME_IN_INTERVAL
@ -2663,19 +2806,62 @@ Returns whether a timestamp is contained within a particular interval, formatted
## TIME_PARSE ## TIME_PARSE
`TIME_PARSE(<string_expr>, [<pattern>, [<timezone>]])` Parses a string into a timestamp using a given [Joda DateTimeFormat pattern](http://www.joda.org/joda-time/apidocs/org/joda/time/format/DateTimeFormat.html). If no pattern is provided, `pattern` defaults to ISO 8601. Returns NULL if string cannot be parsed. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `TIME_PARSE(string_expr[, pattern[, timezone]])`
* **Function type:** Scalar, date and time
Parses a string into a timestamp. <details><summary>Example</summary>
The following example parses the `FlightDate` STRING column from the `flight-carriers` datasource into a valid timestamp with an offset of `-05:00` hours.
```sql
SELECT
"FlightDate" AS "original_string",
TIME_PARSE("FlightDate", 'YYYY-MM-dd', '-05:00') AS "timestamp"
FROM "flight-carriers"
LIMIT 1
```
Returns the following:
| `original_string` | `timestamp` |
| -- | -- |
| `2005-11-01` | `2005-11-01T05:00:00.000Z` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
## TIME_SHIFT ## TIME_SHIFT
`TIME_SHIFT(<TIMESTAMP>, <period>, <step>, [<timezone>])` Shifts a timestamp by a given number of time units. The `period` parameter can be any ISO 8601 period. The `step` parameter can be negative. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.
**Function type:** [Scalar, date and time](sql-scalar.md#date-and-time-functions) * **Syntax:** `TIME_SHIFT(timestamp_expr, period, step[, timezone])`
* **Function type:** Scalar, date and time
<details><summary>Example</summary>
The following example shifts the `__time` column from the `taxi-trips` datasource back by 24 hours.
```sql
SELECT
"__time" AS "original_timestamp",
TIME_SHIFT("__time", 'PT1H', -24) AS "shift_back"
FROM "taxi-trips"
LIMIT 1
```
Returns the following:
| `original_timestamp` | `shift_back` |
| -- | -- |
| `2013-08-01T08:14:37.000Z` | `2013-07-31T08:14:37.000Z` |
</details>
[Learn more](sql-scalar.md#date-and-time-functions)
Shifts a timestamp forwards or backwards by a given number of time units.
## TIMESTAMP_TO_MILLIS ## TIMESTAMP_TO_MILLIS

View File

@ -143,11 +143,11 @@ Literal timestamps in the connection time zone can be written using `TIMESTAMP '
simplest way to write literal timestamps in other time zones is to use TIME_PARSE, like simplest way to write literal timestamps in other time zones is to use TIME_PARSE, like
`TIME_PARSE('2000-02-01 00:00:00', NULL, 'America/Los_Angeles')`. `TIME_PARSE('2000-02-01 00:00:00', NULL, 'America/Los_Angeles')`.
The best ways to filter based on time are by using ISO8601 intervals, like The best way to filter based on time is by using ISO 8601 intervals, like
`TIME_IN_INTERVAL(__time, '2000-01-01/2000-02-01')`, or by using literal timestamps with the `>=` and `<` operators, like `TIME_IN_INTERVAL(__time, '2000-01-01/2000-02-01')`, or by using literal timestamps with the `>=` and `<` operators, like
`__time >= TIMESTAMP '2000-01-01 00:00:00' AND __time < TIMESTAMP '2000-02-01 00:00:00'`. `__time >= TIMESTAMP '2000-01-01 00:00:00' AND __time < TIMESTAMP '2000-02-01 00:00:00'`.
Druid supports the standard SQL BETWEEN operator, but we recommend avoiding it for time filters. BETWEEN is inclusive Druid supports the standard SQL `BETWEEN` operator, but we recommend avoiding it for time filters. `BETWEEN` is inclusive
of its upper bound, which makes it awkward to write time filters correctly. For example, the equivalent of of its upper bound, which makes it awkward to write time filters correctly. For example, the equivalent of
`TIME_IN_INTERVAL(__time, '2000-01-01/2000-02-01')` is `TIME_IN_INTERVAL(__time, '2000-01-01/2000-02-01')` is
`__time BETWEEN TIMESTAMP '2000-01-01 00:00:00' AND TIMESTAMP '2000-01-31 23:59:59.999'`. `__time BETWEEN TIMESTAMP '2000-01-01 00:00:00' AND TIMESTAMP '2000-01-31 23:59:59.999'`.
@ -160,16 +160,16 @@ overhead.
|Function|Notes| |Function|Notes|
|--------|-----| |--------|-----|
|`CURRENT_TIMESTAMP`|Current timestamp in the connection's time zone.| |`CURRENT_TIMESTAMP`|Current timestamp in UTC time, unless you specify a different timezone in the query context.|
|`CURRENT_DATE`|Current date in the connection's time zone.| |`CURRENT_DATE`|Current date in UTC time, unless you specify a different timezone in the query context.|
|`DATE_TRUNC(unit, timestamp_expr)`|Rounds down a timestamp, returning it as a new timestamp. Unit can be 'milliseconds', 'second', 'minute', 'hour', 'day', 'week', 'month', 'quarter', 'year', 'decade', 'century', or 'millennium'.| |`DATE_TRUNC(unit, timestamp_expr)`|Rounds down a timestamp, returning it as a new timestamp. Unit can be 'milliseconds', 'second', 'minute', 'hour', 'day', 'week', 'month', 'quarter', 'year', 'decade', 'century', or 'millennium'.|
|`TIME_CEIL(timestamp_expr, period[, origin[, timezone]])`|Rounds up a timestamp, returning it as a new timestamp. Period can be any ISO8601 period, like P3M (quarters) or PT12H (half-days). Specify `origin` as a timestamp to set the reference time for rounding. For example, `TIME_CEIL(__time, 'PT1H', TIMESTAMP '2016-06-27 00:30:00')` measures an hourly period from 00:30-01:30 instead of 00:00-01:00. See [Period granularities](granularities.md) for details on the default starting boundaries. The time zone, if provided, should be a time zone name like "America/Los_Angeles" or offset like "-08:00". This function is similar to `CEIL` but is more flexible.| |`TIME_CEIL(timestamp_expr, period[, origin[, timezone]])`|Rounds up a timestamp, returning it as a new timestamp. Period can be any ISO 8601 period, like P3M (quarters) or PT12H (half-days). Specify `origin` as a timestamp to set the reference time for rounding. For example, `TIME_CEIL(__time, 'PT1H', TIMESTAMP '2016-06-27 00:30:00')` measures an hourly period from 00:30-01:30 instead of 00:00-01:00. See [Period granularities](granularities.md) for details on the default starting boundaries. The time zone, if provided, should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`. This function is similar to `CEIL` but is more flexible.|
|`TIME_FLOOR(timestamp_expr, period[, origin[, timezone]])`|Rounds down a timestamp, returning it as a new timestamp. Period can be any ISO8601 period, like P3M (quarters) or PT12H (half-days). Specify `origin` as a timestamp to set the reference time for rounding. For example, `TIME_FLOOR(__time, 'PT1H', TIMESTAMP '2016-06-27 00:30:00')` measures an hourly period from 00:30-01:30 instead of 00:00-01:00. See [Period granularities](granularities.md) for details on the default starting boundaries. The time zone, if provided, should be a time zone name like "America/Los_Angeles" or offset like "-08:00". This function is similar to `FLOOR` but is more flexible.| |`TIME_FLOOR(timestamp_expr, period[, origin[, timezone]])`|Rounds down a timestamp, returning it as a new timestamp. Period can be any ISO 8601 period, like P3M (quarters) or PT12H (half-days). Specify `origin` as a timestamp to set the reference time for rounding. For example, `TIME_FLOOR(__time, 'PT1H', TIMESTAMP '2016-06-27 00:30:00')` measures an hourly period from 00:30-01:30 instead of 00:00-01:00. See [Period granularities](granularities.md) for details on the default starting boundaries. The time zone, if provided, should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`. This function is similar to `FLOOR` but is more flexible.|
|`TIME_SHIFT(timestamp_expr, period, step[, timezone])`|Shifts a timestamp by a period (step times), returning it as a new timestamp. Period can be any ISO8601 period. Step may be negative. The time zone, if provided, should be a time zone name like "America/Los_Angeles" or offset like "-08:00".| |`TIME_SHIFT(timestamp_expr, period, step[, timezone])`|Shifts a timestamp by a period (step times), returning it as a new timestamp. The `period` parameter can be any ISO 8601 period. The `step` parameter can be negative. The time zone, if provided, should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`.|
|`TIME_EXTRACT(timestamp_expr[, unit[, timezone]])`|Extracts a time part from `expr`, returning it as a number. Unit can be EPOCH, SECOND, MINUTE, HOUR, DAY (day of month), DOW (day of week), DOY (day of year), WEEK (week of [week year](https://en.wikipedia.org/wiki/ISO_week_date)), MONTH (1 through 12), QUARTER (1 through 4), or YEAR. The time zone, if provided, should be a time zone name like "America/Los_Angeles" or offset like "-08:00". This function is similar to `EXTRACT` but is more flexible. Unit and time zone must be literals, and must be provided quoted, like `TIME_EXTRACT(__time, 'HOUR')` or `TIME_EXTRACT(__time, 'HOUR', 'America/Los_Angeles')`.| |`TIME_EXTRACT(timestamp_expr, unit[, timezone])`|Extracts a time part from `expr`, returning it as a number. Unit can be EPOCH, SECOND, MINUTE, HOUR, DAY (day of month), DOW (day of week), DOY (day of year), WEEK (week of [week year](https://en.wikipedia.org/wiki/ISO_week_date)), MONTH (1 through 12), QUARTER (1 through 4), or YEAR. The time zone, if provided, should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`. The `unit` and `timezone` parameters must be provided as quoted literals, such as `TIME_EXTRACT(__time, 'HOUR')` or `TIME_EXTRACT(__time, 'HOUR', 'America/Los_Angeles')`. This function is similar to `EXTRACT` but is more flexible. |
|`TIME_PARSE(string_expr[, pattern[, timezone]])`|Parses a string into a timestamp using a given [Joda DateTimeFormat pattern](http://www.joda.org/joda-time/apidocs/org/joda/time/format/DateTimeFormat.html), or ISO8601 (e.g. `2000-01-02T03:04:05Z`) if the pattern is not provided. The time zone, if provided, should be a time zone name like "America/Los_Angeles" or offset like "-08:00", and will be used as the time zone for strings that do not include a time zone offset. Pattern and time zone must be literals. Strings that cannot be parsed as timestamps will be returned as NULL.| |`TIME_PARSE(string_expr[, pattern[, timezone]])`|Parses a string into a timestamp using a given [Joda DateTimeFormat pattern](http://www.joda.org/joda-time/apidocs/org/joda/time/format/DateTimeFormat.html), or ISO 8601 (e.g. `2000-01-02T03:04:05Z`) if the pattern is not provided. The `timezone` parameter is used as the time zone for strings that do not already include a time zone offset. If provided, `timezone` should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`. The `pattern` and `timezone` parameters must be literals. Strings that cannot be parsed as timestamps return NULL.|
|`TIME_FORMAT(timestamp_expr[, pattern[, timezone]])`|Formats a timestamp as a string with a given [Joda DateTimeFormat pattern](http://www.joda.org/joda-time/apidocs/org/joda/time/format/DateTimeFormat.html), or ISO8601 (e.g. `2000-01-02T03:04:05Z`) if the pattern is not provided. The time zone, if provided, should be a time zone name like "America/Los_Angeles" or offset like "-08:00". Pattern and time zone must be literals.| |`TIME_FORMAT(timestamp_expr[, pattern[, timezone]])`|Formats a timestamp as a string with a given [Joda DateTimeFormat pattern](http://www.joda.org/joda-time/apidocs/org/joda/time/format/DateTimeFormat.html), or ISO 8601 (e.g. `2000-01-02T03:04:05Z`) if the pattern is not provided. If provided, the `timezone` parameter should be a time zone name like `America/Los_Angeles` or an offset like `-08:00`. The `pattern` and `timezone` parameters must be literals.|
|`TIME_IN_INTERVAL(timestamp_expr, interval)`|Returns whether a timestamp is contained within a particular interval. The interval must be a literal string containing any ISO8601 interval, such as `'2001-01-01/P1D'` or `'2001-01-01T01:00:00/2001-01-02T01:00:00'`. The start instant of the interval is inclusive and the end instant is exclusive.| |`TIME_IN_INTERVAL(timestamp_expr, interval)`|Returns whether a timestamp is contained within a particular interval. The interval must be a literal string containing any ISO 8601 interval, such as `'2001-01-01/P1D'` or `'2001-01-01T01:00:00/2001-01-02T01:00:00'`. The start instant of the interval is inclusive and the end instant is exclusive.|
|`MILLIS_TO_TIMESTAMP(millis_expr)`|Converts a number of milliseconds since the epoch (1970-01-01 00:00:00 UTC) into a timestamp.| |`MILLIS_TO_TIMESTAMP(millis_expr)`|Converts a number of milliseconds since the epoch (1970-01-01 00:00:00 UTC) into a timestamp.|
|`TIMESTAMP_TO_MILLIS(timestamp_expr)`|Converts a timestamp into a number of milliseconds since the epoch.| |`TIMESTAMP_TO_MILLIS(timestamp_expr)`|Converts a timestamp into a number of milliseconds since the epoch.|
|`EXTRACT(unit FROM timestamp_expr)`|Extracts a time part from `expr`, returning it as a number. Unit can be EPOCH, MICROSECOND, MILLISECOND, SECOND, MINUTE, HOUR, DAY (day of month), DOW (day of week), ISODOW (ISO day of week), DOY (day of year), WEEK (week of year), MONTH, QUARTER, YEAR, ISOYEAR, DECADE, CENTURY or MILLENNIUM. Units must be provided unquoted, like `EXTRACT(HOUR FROM __time)`.| |`EXTRACT(unit FROM timestamp_expr)`|Extracts a time part from `expr`, returning it as a number. Unit can be EPOCH, MICROSECOND, MILLISECOND, SECOND, MINUTE, HOUR, DAY (day of month), DOW (day of week), ISODOW (ISO day of week), DOY (day of year), WEEK (week of year), MONTH, QUARTER, YEAR, ISOYEAR, DECADE, CENTURY or MILLENNIUM. Units must be provided unquoted, like `EXTRACT(HOUR FROM __time)`.|