mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-10 09:32:06 +00:00
commit
f2cad33f1b
@ -410,35 +410,35 @@ Converts a date with time to a certain fixed date, while preserving the time.
|
|||||||
|
|
||||||
## toRelativeYearNum
|
## toRelativeYearNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the year, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the year, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeQuarterNum
|
## toRelativeQuarterNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the quarter, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the quarter, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeMonthNum
|
## toRelativeMonthNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the month, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the month, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeWeekNum
|
## toRelativeWeekNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the week, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the week, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeDayNum
|
## toRelativeDayNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the day, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the day, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeHourNum
|
## toRelativeHourNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the hour, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the hour, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeMinuteNum
|
## toRelativeMinuteNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the minute, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the minute, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toRelativeSecondNum
|
## toRelativeSecondNum
|
||||||
|
|
||||||
Converts a date with time or date to the number of the second, starting from a certain fixed point in the past.
|
Converts a date or date with time to the number of the second, starting from a certain fixed point in the past.
|
||||||
|
|
||||||
## toISOYear
|
## toISOYear
|
||||||
|
|
||||||
@ -517,6 +517,154 @@ SELECT toDate('2016-12-27') AS date, toYearWeek(date) AS yearWeek0, toYearWeek(d
|
|||||||
└────────────┴───────────┴───────────┴───────────┘
|
└────────────┴───────────┴───────────┴───────────┘
|
||||||
```
|
```
|
||||||
|
|
||||||
|
## age
|
||||||
|
|
||||||
|
Returns the `unit` component of the difference between `startdate` and `enddate`. The difference is calculated using a precision of 1 second.
|
||||||
|
E.g. the difference between `2021-12-29` and `2022-01-01` is 3 days for `day` unit, 0 months for `month` unit, 0 years for `year` unit.
|
||||||
|
|
||||||
|
|
||||||
|
**Syntax**
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
age('unit', startdate, enddate, [timezone])
|
||||||
|
```
|
||||||
|
|
||||||
|
**Arguments**
|
||||||
|
|
||||||
|
- `unit` — The type of interval for result. [String](../../sql-reference/data-types/string.md).
|
||||||
|
Possible values:
|
||||||
|
|
||||||
|
- `second` (possible abbreviations: `ss`, `s`)
|
||||||
|
- `minute` (possible abbreviations: `mi`, `n`)
|
||||||
|
- `hour` (possible abbreviations: `hh`, `h`)
|
||||||
|
- `day` (possible abbreviations: `dd`, `d`)
|
||||||
|
- `week` (possible abbreviations: `wk`, `ww`)
|
||||||
|
- `month` (possible abbreviations: `mm`, `m`)
|
||||||
|
- `quarter` (possible abbreviations: `qq`, `q`)
|
||||||
|
- `year` (possible abbreviations: `yyyy`, `yy`)
|
||||||
|
|
||||||
|
- `startdate` — The first time value to subtract (the subtrahend). [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `enddate` — The second time value to subtract from (the minuend). [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `timezone` — [Timezone name](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone) (optional). If specified, it is applied to both `startdate` and `enddate`. If not specified, timezones of `startdate` and `enddate` are used. If they are not the same, the result is unspecified. [String](../../sql-reference/data-types/string.md).
|
||||||
|
|
||||||
|
**Returned value**
|
||||||
|
|
||||||
|
Difference between `enddate` and `startdate` expressed in `unit`.
|
||||||
|
|
||||||
|
Type: [Int](../../sql-reference/data-types/int-uint.md).
|
||||||
|
|
||||||
|
**Example**
|
||||||
|
|
||||||
|
Query:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT age('hour', toDateTime('2018-01-01 22:30:00'), toDateTime('2018-01-02 23:00:00'));
|
||||||
|
```
|
||||||
|
|
||||||
|
Result:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌─age('hour', toDateTime('2018-01-01 22:30:00'), toDateTime('2018-01-02 23:00:00'))─┐
|
||||||
|
│ 24 │
|
||||||
|
└───────────────────────────────────────────────────────────────────────────────────┘
|
||||||
|
```
|
||||||
|
|
||||||
|
Query:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT
|
||||||
|
toDate('2022-01-01') AS e,
|
||||||
|
toDate('2021-12-29') AS s,
|
||||||
|
age('day', s, e) AS day_age,
|
||||||
|
age('month', s, e) AS month__age,
|
||||||
|
age('year', s, e) AS year_age;
|
||||||
|
```
|
||||||
|
|
||||||
|
Result:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌──────────e─┬──────────s─┬─day_age─┬─month__age─┬─year_age─┐
|
||||||
|
│ 2022-01-01 │ 2021-12-29 │ 3 │ 0 │ 0 │
|
||||||
|
└────────────┴────────────┴─────────┴────────────┴──────────┘
|
||||||
|
```
|
||||||
|
|
||||||
|
|
||||||
|
## date\_diff
|
||||||
|
|
||||||
|
Returns the count of the specified `unit` boundaries crossed between the `startdate` and `enddate`.
|
||||||
|
The difference is calculated using relative units, e.g. the difference between `2021-12-29` and `2022-01-01` is 3 days for day unit (see [toRelativeDayNum](#torelativedaynum)), 1 month for month unit (see [toRelativeMonthNum](#torelativemonthnum)), 1 year for year unit (see [toRelativeYearNum](#torelativeyearnum)).
|
||||||
|
|
||||||
|
**Syntax**
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
date_diff('unit', startdate, enddate, [timezone])
|
||||||
|
```
|
||||||
|
|
||||||
|
Aliases: `dateDiff`, `DATE_DIFF`.
|
||||||
|
|
||||||
|
**Arguments**
|
||||||
|
|
||||||
|
- `unit` — The type of interval for result. [String](../../sql-reference/data-types/string.md).
|
||||||
|
Possible values:
|
||||||
|
|
||||||
|
- `second` (possible abbreviations: `ss`, `s`)
|
||||||
|
- `minute` (possible abbreviations: `mi`, `n`)
|
||||||
|
- `hour` (possible abbreviations: `hh`, `h`)
|
||||||
|
- `day` (possible abbreviations: `dd`, `d`)
|
||||||
|
- `week` (possible abbreviations: `wk`, `ww`)
|
||||||
|
- `month` (possible abbreviations: `mm`, `m`)
|
||||||
|
- `quarter` (possible abbreviations: `qq`, `q`)
|
||||||
|
- `year` (possible abbreviations: `yyyy`, `yy`)
|
||||||
|
|
||||||
|
- `startdate` — The first time value to subtract (the subtrahend). [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `enddate` — The second time value to subtract from (the minuend). [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `timezone` — [Timezone name](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone) (optional). If specified, it is applied to both `startdate` and `enddate`. If not specified, timezones of `startdate` and `enddate` are used. If they are not the same, the result is unspecified. [String](../../sql-reference/data-types/string.md).
|
||||||
|
|
||||||
|
**Returned value**
|
||||||
|
|
||||||
|
Difference between `enddate` and `startdate` expressed in `unit`.
|
||||||
|
|
||||||
|
Type: [Int](../../sql-reference/data-types/int-uint.md).
|
||||||
|
|
||||||
|
**Example**
|
||||||
|
|
||||||
|
Query:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'));
|
||||||
|
```
|
||||||
|
|
||||||
|
Result:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌─dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'))─┐
|
||||||
|
│ 25 │
|
||||||
|
└────────────────────────────────────────────────────────────────────────────────────────┘
|
||||||
|
```
|
||||||
|
|
||||||
|
Query:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT
|
||||||
|
toDate('2022-01-01') AS e,
|
||||||
|
toDate('2021-12-29') AS s,
|
||||||
|
dateDiff('day', s, e) AS day_diff,
|
||||||
|
dateDiff('month', s, e) AS month__diff,
|
||||||
|
dateDiff('year', s, e) AS year_diff;
|
||||||
|
```
|
||||||
|
|
||||||
|
Result:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌──────────e─┬──────────s─┬─day_diff─┬─month__diff─┬─year_diff─┐
|
||||||
|
│ 2022-01-01 │ 2021-12-29 │ 3 │ 1 │ 1 │
|
||||||
|
└────────────┴────────────┴──────────┴─────────────┴───────────┘
|
||||||
|
```
|
||||||
|
|
||||||
## date\_trunc
|
## date\_trunc
|
||||||
|
|
||||||
Truncates date and time data to the specified part of date.
|
Truncates date and time data to the specified part of date.
|
||||||
@ -637,80 +785,6 @@ Result:
|
|||||||
└───────────────────────────────────────────────┘
|
└───────────────────────────────────────────────┘
|
||||||
```
|
```
|
||||||
|
|
||||||
## date\_diff
|
|
||||||
|
|
||||||
Returns the difference between two dates or dates with time values.
|
|
||||||
The difference is calculated using relative units, e.g. the difference between `2022-01-01` and `2021-12-29` is 3 days for day unit (see [toRelativeDayNum](#torelativedaynum)), 1 month for month unit (see [toRelativeMonthNum](#torelativemonthnum)), 1 year for year unit (see [toRelativeYearNum](#torelativeyearnum)).
|
|
||||||
|
|
||||||
**Syntax**
|
|
||||||
|
|
||||||
``` sql
|
|
||||||
date_diff('unit', startdate, enddate, [timezone])
|
|
||||||
```
|
|
||||||
|
|
||||||
Aliases: `dateDiff`, `DATE_DIFF`.
|
|
||||||
|
|
||||||
**Arguments**
|
|
||||||
|
|
||||||
- `unit` — The type of interval for result. [String](../../sql-reference/data-types/string.md).
|
|
||||||
Possible values:
|
|
||||||
|
|
||||||
- `second`
|
|
||||||
- `minute`
|
|
||||||
- `hour`
|
|
||||||
- `day`
|
|
||||||
- `week`
|
|
||||||
- `month`
|
|
||||||
- `quarter`
|
|
||||||
- `year`
|
|
||||||
|
|
||||||
- `startdate` — The first time value to subtract (the subtrahend). [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
|
|
||||||
|
|
||||||
- `enddate` — The second time value to subtract from (the minuend). [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
|
|
||||||
|
|
||||||
- `timezone` — [Timezone name](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone) (optional). If specified, it is applied to both `startdate` and `enddate`. If not specified, timezones of `startdate` and `enddate` are used. If they are not the same, the result is unspecified. [String](../../sql-reference/data-types/string.md).
|
|
||||||
|
|
||||||
**Returned value**
|
|
||||||
|
|
||||||
Difference between `enddate` and `startdate` expressed in `unit`.
|
|
||||||
|
|
||||||
Type: [Int](../../sql-reference/data-types/int-uint.md).
|
|
||||||
|
|
||||||
**Example**
|
|
||||||
|
|
||||||
Query:
|
|
||||||
|
|
||||||
``` sql
|
|
||||||
SELECT dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'));
|
|
||||||
```
|
|
||||||
|
|
||||||
Result:
|
|
||||||
|
|
||||||
``` text
|
|
||||||
┌─dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'))─┐
|
|
||||||
│ 25 │
|
|
||||||
└────────────────────────────────────────────────────────────────────────────────────────┘
|
|
||||||
```
|
|
||||||
|
|
||||||
Query:
|
|
||||||
|
|
||||||
``` sql
|
|
||||||
SELECT
|
|
||||||
toDate('2022-01-01') AS e,
|
|
||||||
toDate('2021-12-29') AS s,
|
|
||||||
dateDiff('day', s, e) AS day_diff,
|
|
||||||
dateDiff('month', s, e) AS month__diff,
|
|
||||||
dateDiff('year', s, e) AS year_diff;
|
|
||||||
```
|
|
||||||
|
|
||||||
Result:
|
|
||||||
|
|
||||||
``` text
|
|
||||||
┌──────────e─┬──────────s─┬─day_diff─┬─month__diff─┬─year_diff─┐
|
|
||||||
│ 2022-01-01 │ 2021-12-29 │ 3 │ 1 │ 1 │
|
|
||||||
└────────────┴────────────┴──────────┴─────────────┴───────────┘
|
|
||||||
```
|
|
||||||
|
|
||||||
## date\_sub
|
## date\_sub
|
||||||
|
|
||||||
Subtracts the time interval or date interval from the provided date or date with time.
|
Subtracts the time interval or date interval from the provided date or date with time.
|
||||||
|
@ -424,23 +424,23 @@ WITH toDateTime64('2020-01-01 10:20:30.999', 3) AS dt64 SELECT toStartOfSecond(d
|
|||||||
|
|
||||||
## toRelativeYearNum {#torelativeyearnum}
|
## toRelativeYearNum {#torelativeyearnum}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в номер года, начиная с некоторого фиксированного момента в прошлом.
|
Переводит дату или дату-с-временем в номер года, начиная с некоторого фиксированного момента в прошлом.
|
||||||
|
|
||||||
## toRelativeQuarterNum {#torelativequarternum}
|
## toRelativeQuarterNum {#torelativequarternum}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в номер квартала, начиная с некоторого фиксированного момента в прошлом.
|
Переводит дату или дату-с-временем в номер квартала, начиная с некоторого фиксированного момента в прошлом.
|
||||||
|
|
||||||
## toRelativeMonthNum {#torelativemonthnum}
|
## toRelativeMonthNum {#torelativemonthnum}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в номер месяца, начиная с некоторого фиксированного момента в прошлом.
|
Переводит дату или дату-с-временем в номер месяца, начиная с некоторого фиксированного момента в прошлом.
|
||||||
|
|
||||||
## toRelativeWeekNum {#torelativeweeknum}
|
## toRelativeWeekNum {#torelativeweeknum}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в номер недели, начиная с некоторого фиксированного момента в прошлом.
|
Переводит дату или дату-с-временем в номер недели, начиная с некоторого фиксированного момента в прошлом.
|
||||||
|
|
||||||
## toRelativeDayNum {#torelativedaynum}
|
## toRelativeDayNum {#torelativedaynum}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в номер дня, начиная с некоторого фиксированного момента в прошлом.
|
Переводит дату или дату-с-временем в номер дня, начиная с некоторого фиксированного момента в прошлом.
|
||||||
|
|
||||||
## toRelativeHourNum {#torelativehournum}
|
## toRelativeHourNum {#torelativehournum}
|
||||||
|
|
||||||
@ -456,7 +456,7 @@ WITH toDateTime64('2020-01-01 10:20:30.999', 3) AS dt64 SELECT toStartOfSecond(d
|
|||||||
|
|
||||||
## toISOYear {#toisoyear}
|
## toISOYear {#toisoyear}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в число типа UInt16, содержащее номер ISO года. ISO год отличается от обычного года, потому что в соответствии с [ISO 8601:1988](https://en.wikipedia.org/wiki/ISO_8601) ISO год начинается необязательно первого января.
|
Переводит дату или дату-с-временем в число типа UInt16, содержащее номер ISO года. ISO год отличается от обычного года, потому что в соответствии с [ISO 8601:1988](https://en.wikipedia.org/wiki/ISO_8601) ISO год начинается необязательно первого января.
|
||||||
|
|
||||||
**Пример**
|
**Пример**
|
||||||
|
|
||||||
@ -479,7 +479,7 @@ SELECT
|
|||||||
|
|
||||||
## toISOWeek {#toisoweek}
|
## toISOWeek {#toisoweek}
|
||||||
|
|
||||||
Переводит дату-с-временем или дату в число типа UInt8, содержащее номер ISO недели.
|
Переводит дату или дату-с-временем в число типа UInt8, содержащее номер ISO недели.
|
||||||
Начало ISO года отличается от начала обычного года, потому что в соответствии с [ISO 8601:1988](https://en.wikipedia.org/wiki/ISO_8601) первая неделя года - это неделя с четырьмя или более днями в этом году.
|
Начало ISO года отличается от начала обычного года, потому что в соответствии с [ISO 8601:1988](https://en.wikipedia.org/wiki/ISO_8601) первая неделя года - это неделя с четырьмя или более днями в этом году.
|
||||||
|
|
||||||
1 Января 2017 г. - воскресение, т.е. первая ISO неделя 2017 года началась в понедельник 2 января, поэтому 1 января 2017 это последняя неделя 2016 года.
|
1 Января 2017 г. - воскресение, т.е. первая ISO неделя 2017 года началась в понедельник 2 января, поэтому 1 января 2017 это последняя неделя 2016 года.
|
||||||
@ -503,7 +503,7 @@ SELECT
|
|||||||
```
|
```
|
||||||
|
|
||||||
## toWeek(date\[, mode\]\[, timezone\]) {#toweek}
|
## toWeek(date\[, mode\]\[, timezone\]) {#toweek}
|
||||||
Переводит дату-с-временем или дату в число UInt8, содержащее номер недели. Второй аргументам mode задает режим, начинается ли неделя с воскресенья или с понедельника и должно ли возвращаемое значение находиться в диапазоне от 0 до 53 или от 1 до 53. Если аргумент mode опущен, то используется режим 0.
|
Переводит дату или дату-с-временем в число UInt8, содержащее номер недели. Второй аргументам mode задает режим, начинается ли неделя с воскресенья или с понедельника и должно ли возвращаемое значение находиться в диапазоне от 0 до 53 или от 1 до 53. Если аргумент mode опущен, то используется режим 0.
|
||||||
|
|
||||||
`toISOWeek() ` эквивалентно `toWeek(date,3)`.
|
`toISOWeek() ` эквивалентно `toWeek(date,3)`.
|
||||||
|
|
||||||
@ -569,6 +569,132 @@ SELECT toDate('2016-12-27') AS date, toYearWeek(date) AS yearWeek0, toYearWeek(d
|
|||||||
└────────────┴───────────┴───────────┴───────────┘
|
└────────────┴───────────┴───────────┴───────────┘
|
||||||
```
|
```
|
||||||
|
|
||||||
|
## age
|
||||||
|
|
||||||
|
Вычисляет компонент `unit` разницы между `startdate` и `enddate`. Разница вычисляется с точностью в 1 секунду.
|
||||||
|
Например, разница между `2021-12-29` и `2022-01-01` 3 дня для единицы `day`, 0 месяцев для единицы `month`, 0 лет для единицы `year`.
|
||||||
|
|
||||||
|
**Синтаксис**
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
age('unit', startdate, enddate, [timezone])
|
||||||
|
```
|
||||||
|
|
||||||
|
**Аргументы**
|
||||||
|
|
||||||
|
- `unit` — единица измерения времени, в которой будет выражено возвращаемое значение функции. [String](../../sql-reference/data-types/string.md).
|
||||||
|
Возможные значения:
|
||||||
|
|
||||||
|
- `second` (возможные сокращения: `ss`, `s`)
|
||||||
|
- `minute` (возможные сокращения: `mi`, `n`)
|
||||||
|
- `hour` (возможные сокращения: `hh`, `h`)
|
||||||
|
- `day` (возможные сокращения: `dd`, `d`)
|
||||||
|
- `week` (возможные сокращения: `wk`, `ww`)
|
||||||
|
- `month` (возможные сокращения: `mm`, `m`)
|
||||||
|
- `quarter` (возможные сокращения: `qq`, `q`)
|
||||||
|
- `year` (возможные сокращения: `yyyy`, `yy`)
|
||||||
|
|
||||||
|
- `startdate` — первая дата или дата со временем, которая вычитается из `enddate`. [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) или [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `enddate` — вторая дата или дата со временем, из которой вычитается `startdate`. [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) или [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `timezone` — [часовой пояс](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone) (необязательно). Если этот аргумент указан, то он применяется как для `startdate`, так и для `enddate`. Если этот аргумент не указан, то используются часовые пояса аргументов `startdate` и `enddate`. Если часовые пояса аргументов `startdate` и `enddate` не совпадают, то результат не определен. [String](../../sql-reference/data-types/string.md).
|
||||||
|
|
||||||
|
**Возвращаемое значение**
|
||||||
|
|
||||||
|
Разница между `enddate` и `startdate`, выраженная в `unit`.
|
||||||
|
|
||||||
|
Тип: [Int](../../sql-reference/data-types/int-uint.md).
|
||||||
|
|
||||||
|
**Пример**
|
||||||
|
|
||||||
|
Запрос:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT age('hour', toDateTime('2018-01-01 22:30:00'), toDateTime('2018-01-02 23:00:00'));
|
||||||
|
```
|
||||||
|
|
||||||
|
Результат:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌─age('hour', toDateTime('2018-01-01 22:30:00'), toDateTime('2018-01-02 23:00:00'))─┐
|
||||||
|
│ 24 │
|
||||||
|
└───────────────────────────────────────────────────────────────────────────────────┘
|
||||||
|
```
|
||||||
|
|
||||||
|
Запрос:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT
|
||||||
|
toDate('2022-01-01') AS e,
|
||||||
|
toDate('2021-12-29') AS s,
|
||||||
|
age('day', s, e) AS day_age,
|
||||||
|
age('month', s, e) AS month__age,
|
||||||
|
age('year', s, e) AS year_age;
|
||||||
|
```
|
||||||
|
|
||||||
|
Результат:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌──────────e─┬──────────s─┬─day_age─┬─month__age─┬─year_age─┐
|
||||||
|
│ 2022-01-01 │ 2021-12-29 │ 3 │ 0 │ 0 │
|
||||||
|
└────────────┴────────────┴─────────┴────────────┴──────────┘
|
||||||
|
```
|
||||||
|
|
||||||
|
## date\_diff {#date_diff}
|
||||||
|
|
||||||
|
Вычисляет разницу указанных границ `unit` пересекаемых между `startdate` и `enddate`.
|
||||||
|
|
||||||
|
**Синтаксис**
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
date_diff('unit', startdate, enddate, [timezone])
|
||||||
|
```
|
||||||
|
|
||||||
|
Синонимы: `dateDiff`, `DATE_DIFF`.
|
||||||
|
|
||||||
|
**Аргументы**
|
||||||
|
|
||||||
|
- `unit` — единица измерения времени, в которой будет выражено возвращаемое значение функции. [String](../../sql-reference/data-types/string.md).
|
||||||
|
Возможные значения:
|
||||||
|
|
||||||
|
- `second` (возможные сокращения: `ss`, `s`)
|
||||||
|
- `minute` (возможные сокращения: `mi`, `n`)
|
||||||
|
- `hour` (возможные сокращения: `hh`, `h`)
|
||||||
|
- `day` (возможные сокращения: `dd`, `d`)
|
||||||
|
- `week` (возможные сокращения: `wk`, `ww`)
|
||||||
|
- `month` (возможные сокращения: `mm`, `m`)
|
||||||
|
- `quarter` (возможные сокращения: `qq`, `q`)
|
||||||
|
- `year` (возможные сокращения: `yyyy`, `yy`)
|
||||||
|
|
||||||
|
- `startdate` — первая дата или дата со временем, которая вычитается из `enddate`. [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) или [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `enddate` — вторая дата или дата со временем, из которой вычитается `startdate`. [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) или [DateTime64](../../sql-reference/data-types/datetime64.md).
|
||||||
|
|
||||||
|
- `timezone` — [часовой пояс](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone) (необязательно). Если этот аргумент указан, то он применяется как для `startdate`, так и для `enddate`. Если этот аргумент не указан, то используются часовые пояса аргументов `startdate` и `enddate`. Если часовые пояса аргументов `startdate` и `enddate` не совпадают, то результат не определен. [String](../../sql-reference/data-types/string.md).
|
||||||
|
|
||||||
|
**Возвращаемое значение**
|
||||||
|
|
||||||
|
Разница между `enddate` и `startdate`, выраженная в `unit`.
|
||||||
|
|
||||||
|
Тип: [Int](../../sql-reference/data-types/int-uint.md).
|
||||||
|
|
||||||
|
**Пример**
|
||||||
|
|
||||||
|
Запрос:
|
||||||
|
|
||||||
|
``` sql
|
||||||
|
SELECT dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'));
|
||||||
|
```
|
||||||
|
|
||||||
|
Результат:
|
||||||
|
|
||||||
|
``` text
|
||||||
|
┌─dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'))─┐
|
||||||
|
│ 25 │
|
||||||
|
└────────────────────────────────────────────────────────────────────────────────────────┘
|
||||||
|
```
|
||||||
|
|
||||||
## date_trunc {#date_trunc}
|
## date_trunc {#date_trunc}
|
||||||
|
|
||||||
Отсекает от даты и времени части, меньшие чем указанная часть.
|
Отсекает от даты и времени части, меньшие чем указанная часть.
|
||||||
@ -689,60 +815,6 @@ SELECT date_add(YEAR, 3, toDate('2018-01-01'));
|
|||||||
└───────────────────────────────────────────────┘
|
└───────────────────────────────────────────────┘
|
||||||
```
|
```
|
||||||
|
|
||||||
## date\_diff {#date_diff}
|
|
||||||
|
|
||||||
Вычисляет разницу между двумя значениями дат или дат со временем.
|
|
||||||
|
|
||||||
**Синтаксис**
|
|
||||||
|
|
||||||
``` sql
|
|
||||||
date_diff('unit', startdate, enddate, [timezone])
|
|
||||||
```
|
|
||||||
|
|
||||||
Синонимы: `dateDiff`, `DATE_DIFF`.
|
|
||||||
|
|
||||||
**Аргументы**
|
|
||||||
|
|
||||||
- `unit` — единица измерения времени, в которой будет выражено возвращаемое значение функции. [String](../../sql-reference/data-types/string.md).
|
|
||||||
Возможные значения:
|
|
||||||
|
|
||||||
- `second`
|
|
||||||
- `minute`
|
|
||||||
- `hour`
|
|
||||||
- `day`
|
|
||||||
- `week`
|
|
||||||
- `month`
|
|
||||||
- `quarter`
|
|
||||||
- `year`
|
|
||||||
|
|
||||||
- `startdate` — первая дата или дата со временем, которая вычитается из `enddate`. [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) или [DateTime64](../../sql-reference/data-types/datetime64.md).
|
|
||||||
|
|
||||||
- `enddate` — вторая дата или дата со временем, из которой вычитается `startdate`. [Date](../../sql-reference/data-types/date.md), [Date32](../../sql-reference/data-types/date32.md), [DateTime](../../sql-reference/data-types/datetime.md) или [DateTime64](../../sql-reference/data-types/datetime64.md).
|
|
||||||
|
|
||||||
- `timezone` — [часовой пояс](../../operations/server-configuration-parameters/settings.md#server_configuration_parameters-timezone) (необязательно). Если этот аргумент указан, то он применяется как для `startdate`, так и для `enddate`. Если этот аргумент не указан, то используются часовые пояса аргументов `startdate` и `enddate`. Если часовые пояса аргументов `startdate` и `enddate` не совпадают, то результат не определен. [String](../../sql-reference/data-types/string.md).
|
|
||||||
|
|
||||||
**Возвращаемое значение**
|
|
||||||
|
|
||||||
Разница между `enddate` и `startdate`, выраженная в `unit`.
|
|
||||||
|
|
||||||
Тип: [Int](../../sql-reference/data-types/int-uint.md).
|
|
||||||
|
|
||||||
**Пример**
|
|
||||||
|
|
||||||
Запрос:
|
|
||||||
|
|
||||||
``` sql
|
|
||||||
SELECT dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'));
|
|
||||||
```
|
|
||||||
|
|
||||||
Результат:
|
|
||||||
|
|
||||||
``` text
|
|
||||||
┌─dateDiff('hour', toDateTime('2018-01-01 22:00:00'), toDateTime('2018-01-02 23:00:00'))─┐
|
|
||||||
│ 25 │
|
|
||||||
└────────────────────────────────────────────────────────────────────────────────────────┘
|
|
||||||
```
|
|
||||||
|
|
||||||
## date\_sub {#date_sub}
|
## date\_sub {#date_sub}
|
||||||
|
|
||||||
Вычитает интервал времени или даты из указанной даты или даты со временем.
|
Вычитает интервал времени или даты из указанной даты или даты со временем.
|
||||||
|
@ -1204,6 +1204,11 @@ public:
|
|||||||
return res;
|
return res;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
template <typename DateOrTime>
|
||||||
|
inline DateTimeComponents toDateTimeComponents(DateOrTime v) const
|
||||||
|
{
|
||||||
|
return toDateTimeComponents(lut[toLUTIndex(v)].date);
|
||||||
|
}
|
||||||
|
|
||||||
inline UInt64 toNumYYYYMMDDhhmmss(Time t) const
|
inline UInt64 toNumYYYYMMDDhhmmss(Time t) const
|
||||||
{
|
{
|
||||||
|
@ -1343,6 +1343,30 @@ struct ToYYYYMMDDhhmmssImpl
|
|||||||
using FactorTransform = ZeroTransform;
|
using FactorTransform = ZeroTransform;
|
||||||
};
|
};
|
||||||
|
|
||||||
|
struct ToDateTimeComponentsImpl
|
||||||
|
{
|
||||||
|
static constexpr auto name = "toDateTimeComponents";
|
||||||
|
|
||||||
|
static inline DateLUTImpl::DateTimeComponents execute(Int64 t, const DateLUTImpl & time_zone)
|
||||||
|
{
|
||||||
|
return time_zone.toDateTimeComponents(t);
|
||||||
|
}
|
||||||
|
static inline DateLUTImpl::DateTimeComponents execute(UInt32 t, const DateLUTImpl & time_zone)
|
||||||
|
{
|
||||||
|
return time_zone.toDateTimeComponents(static_cast<DateLUTImpl::Time>(t));
|
||||||
|
}
|
||||||
|
static inline DateLUTImpl::DateTimeComponents execute(Int32 d, const DateLUTImpl & time_zone)
|
||||||
|
{
|
||||||
|
return time_zone.toDateTimeComponents(ExtendedDayNum(d));
|
||||||
|
}
|
||||||
|
static inline DateLUTImpl::DateTimeComponents execute(UInt16 d, const DateLUTImpl & time_zone)
|
||||||
|
{
|
||||||
|
return time_zone.toDateTimeComponents(DayNum(d));
|
||||||
|
}
|
||||||
|
|
||||||
|
using FactorTransform = ZeroTransform;
|
||||||
|
};
|
||||||
|
|
||||||
|
|
||||||
template <typename FromType, typename ToType, typename Transform, bool is_extended_result = false>
|
template <typename FromType, typename ToType, typename Transform, bool is_extended_result = false>
|
||||||
struct Transformer
|
struct Transformer
|
||||||
|
@ -48,6 +48,10 @@ public:
|
|||||||
: scale_multiplier(DecimalUtils::scaleMultiplier<DateTime64::NativeType>(scale_))
|
: scale_multiplier(DecimalUtils::scaleMultiplier<DateTime64::NativeType>(scale_))
|
||||||
{}
|
{}
|
||||||
|
|
||||||
|
TransformDateTime64(DateTime64::NativeType scale_multiplier_ = 1) /// NOLINT(google-explicit-constructor)
|
||||||
|
: scale_multiplier(scale_multiplier_)
|
||||||
|
{}
|
||||||
|
|
||||||
template <typename ... Args>
|
template <typename ... Args>
|
||||||
inline auto NO_SANITIZE_UNDEFINED execute(const DateTime64 & t, Args && ... args) const
|
inline auto NO_SANITIZE_UNDEFINED execute(const DateTime64 & t, Args && ... args) const
|
||||||
{
|
{
|
||||||
@ -127,6 +131,8 @@ public:
|
|||||||
return wrapped_transform.executeExtendedResult(t, std::forward<Args>(args)...);
|
return wrapped_transform.executeExtendedResult(t, std::forward<Args>(args)...);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
DateTime64::NativeType getScaleMultiplier() const { return scale_multiplier; }
|
||||||
|
|
||||||
private:
|
private:
|
||||||
DateTime64::NativeType scale_multiplier = 1;
|
DateTime64::NativeType scale_multiplier = 1;
|
||||||
Transform wrapped_transform = {};
|
Transform wrapped_transform = {};
|
||||||
|
@ -1,6 +1,7 @@
|
|||||||
#include <DataTypes/DataTypeDateTime.h>
|
#include <DataTypes/DataTypeDateTime.h>
|
||||||
#include <DataTypes/DataTypeDateTime64.h>
|
#include <DataTypes/DataTypeDateTime64.h>
|
||||||
#include <DataTypes/DataTypesNumber.h>
|
#include <DataTypes/DataTypesNumber.h>
|
||||||
|
#include <Common/IntervalKind.h>
|
||||||
#include <Columns/ColumnString.h>
|
#include <Columns/ColumnString.h>
|
||||||
#include <Columns/ColumnsDateTime.h>
|
#include <Columns/ColumnsDateTime.h>
|
||||||
#include <Columns/ColumnsNumber.h>
|
#include <Columns/ColumnsNumber.h>
|
||||||
@ -34,6 +35,7 @@ namespace ErrorCodes
|
|||||||
namespace
|
namespace
|
||||||
{
|
{
|
||||||
|
|
||||||
|
template <bool is_diff>
|
||||||
class DateDiffImpl
|
class DateDiffImpl
|
||||||
{
|
{
|
||||||
public:
|
public:
|
||||||
@ -165,8 +167,92 @@ public:
|
|||||||
template <typename TransformX, typename TransformY, typename T1, typename T2>
|
template <typename TransformX, typename TransformY, typename T1, typename T2>
|
||||||
Int64 calculate(const TransformX & transform_x, const TransformY & transform_y, T1 x, T2 y, const DateLUTImpl & timezone_x, const DateLUTImpl & timezone_y) const
|
Int64 calculate(const TransformX & transform_x, const TransformY & transform_y, T1 x, T2 y, const DateLUTImpl & timezone_x, const DateLUTImpl & timezone_y) const
|
||||||
{
|
{
|
||||||
|
if constexpr (is_diff)
|
||||||
return static_cast<Int64>(transform_y.execute(y, timezone_y))
|
return static_cast<Int64>(transform_y.execute(y, timezone_y))
|
||||||
- static_cast<Int64>(transform_x.execute(x, timezone_x));
|
- static_cast<Int64>(transform_x.execute(x, timezone_x));
|
||||||
|
else
|
||||||
|
{
|
||||||
|
auto res = static_cast<Int64>(transform_y.execute(y, timezone_y))
|
||||||
|
- static_cast<Int64>(transform_x.execute(x, timezone_x));
|
||||||
|
DateLUTImpl::DateTimeComponents a_comp;
|
||||||
|
DateLUTImpl::DateTimeComponents b_comp;
|
||||||
|
Int64 adjust_value;
|
||||||
|
auto x_seconds = TransformDateTime64<ToRelativeSecondNumImpl<ResultPrecision::Extended>>(transform_x.getScaleMultiplier()).execute(x, timezone_x);
|
||||||
|
auto y_seconds = TransformDateTime64<ToRelativeSecondNumImpl<ResultPrecision::Extended>>(transform_y.getScaleMultiplier()).execute(y, timezone_y);
|
||||||
|
if (x_seconds <= y_seconds)
|
||||||
|
{
|
||||||
|
a_comp = TransformDateTime64<ToDateTimeComponentsImpl>(transform_x.getScaleMultiplier()).execute(x, timezone_x);
|
||||||
|
b_comp = TransformDateTime64<ToDateTimeComponentsImpl>(transform_y.getScaleMultiplier()).execute(y, timezone_y);
|
||||||
|
adjust_value = -1;
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
a_comp = TransformDateTime64<ToDateTimeComponentsImpl>(transform_y.getScaleMultiplier()).execute(y, timezone_y);
|
||||||
|
b_comp = TransformDateTime64<ToDateTimeComponentsImpl>(transform_x.getScaleMultiplier()).execute(x, timezone_x);
|
||||||
|
adjust_value = 1;
|
||||||
|
}
|
||||||
|
|
||||||
|
if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeYearNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
if ((a_comp.date.month > b_comp.date.month)
|
||||||
|
|| ((a_comp.date.month == b_comp.date.month) && ((a_comp.date.day > b_comp.date.day)
|
||||||
|
|| ((a_comp.date.day == b_comp.date.day) && ((a_comp.time.hour > b_comp.time.hour)
|
||||||
|
|| ((a_comp.time.hour == b_comp.time.hour) && ((a_comp.time.minute > b_comp.time.minute)
|
||||||
|
|| ((a_comp.time.minute == b_comp.time.minute) && (a_comp.time.second > b_comp.time.second))))
|
||||||
|
)))))
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
else if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeQuarterNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
auto x_month_in_quarter = (a_comp.date.month - 1) % 3;
|
||||||
|
auto y_month_in_quarter = (b_comp.date.month - 1) % 3;
|
||||||
|
if ((x_month_in_quarter > y_month_in_quarter)
|
||||||
|
|| ((x_month_in_quarter == y_month_in_quarter) && ((a_comp.date.day > b_comp.date.day)
|
||||||
|
|| ((a_comp.date.day == b_comp.date.day) && ((a_comp.time.hour > b_comp.time.hour)
|
||||||
|
|| ((a_comp.time.hour == b_comp.time.hour) && ((a_comp.time.minute > b_comp.time.minute)
|
||||||
|
|| ((a_comp.time.minute == b_comp.time.minute) && (a_comp.time.second > b_comp.time.second))))
|
||||||
|
)))))
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
else if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeMonthNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
if ((a_comp.date.day > b_comp.date.day)
|
||||||
|
|| ((a_comp.date.day == b_comp.date.day) && ((a_comp.time.hour > b_comp.time.hour)
|
||||||
|
|| ((a_comp.time.hour == b_comp.time.hour) && ((a_comp.time.minute > b_comp.time.minute)
|
||||||
|
|| ((a_comp.time.minute == b_comp.time.minute) && (a_comp.time.second > b_comp.time.second))))
|
||||||
|
)))
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
else if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeWeekNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
auto x_day_of_week = TransformDateTime64<ToDayOfWeekImpl>(transform_x.getScaleMultiplier()).execute(x, timezone_x);
|
||||||
|
auto y_day_of_week = TransformDateTime64<ToDayOfWeekImpl>(transform_y.getScaleMultiplier()).execute(y, timezone_y);
|
||||||
|
if ((x_day_of_week > y_day_of_week)
|
||||||
|
|| ((x_day_of_week == y_day_of_week) && (a_comp.time.hour > b_comp.time.hour))
|
||||||
|
|| ((a_comp.time.hour == b_comp.time.hour) && ((a_comp.time.minute > b_comp.time.minute)
|
||||||
|
|| ((a_comp.time.minute == b_comp.time.minute) && (a_comp.time.second > b_comp.time.second)))))
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
else if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeDayNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
if ((a_comp.time.hour > b_comp.time.hour)
|
||||||
|
|| ((a_comp.time.hour == b_comp.time.hour) && ((a_comp.time.minute > b_comp.time.minute)
|
||||||
|
|| ((a_comp.time.minute == b_comp.time.minute) && (a_comp.time.second > b_comp.time.second)))))
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
else if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeHourNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
if ((a_comp.time.minute > b_comp.time.minute)
|
||||||
|
|| ((a_comp.time.minute == b_comp.time.minute) && (a_comp.time.second > b_comp.time.second)))
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
else if constexpr (std::is_same_v<TransformX, TransformDateTime64<ToRelativeMinuteNumImpl<ResultPrecision::Extended>>>)
|
||||||
|
{
|
||||||
|
if (a_comp.time.second > b_comp.time.second)
|
||||||
|
res += adjust_value;
|
||||||
|
}
|
||||||
|
return res;
|
||||||
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
template <typename T>
|
template <typename T>
|
||||||
@ -193,7 +279,8 @@ private:
|
|||||||
|
|
||||||
|
|
||||||
/** dateDiff('unit', t1, t2, [timezone])
|
/** dateDiff('unit', t1, t2, [timezone])
|
||||||
* t1 and t2 can be Date or DateTime
|
* age('unit', t1, t2, [timezone])
|
||||||
|
* t1 and t2 can be Date, Date32, DateTime or DateTime64
|
||||||
*
|
*
|
||||||
* If timezone is specified, it applied to both arguments.
|
* If timezone is specified, it applied to both arguments.
|
||||||
* If not, timezones from datatypes t1 and t2 are used.
|
* If not, timezones from datatypes t1 and t2 are used.
|
||||||
@ -201,10 +288,11 @@ private:
|
|||||||
*
|
*
|
||||||
* Timezone matters because days can have different length.
|
* Timezone matters because days can have different length.
|
||||||
*/
|
*/
|
||||||
|
template <bool is_relative>
|
||||||
class FunctionDateDiff : public IFunction
|
class FunctionDateDiff : public IFunction
|
||||||
{
|
{
|
||||||
public:
|
public:
|
||||||
static constexpr auto name = "dateDiff";
|
static constexpr auto name = is_relative ? "dateDiff" : "age";
|
||||||
static FunctionPtr create(ContextPtr) { return std::make_shared<FunctionDateDiff>(); }
|
static FunctionPtr create(ContextPtr) { return std::make_shared<FunctionDateDiff>(); }
|
||||||
|
|
||||||
String getName() const override
|
String getName() const override
|
||||||
@ -270,21 +358,21 @@ public:
|
|||||||
const auto & timezone_y = extractTimeZoneFromFunctionArguments(arguments, 3, 2);
|
const auto & timezone_y = extractTimeZoneFromFunctionArguments(arguments, 3, 2);
|
||||||
|
|
||||||
if (unit == "year" || unit == "yy" || unit == "yyyy")
|
if (unit == "year" || unit == "yy" || unit == "yyyy")
|
||||||
impl.dispatchForColumns<ToRelativeYearNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeYearNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "quarter" || unit == "qq" || unit == "q")
|
else if (unit == "quarter" || unit == "qq" || unit == "q")
|
||||||
impl.dispatchForColumns<ToRelativeQuarterNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeQuarterNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "month" || unit == "mm" || unit == "m")
|
else if (unit == "month" || unit == "mm" || unit == "m")
|
||||||
impl.dispatchForColumns<ToRelativeMonthNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeMonthNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "week" || unit == "wk" || unit == "ww")
|
else if (unit == "week" || unit == "wk" || unit == "ww")
|
||||||
impl.dispatchForColumns<ToRelativeWeekNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeWeekNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "day" || unit == "dd" || unit == "d")
|
else if (unit == "day" || unit == "dd" || unit == "d")
|
||||||
impl.dispatchForColumns<ToRelativeDayNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeDayNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "hour" || unit == "hh" || unit == "h")
|
else if (unit == "hour" || unit == "hh" || unit == "h")
|
||||||
impl.dispatchForColumns<ToRelativeHourNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeHourNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "minute" || unit == "mi" || unit == "n")
|
else if (unit == "minute" || unit == "mi" || unit == "n")
|
||||||
impl.dispatchForColumns<ToRelativeMinuteNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeMinuteNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else if (unit == "second" || unit == "ss" || unit == "s")
|
else if (unit == "second" || unit == "ss" || unit == "s")
|
||||||
impl.dispatchForColumns<ToRelativeSecondNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
impl.template dispatchForColumns<ToRelativeSecondNumImpl<ResultPrecision::Extended>>(x, y, timezone_x, timezone_y, res->getData());
|
||||||
else
|
else
|
||||||
throw Exception(ErrorCodes::BAD_ARGUMENTS,
|
throw Exception(ErrorCodes::BAD_ARGUMENTS,
|
||||||
"Function {} does not support '{}' unit", getName(), unit);
|
"Function {} does not support '{}' unit", getName(), unit);
|
||||||
@ -292,7 +380,7 @@ public:
|
|||||||
return res;
|
return res;
|
||||||
}
|
}
|
||||||
private:
|
private:
|
||||||
DateDiffImpl impl{name};
|
DateDiffImpl<is_relative> impl{name};
|
||||||
};
|
};
|
||||||
|
|
||||||
|
|
||||||
@ -352,14 +440,14 @@ public:
|
|||||||
return res;
|
return res;
|
||||||
}
|
}
|
||||||
private:
|
private:
|
||||||
DateDiffImpl impl{name};
|
DateDiffImpl<true> impl{name};
|
||||||
};
|
};
|
||||||
|
|
||||||
}
|
}
|
||||||
|
|
||||||
REGISTER_FUNCTION(DateDiff)
|
REGISTER_FUNCTION(DateDiff)
|
||||||
{
|
{
|
||||||
factory.registerFunction<FunctionDateDiff>({}, FunctionFactory::CaseInsensitive);
|
factory.registerFunction<FunctionDateDiff<true>>({}, FunctionFactory::CaseInsensitive);
|
||||||
}
|
}
|
||||||
|
|
||||||
REGISTER_FUNCTION(TimeDiff)
|
REGISTER_FUNCTION(TimeDiff)
|
||||||
@ -376,4 +464,9 @@ Example:
|
|||||||
Documentation::Categories{"Dates and Times"}}, FunctionFactory::CaseInsensitive);
|
Documentation::Categories{"Dates and Times"}}, FunctionFactory::CaseInsensitive);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
REGISTER_FUNCTION(Age)
|
||||||
|
{
|
||||||
|
factory.registerFunction<FunctionDateDiff<false>>({}, FunctionFactory::CaseInsensitive);
|
||||||
|
}
|
||||||
|
|
||||||
}
|
}
|
||||||
|
@ -82,6 +82,7 @@ addYears
|
|||||||
addressToLine
|
addressToLine
|
||||||
addressToLineWithInlines
|
addressToLineWithInlines
|
||||||
addressToSymbol
|
addressToSymbol
|
||||||
|
age
|
||||||
alphaTokens
|
alphaTokens
|
||||||
and
|
and
|
||||||
appendTrailingCharIfAbsent
|
appendTrailingCharIfAbsent
|
||||||
|
76
tests/queries/0_stateless/02477_age.reference
Normal file
76
tests/queries/0_stateless/02477_age.reference
Normal file
@ -0,0 +1,76 @@
|
|||||||
|
Various intervals
|
||||||
|
-1
|
||||||
|
0
|
||||||
|
0
|
||||||
|
-7
|
||||||
|
-3
|
||||||
|
0
|
||||||
|
-23
|
||||||
|
-11
|
||||||
|
0
|
||||||
|
-103
|
||||||
|
-52
|
||||||
|
0
|
||||||
|
-730
|
||||||
|
-364
|
||||||
|
1
|
||||||
|
-17520
|
||||||
|
-8736
|
||||||
|
24
|
||||||
|
-1051200
|
||||||
|
-524160
|
||||||
|
1440
|
||||||
|
-63072000
|
||||||
|
-31449600
|
||||||
|
86400
|
||||||
|
DateTime arguments
|
||||||
|
0
|
||||||
|
23
|
||||||
|
1439
|
||||||
|
86399
|
||||||
|
Date and DateTime arguments
|
||||||
|
-63072000
|
||||||
|
-31449600
|
||||||
|
86400
|
||||||
|
Constant and non-constant arguments
|
||||||
|
-1051200
|
||||||
|
-524160
|
||||||
|
1440
|
||||||
|
Case insensitive
|
||||||
|
-10
|
||||||
|
Dependance of timezones
|
||||||
|
0
|
||||||
|
0
|
||||||
|
1
|
||||||
|
25
|
||||||
|
1500
|
||||||
|
90000
|
||||||
|
0
|
||||||
|
0
|
||||||
|
1
|
||||||
|
24
|
||||||
|
1440
|
||||||
|
86400
|
||||||
|
0
|
||||||
|
0
|
||||||
|
1
|
||||||
|
25
|
||||||
|
1500
|
||||||
|
90000
|
||||||
|
0
|
||||||
|
0
|
||||||
|
1
|
||||||
|
24
|
||||||
|
1440
|
||||||
|
86400
|
||||||
|
Additional test
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
||||||
|
1
|
82
tests/queries/0_stateless/02477_age.sql
Normal file
82
tests/queries/0_stateless/02477_age.sql
Normal file
@ -0,0 +1,82 @@
|
|||||||
|
SELECT 'Various intervals';
|
||||||
|
|
||||||
|
SELECT age('year', toDate('2017-12-31'), toDate('2016-01-01'));
|
||||||
|
SELECT age('year', toDate('2017-12-31'), toDate('2017-01-01'));
|
||||||
|
SELECT age('year', toDate('2017-12-31'), toDate('2018-01-01'));
|
||||||
|
SELECT age('quarter', toDate('2017-12-31'), toDate('2016-01-01'));
|
||||||
|
SELECT age('quarter', toDate('2017-12-31'), toDate('2017-01-01'));
|
||||||
|
SELECT age('quarter', toDate('2017-12-31'), toDate('2018-01-01'));
|
||||||
|
SELECT age('month', toDate('2017-12-31'), toDate('2016-01-01'));
|
||||||
|
SELECT age('month', toDate('2017-12-31'), toDate('2017-01-01'));
|
||||||
|
SELECT age('month', toDate('2017-12-31'), toDate('2018-01-01'));
|
||||||
|
SELECT age('week', toDate('2017-12-31'), toDate('2016-01-01'));
|
||||||
|
SELECT age('week', toDate('2017-12-31'), toDate('2017-01-01'));
|
||||||
|
SELECT age('week', toDate('2017-12-31'), toDate('2018-01-01'));
|
||||||
|
SELECT age('day', toDate('2017-12-31'), toDate('2016-01-01'));
|
||||||
|
SELECT age('day', toDate('2017-12-31'), toDate('2017-01-01'));
|
||||||
|
SELECT age('day', toDate('2017-12-31'), toDate('2018-01-01'));
|
||||||
|
SELECT age('hour', toDate('2017-12-31'), toDate('2016-01-01'), 'UTC');
|
||||||
|
SELECT age('hour', toDate('2017-12-31'), toDate('2017-01-01'), 'UTC');
|
||||||
|
SELECT age('hour', toDate('2017-12-31'), toDate('2018-01-01'), 'UTC');
|
||||||
|
SELECT age('minute', toDate('2017-12-31'), toDate('2016-01-01'), 'UTC');
|
||||||
|
SELECT age('minute', toDate('2017-12-31'), toDate('2017-01-01'), 'UTC');
|
||||||
|
SELECT age('minute', toDate('2017-12-31'), toDate('2018-01-01'), 'UTC');
|
||||||
|
SELECT age('second', toDate('2017-12-31'), toDate('2016-01-01'), 'UTC');
|
||||||
|
SELECT age('second', toDate('2017-12-31'), toDate('2017-01-01'), 'UTC');
|
||||||
|
SELECT age('second', toDate('2017-12-31'), toDate('2018-01-01'), 'UTC');
|
||||||
|
|
||||||
|
SELECT 'DateTime arguments';
|
||||||
|
SELECT age('day', toDateTime('2016-01-01 00:00:01', 'UTC'), toDateTime('2016-01-02 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDateTime('2016-01-01 00:00:01', 'UTC'), toDateTime('2016-01-02 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDateTime('2016-01-01 00:00:01', 'UTC'), toDateTime('2016-01-02 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('second', toDateTime('2016-01-01 00:00:01', 'UTC'), toDateTime('2016-01-02 00:00:00', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
SELECT 'Date and DateTime arguments';
|
||||||
|
|
||||||
|
SELECT age('second', toDate('2017-12-31'), toDateTime('2016-01-01 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('second', toDateTime('2017-12-31 00:00:00', 'UTC'), toDate('2017-01-01'), 'UTC');
|
||||||
|
SELECT age('second', toDateTime('2017-12-31 00:00:00', 'UTC'), toDateTime('2018-01-01 00:00:00', 'UTC'));
|
||||||
|
|
||||||
|
SELECT 'Constant and non-constant arguments';
|
||||||
|
|
||||||
|
SELECT age('minute', materialize(toDate('2017-12-31')), toDate('2016-01-01'), 'UTC');
|
||||||
|
SELECT age('minute', toDate('2017-12-31'), materialize(toDate('2017-01-01')), 'UTC');
|
||||||
|
SELECT age('minute', materialize(toDate('2017-12-31')), materialize(toDate('2018-01-01')), 'UTC');
|
||||||
|
|
||||||
|
SELECT 'Case insensitive';
|
||||||
|
|
||||||
|
SELECT age('year', today(), today() - INTERVAL 10 YEAR);
|
||||||
|
|
||||||
|
SELECT 'Dependance of timezones';
|
||||||
|
|
||||||
|
SELECT age('month', toDate('2014-10-26'), toDate('2014-10-27'), 'Asia/Istanbul');
|
||||||
|
SELECT age('week', toDate('2014-10-26'), toDate('2014-10-27'), 'Asia/Istanbul');
|
||||||
|
SELECT age('day', toDate('2014-10-26'), toDate('2014-10-27'), 'Asia/Istanbul');
|
||||||
|
SELECT age('hour', toDate('2014-10-26'), toDate('2014-10-27'), 'Asia/Istanbul');
|
||||||
|
SELECT age('minute', toDate('2014-10-26'), toDate('2014-10-27'), 'Asia/Istanbul');
|
||||||
|
SELECT age('second', toDate('2014-10-26'), toDate('2014-10-27'), 'Asia/Istanbul');
|
||||||
|
|
||||||
|
SELECT age('month', toDate('2014-10-26'), toDate('2014-10-27'), 'UTC');
|
||||||
|
SELECT age('week', toDate('2014-10-26'), toDate('2014-10-27'), 'UTC');
|
||||||
|
SELECT age('day', toDate('2014-10-26'), toDate('2014-10-27'), 'UTC');
|
||||||
|
SELECT age('hour', toDate('2014-10-26'), toDate('2014-10-27'), 'UTC');
|
||||||
|
SELECT age('minute', toDate('2014-10-26'), toDate('2014-10-27'), 'UTC');
|
||||||
|
SELECT age('second', toDate('2014-10-26'), toDate('2014-10-27'), 'UTC');
|
||||||
|
|
||||||
|
SELECT age('month', toDateTime('2014-10-26 00:00:00', 'Asia/Istanbul'), toDateTime('2014-10-27 00:00:00', 'Asia/Istanbul'));
|
||||||
|
SELECT age('week', toDateTime('2014-10-26 00:00:00', 'Asia/Istanbul'), toDateTime('2014-10-27 00:00:00', 'Asia/Istanbul'));
|
||||||
|
SELECT age('day', toDateTime('2014-10-26 00:00:00', 'Asia/Istanbul'), toDateTime('2014-10-27 00:00:00', 'Asia/Istanbul'));
|
||||||
|
SELECT age('hour', toDateTime('2014-10-26 00:00:00', 'Asia/Istanbul'), toDateTime('2014-10-27 00:00:00', 'Asia/Istanbul'));
|
||||||
|
SELECT age('minute', toDateTime('2014-10-26 00:00:00', 'Asia/Istanbul'), toDateTime('2014-10-27 00:00:00', 'Asia/Istanbul'));
|
||||||
|
SELECT age('second', toDateTime('2014-10-26 00:00:00', 'Asia/Istanbul'), toDateTime('2014-10-27 00:00:00', 'Asia/Istanbul'));
|
||||||
|
|
||||||
|
SELECT age('month', toDateTime('2014-10-26 00:00:00', 'UTC'), toDateTime('2014-10-27 00:00:00', 'UTC'));
|
||||||
|
SELECT age('week', toDateTime('2014-10-26 00:00:00', 'UTC'), toDateTime('2014-10-27 00:00:00', 'UTC'));
|
||||||
|
SELECT age('day', toDateTime('2014-10-26 00:00:00', 'UTC'), toDateTime('2014-10-27 00:00:00', 'UTC'));
|
||||||
|
SELECT age('hour', toDateTime('2014-10-26 00:00:00', 'UTC'), toDateTime('2014-10-27 00:00:00', 'UTC'));
|
||||||
|
SELECT age('minute', toDateTime('2014-10-26 00:00:00', 'UTC'), toDateTime('2014-10-27 00:00:00', 'UTC'));
|
||||||
|
SELECT age('second', toDateTime('2014-10-26 00:00:00', 'UTC'), toDateTime('2014-10-27 00:00:00', 'UTC'));
|
||||||
|
|
||||||
|
SELECT 'Additional test';
|
||||||
|
|
||||||
|
SELECT number = age('month', now() - INTERVAL number MONTH, now()) FROM system.numbers LIMIT 10;
|
169
tests/queries/0_stateless/02477_age_date32.reference
Normal file
169
tests/queries/0_stateless/02477_age_date32.reference
Normal file
@ -0,0 +1,169 @@
|
|||||||
|
-- { echo }
|
||||||
|
|
||||||
|
-- Date32 vs Date32
|
||||||
|
SELECT age('second', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-08', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDate32('1927-01-01', 'UTC'), toDate32('1927-02-01', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDate32('1927-01-01', 'UTC'), toDate32('1927-04-01', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDate32('1927-01-01', 'UTC'), toDate32('1928-01-01', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- With DateTime64
|
||||||
|
-- Date32 vs DateTime64
|
||||||
|
SELECT age('second', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-08 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-02-01 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-04-01 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDate32('1927-01-01', 'UTC'), toDateTime64('1928-01-01 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- DateTime64 vs Date32
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-08', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-02-01', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-04-01', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1928-01-01', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- With DateTime
|
||||||
|
-- Date32 vs DateTime
|
||||||
|
SELECT age('second', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-25 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDate32('2015-08-18', 'UTC'), toDateTime('2015-09-18 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDate32('2015-08-18', 'UTC'), toDateTime('2015-11-18 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDate32('2015-08-18', 'UTC'), toDateTime('2016-08-18 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- DateTime vs Date32
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-25', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-09-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-11-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2016-08-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- With Date
|
||||||
|
-- Date32 vs Date
|
||||||
|
SELECT age('second', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDate32('2015-08-18', 'UTC'), toDate('2015-08-25', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDate32('2015-08-18', 'UTC'), toDate('2015-09-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDate32('2015-08-18', 'UTC'), toDate('2015-11-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDate32('2015-08-18', 'UTC'), toDate('2016-08-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- Date vs Date32
|
||||||
|
SELECT age('second', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
86400
|
||||||
|
SELECT age('minute', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1440
|
||||||
|
SELECT age('hour', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
24
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('week', toDate('2015-08-18', 'UTC'), toDate32('2015-08-25', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('month', toDate('2015-08-18', 'UTC'), toDate32('2015-09-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('quarter', toDate('2015-08-18', 'UTC'), toDate32('2015-11-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('year', toDate('2015-08-18', 'UTC'), toDate32('2016-08-18', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- Const vs non-const columns
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), materialize(toDateTime64('1927-01-02 00:00:00', 3, 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), materialize(toDateTime('2015-08-19 00:00:00', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', toDateTime('2015-08-18 00:00:00', 'UTC'), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), materialize(toDate('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
-- Non-const vs const columns
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDateTime64('1927-01-01 00:00:00', 3, 'UTC')), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
1
|
||||||
|
-- Non-const vs non-const columns
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), materialize(toDateTime64('1927-01-02 00:00:00', 3, 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDateTime64('1927-01-01 00:00:00', 3, 'UTC')), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), materialize(toDateTime('2015-08-19 00:00:00', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), materialize(toDate('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
1
|
101
tests/queries/0_stateless/02477_age_date32.sql
Normal file
101
tests/queries/0_stateless/02477_age_date32.sql
Normal file
@ -0,0 +1,101 @@
|
|||||||
|
-- { echo }
|
||||||
|
|
||||||
|
-- Date32 vs Date32
|
||||||
|
SELECT age('second', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDate32('1927-01-01', 'UTC'), toDate32('1927-01-08', 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDate32('1927-01-01', 'UTC'), toDate32('1927-02-01', 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDate32('1927-01-01', 'UTC'), toDate32('1927-04-01', 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDate32('1927-01-01', 'UTC'), toDate32('1928-01-01', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- With DateTime64
|
||||||
|
-- Date32 vs DateTime64
|
||||||
|
SELECT age('second', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-01-08 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-02-01 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDate32('1927-01-01', 'UTC'), toDateTime64('1927-04-01 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDate32('1927-01-01', 'UTC'), toDateTime64('1928-01-01 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- DateTime64 vs Date32
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-01-08', 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-02-01', 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1927-04-01', 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), toDate32('1928-01-01', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- With DateTime
|
||||||
|
-- Date32 vs DateTime
|
||||||
|
SELECT age('second', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDate32('2015-08-18', 'UTC'), toDateTime('2015-08-25 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDate32('2015-08-18', 'UTC'), toDateTime('2015-09-18 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDate32('2015-08-18', 'UTC'), toDateTime('2015-11-18 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDate32('2015-08-18', 'UTC'), toDateTime('2016-08-18 00:00:00', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- DateTime vs Date32
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-08-25', 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-09-18', 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2015-11-18', 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDateTime('2015-08-18 00:00:00', 'UTC'), toDate32('2016-08-18', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- With Date
|
||||||
|
-- Date32 vs Date
|
||||||
|
SELECT age('second', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDate32('2015-08-18', 'UTC'), toDate('2015-08-25', 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDate32('2015-08-18', 'UTC'), toDate('2015-09-18', 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDate32('2015-08-18', 'UTC'), toDate('2015-11-18', 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDate32('2015-08-18', 'UTC'), toDate('2016-08-18', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- Date vs Date32
|
||||||
|
SELECT age('second', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('minute', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('hour', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('week', toDate('2015-08-18', 'UTC'), toDate32('2015-08-25', 'UTC'), 'UTC');
|
||||||
|
SELECT age('month', toDate('2015-08-18', 'UTC'), toDate32('2015-09-18', 'UTC'), 'UTC');
|
||||||
|
SELECT age('quarter', toDate('2015-08-18', 'UTC'), toDate32('2015-11-18', 'UTC'), 'UTC');
|
||||||
|
SELECT age('year', toDate('2015-08-18', 'UTC'), toDate32('2016-08-18', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- Const vs non-const columns
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', toDate32('1927-01-01', 'UTC'), materialize(toDateTime64('1927-01-02 00:00:00', 3, 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 3, 'UTC'), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), materialize(toDateTime('2015-08-19 00:00:00', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', toDateTime('2015-08-18 00:00:00', 'UTC'), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', toDate32('2015-08-18', 'UTC'), materialize(toDate('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
|
||||||
|
-- Non-const vs const columns
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDateTime64('1927-01-01 00:00:00', 3, 'UTC')), toDate32('1927-01-02', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), toDateTime('2015-08-19 00:00:00', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), toDate('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), toDate32('2015-08-19', 'UTC'), 'UTC');
|
||||||
|
|
||||||
|
-- Non-const vs non-const columns
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate32('1927-01-01', 'UTC')), materialize(toDateTime64('1927-01-02 00:00:00', 3, 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDateTime64('1927-01-01 00:00:00', 3, 'UTC')), materialize(toDate32('1927-01-02', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), materialize(toDateTime('2015-08-19 00:00:00', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate32('2015-08-18', 'UTC')), materialize(toDate('2015-08-19', 'UTC')), 'UTC');
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), materialize(toDate32('2015-08-19', 'UTC')), 'UTC');
|
113
tests/queries/0_stateless/02477_age_datetime64.reference
Normal file
113
tests/queries/0_stateless/02477_age_datetime64.reference
Normal file
@ -0,0 +1,113 @@
|
|||||||
|
-- { echo }
|
||||||
|
|
||||||
|
-- DateTime64 vs DateTime64 same scale
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 00:00:10', 0, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 00:10:00', 0, 'UTC'));
|
||||||
|
600
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 01:00:00', 0, 'UTC'));
|
||||||
|
3600
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 01:10:10', 0, 'UTC'));
|
||||||
|
4210
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 00:10:00', 0, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 10:00:00', 0, 'UTC'));
|
||||||
|
600
|
||||||
|
SELECT age('hour', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 10:00:00', 0, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-02 00:00:00', 0, 'UTC'));
|
||||||
|
1
|
||||||
|
SELECT age('month', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-02-01 00:00:00', 0, 'UTC'));
|
||||||
|
1
|
||||||
|
SELECT age('year', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1928-01-01 00:00:00', 0, 'UTC'));
|
||||||
|
1
|
||||||
|
-- DateTime64 vs DateTime64 different scale
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 00:00:10', 3, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 00:10:00', 3, 'UTC'));
|
||||||
|
600
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 01:00:00', 3, 'UTC'));
|
||||||
|
3600
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 01:10:10', 3, 'UTC'));
|
||||||
|
4210
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 00:10:00', 3, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 10:00:00', 3, 'UTC'));
|
||||||
|
600
|
||||||
|
SELECT age('hour', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 10:00:00', 3, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'));
|
||||||
|
1
|
||||||
|
SELECT age('month', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-02-01 00:00:00', 3, 'UTC'));
|
||||||
|
1
|
||||||
|
SELECT age('year', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1928-01-01 00:00:00', 3, 'UTC'));
|
||||||
|
1
|
||||||
|
-- With DateTime
|
||||||
|
-- DateTime64 vs DateTime
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 00:00:00', 'UTC'));
|
||||||
|
0
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 00:00:10', 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 00:10:00', 'UTC'));
|
||||||
|
600
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 01:00:00', 'UTC'));
|
||||||
|
3600
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 01:10:10', 'UTC'));
|
||||||
|
4210
|
||||||
|
-- DateTime vs DateTime64
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 00:00:00', 3, 'UTC'));
|
||||||
|
0
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 00:00:10', 3, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 00:10:00', 3, 'UTC'));
|
||||||
|
600
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 01:00:00', 3, 'UTC'));
|
||||||
|
3600
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 01:10:10', 3, 'UTC'));
|
||||||
|
4210
|
||||||
|
-- With Date
|
||||||
|
-- DateTime64 vs Date
|
||||||
|
SELECT age('day', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDate('2015-08-19', 'UTC'));
|
||||||
|
1
|
||||||
|
-- Date vs DateTime64
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), toDateTime64('2015-08-19 00:00:00', 3, 'UTC'));
|
||||||
|
1
|
||||||
|
-- Same thing but const vs non-const columns
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), materialize(toDateTime64('1927-01-01 00:00:10', 0, 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), materialize(toDateTime64('1927-01-01 00:00:10', 3, 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), materialize(toDateTime('2015-08-18 00:00:10', 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), materialize(toDateTime64('2015-08-18 00:00:10', 3, 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('day', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), materialize(toDate('2015-08-19', 'UTC')));
|
||||||
|
1
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), materialize(toDateTime64('2015-08-19 00:00:00', 3, 'UTC')));
|
||||||
|
1
|
||||||
|
-- Same thing but non-const vs const columns
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 0, 'UTC')), toDateTime64('1927-01-01 00:00:10', 0, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 6, 'UTC')), toDateTime64('1927-01-01 00:00:10', 3, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), toDateTime('2015-08-18 00:00:10', 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('second', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), toDateTime64('2015-08-18 00:00:10', 3, 'UTC'));
|
||||||
|
10
|
||||||
|
SELECT age('day', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), toDate('2015-08-19', 'UTC'));
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), toDateTime64('2015-08-19 00:00:00', 3, 'UTC'));
|
||||||
|
1
|
||||||
|
-- Same thing but non-const vs non-const columns
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 0, 'UTC')), materialize(toDateTime64('1927-01-01 00:00:10', 0, 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 6, 'UTC')), materialize(toDateTime64('1927-01-01 00:00:10', 3, 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('second', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), materialize(toDateTime('2015-08-18 00:00:10', 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('second', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), materialize(toDateTime64('2015-08-18 00:00:10', 3, 'UTC')));
|
||||||
|
10
|
||||||
|
SELECT age('day', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), materialize(toDate('2015-08-19', 'UTC')));
|
||||||
|
1
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), materialize(toDateTime64('2015-08-19 00:00:00', 3, 'UTC')));
|
||||||
|
1
|
77
tests/queries/0_stateless/02477_age_datetime64.sql
Normal file
77
tests/queries/0_stateless/02477_age_datetime64.sql
Normal file
@ -0,0 +1,77 @@
|
|||||||
|
-- { echo }
|
||||||
|
|
||||||
|
-- DateTime64 vs DateTime64 same scale
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 00:00:10', 0, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 00:10:00', 0, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 01:00:00', 0, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 01:10:10', 0, 'UTC'));
|
||||||
|
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 00:10:00', 0, 'UTC'));
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 10:00:00', 0, 'UTC'));
|
||||||
|
|
||||||
|
SELECT age('hour', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-01 10:00:00', 0, 'UTC'));
|
||||||
|
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-01-02 00:00:00', 0, 'UTC'));
|
||||||
|
SELECT age('month', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1927-02-01 00:00:00', 0, 'UTC'));
|
||||||
|
SELECT age('year', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), toDateTime64('1928-01-01 00:00:00', 0, 'UTC'));
|
||||||
|
|
||||||
|
-- DateTime64 vs DateTime64 different scale
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 00:00:10', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 00:10:00', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 01:00:00', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 01:10:10', 3, 'UTC'));
|
||||||
|
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 00:10:00', 3, 'UTC'));
|
||||||
|
SELECT age('minute', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 10:00:00', 3, 'UTC'));
|
||||||
|
|
||||||
|
SELECT age('hour', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-01 10:00:00', 3, 'UTC'));
|
||||||
|
|
||||||
|
SELECT age('day', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-01-02 00:00:00', 3, 'UTC'));
|
||||||
|
SELECT age('month', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1927-02-01 00:00:00', 3, 'UTC'));
|
||||||
|
SELECT age('year', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), toDateTime64('1928-01-01 00:00:00', 3, 'UTC'));
|
||||||
|
|
||||||
|
-- With DateTime
|
||||||
|
-- DateTime64 vs DateTime
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 00:00:00', 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 00:00:10', 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 00:10:00', 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 01:00:00', 'UTC'));
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDateTime('2015-08-18 01:10:10', 'UTC'));
|
||||||
|
|
||||||
|
-- DateTime vs DateTime64
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 00:00:00', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 00:00:10', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 00:10:00', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 01:00:00', 3, 'UTC'));
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), toDateTime64('2015-08-18 01:10:10', 3, 'UTC'));
|
||||||
|
|
||||||
|
-- With Date
|
||||||
|
-- DateTime64 vs Date
|
||||||
|
SELECT age('day', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), toDate('2015-08-19', 'UTC'));
|
||||||
|
|
||||||
|
-- Date vs DateTime64
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), toDateTime64('2015-08-19 00:00:00', 3, 'UTC'));
|
||||||
|
|
||||||
|
-- Same thing but const vs non-const columns
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 0, 'UTC'), materialize(toDateTime64('1927-01-01 00:00:10', 0, 'UTC')));
|
||||||
|
SELECT age('second', toDateTime64('1927-01-01 00:00:00', 6, 'UTC'), materialize(toDateTime64('1927-01-01 00:00:10', 3, 'UTC')));
|
||||||
|
SELECT age('second', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), materialize(toDateTime('2015-08-18 00:00:10', 'UTC')));
|
||||||
|
SELECT age('second', toDateTime('2015-08-18 00:00:00', 'UTC'), materialize(toDateTime64('2015-08-18 00:00:10', 3, 'UTC')));
|
||||||
|
SELECT age('day', toDateTime64('2015-08-18 00:00:00', 0, 'UTC'), materialize(toDate('2015-08-19', 'UTC')));
|
||||||
|
SELECT age('day', toDate('2015-08-18', 'UTC'), materialize(toDateTime64('2015-08-19 00:00:00', 3, 'UTC')));
|
||||||
|
|
||||||
|
-- Same thing but non-const vs const columns
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 0, 'UTC')), toDateTime64('1927-01-01 00:00:10', 0, 'UTC'));
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 6, 'UTC')), toDateTime64('1927-01-01 00:00:10', 3, 'UTC'));
|
||||||
|
SELECT age('second', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), toDateTime('2015-08-18 00:00:10', 'UTC'));
|
||||||
|
SELECT age('second', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), toDateTime64('2015-08-18 00:00:10', 3, 'UTC'));
|
||||||
|
SELECT age('day', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), toDate('2015-08-19', 'UTC'));
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), toDateTime64('2015-08-19 00:00:00', 3, 'UTC'));
|
||||||
|
|
||||||
|
-- Same thing but non-const vs non-const columns
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 0, 'UTC')), materialize(toDateTime64('1927-01-01 00:00:10', 0, 'UTC')));
|
||||||
|
SELECT age('second', materialize(toDateTime64('1927-01-01 00:00:00', 6, 'UTC')), materialize(toDateTime64('1927-01-01 00:00:10', 3, 'UTC')));
|
||||||
|
SELECT age('second', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), materialize(toDateTime('2015-08-18 00:00:10', 'UTC')));
|
||||||
|
SELECT age('second', materialize(toDateTime('2015-08-18 00:00:00', 'UTC')), materialize(toDateTime64('2015-08-18 00:00:10', 3, 'UTC')));
|
||||||
|
SELECT age('day', materialize(toDateTime64('2015-08-18 00:00:00', 0, 'UTC')), materialize(toDate('2015-08-19', 'UTC')));
|
||||||
|
SELECT age('day', materialize(toDate('2015-08-18', 'UTC')), materialize(toDateTime64('2015-08-19 00:00:00', 3, 'UTC')));
|
Loading…
Reference in New Issue
Block a user