Merge pull request #68057 from yariks5s/interval_type_conversion

Implement interval data type comparison
This commit is contained in:
Yarik Briukhovetskyi 2024-08-22 12:15:10 +00:00 committed by GitHub
commit e979251859
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
8 changed files with 345 additions and 24 deletions

View File

@ -53,29 +53,28 @@ SELECT now() as current_date_time, current_date_time + INTERVAL 4 DAY
└─────────────────────┴───────────────────────────────┘
```
Intervals with different types cant be combined. You cant use intervals like `4 DAY 1 HOUR`. Specify intervals in units that are smaller or equal to the smallest unit of the interval, for example, the interval `1 day and an hour` interval can be expressed as `25 HOUR` or `90000 SECOND`.
You cant perform arithmetical operations with `Interval`-type values, but you can add intervals of different types consequently to values in `Date` or `DateTime` data types. For example:
Also it is possible to use multiple intervals simultaneously:
``` sql
SELECT now() AS current_date_time, current_date_time + INTERVAL 4 DAY + INTERVAL 3 HOUR
SELECT now() AS current_date_time, current_date_time + (INTERVAL 4 DAY + INTERVAL 3 HOUR)
```
``` text
┌───current_date_time─┬─plus(plus(now(), toIntervalDay(4)), toIntervalHour(3))─┐
│ 2019-10-23 11:16:28 │ 2019-10-27 14:16:28
└─────────────────────┴────────────────────────────────────────────────────────┘
┌───current_date_time─┬─plus(current_date_time, plus(toIntervalDay(4), toIntervalHour(3)))─┐
│ 2024-08-08 18:31:39 │ 2024-08-12 21:31:39
└─────────────────────┴────────────────────────────────────────────────────────────────────
```
The following query causes an exception:
And to compare values with different intervals:
``` sql
select now() AS current_date_time, current_date_time + (INTERVAL 4 DAY + INTERVAL 3 HOUR)
SELECT toIntervalMicrosecond(3600000000) = toIntervalHour(1);
```
``` text
Received exception from server (version 19.14.1):
Code: 43. DB::Exception: Received from localhost:9000. DB::Exception: Wrong argument types for function plus: if one argument is Interval, then another must be Date or DateTime..
┌─less(toIntervalMicrosecond(179999999), toIntervalMinute(3))─┐
│ 1 │
└─────────────────────────────────────────────────────────────┘
```
## See Also

View File

@ -54,29 +54,28 @@ SELECT now() as current_date_time, current_date_time + INTERVAL 4 DAY
└─────────────────────┴───────────────────────────────┘
```
Нельзя объединять интервалы различных типов. Нельзя использовать интервалы вида `4 DAY 1 HOUR`. Вместо этого выражайте интервал в единицах меньших или равных минимальной единице интервала, например, интервал «1 день и 1 час» можно выразить как `25 HOUR` или `90000 SECOND`.
Арифметические операции со значениями типов `Interval` не доступны, однако можно последовательно добавлять различные интервалы к значениям типов `Date` и `DateTime`. Например:
Также можно использовать различные типы интервалов одновременно:
``` sql
SELECT now() AS current_date_time, current_date_time + INTERVAL 4 DAY + INTERVAL 3 HOUR
SELECT now() AS current_date_time, current_date_time + (INTERVAL 4 DAY + INTERVAL 3 HOUR)
```
``` text
┌───current_date_time─┬─plus(plus(now(), toIntervalDay(4)), toIntervalHour(3))─┐
│ 2019-10-23 11:16:28 │ 2019-10-27 14:16:28
└─────────────────────┴────────────────────────────────────────────────────────┘
┌───current_date_time─┬─plus(current_date_time, plus(toIntervalDay(4), toIntervalHour(3)))─┐
│ 2024-08-08 18:31:39 │ 2024-08-12 21:31:39
└─────────────────────┴────────────────────────────────────────────────────────────────────
```
Следующий запрос приведёт к генерированию исключения:
И сравнивать значения из разными интервалами:
``` sql
select now() AS current_date_time, current_date_time + (INTERVAL 4 DAY + INTERVAL 3 HOUR)
SELECT toIntervalMicrosecond(3600000000) = toIntervalHour(1);
```
``` text
Received exception from server (version 19.14.1):
Code: 43. DB::Exception: Received from localhost:9000. DB::Exception: Wrong argument types for function plus: if one argument is Interval, then another must be Date or DateTime..
┌─less(toIntervalMicrosecond(179999999), toIntervalMinute(3))─┐
│ 1 │
└─────────────────────────────────────────────────────────────┘
```
## Смотрите также {#smotrite-takzhe}

View File

@ -3,6 +3,7 @@
#include <utility>
#include <Core/Types.h>
#include <DataTypes/DataTypeInterval.h>
namespace DB
@ -212,6 +213,8 @@ static bool callOnIndexAndDataType(TypeIndex number, F && f, ExtraArgs && ... ar
case TypeIndex::IPv4: return f(TypePair<DataTypeIPv4, T>(), std::forward<ExtraArgs>(args)...);
case TypeIndex::IPv6: return f(TypePair<DataTypeIPv6, T>(), std::forward<ExtraArgs>(args)...);
case TypeIndex::Interval: return f(TypePair<DataTypeInterval, T>(), std::forward<ExtraArgs>(args)...);
default:
break;
}

View File

@ -228,6 +228,39 @@ void convertUInt64toInt64IfPossible(const DataTypes & types, TypeIndexSet & type
}
}
DataTypePtr findSmallestIntervalSuperType(const DataTypes &types, TypeIndexSet &types_set)
{
auto min_interval = IntervalKind::Kind::Year;
DataTypePtr smallest_type;
bool is_higher_interval = false; // For Years, Quarters and Months
for (const auto &type : types)
{
if (const auto * interval_type = typeid_cast<const DataTypeInterval *>(type.get()))
{
auto current_interval = interval_type->getKind().kind;
if (current_interval > IntervalKind::Kind::Week)
is_higher_interval = true;
if (current_interval < min_interval)
{
min_interval = current_interval;
smallest_type = type;
}
}
}
if (is_higher_interval && min_interval <= IntervalKind::Kind::Week)
throw Exception(ErrorCodes::NO_COMMON_TYPE, "Cannot compare intervals {} and {} because the number of days in a month is not fixed", types[0]->getName(), types[1]->getName());
if (smallest_type)
{
types_set.clear();
types_set.insert(smallest_type->getTypeId());
}
return smallest_type;
}
}
template <LeastSupertypeOnError on_error>
@ -652,6 +685,13 @@ DataTypePtr getLeastSupertype(const DataTypes & types)
return numeric_type;
}
/// For interval data types.
{
auto res = findSmallestIntervalSuperType(types, type_ids);
if (res)
return res;
}
/// All other data types (UUID, AggregateFunction, Enum...) are compatible only if they are the same (checked in trivial cases).
return throwOrReturn<on_error>(types, "", ErrorCodes::NO_COMMON_TYPE);
}

View File

@ -1,5 +1,7 @@
#pragma once
#include <DataTypes/IDataType.h>
#include <DataTypes/DataTypeInterval.h>
#include <Common/IntervalKind.h>
namespace DB
{
@ -48,4 +50,7 @@ DataTypePtr getLeastSupertypeOrString(const TypeIndexSet & types);
DataTypePtr tryGetLeastSupertype(const TypeIndexSet & types);
/// A vector that shows the conversion rates to the next Interval type starting from NanoSecond
static std::vector<int> interval_conversions = {1, 1000, 1000, 1000, 60, 60, 24, 7, 4, 3, 4};
}

View File

@ -48,6 +48,7 @@
#include <DataTypes/DataTypesBinaryEncoding.h>
#include <DataTypes/ObjectUtils.h>
#include <DataTypes/Serializations/SerializationDecimal.h>
#include <DataTypes/getLeastSupertype.h>
#include <Formats/FormatSettings.h>
#include <Formats/FormatFactory.h>
#include <Functions/CastOverloadResolver.h>
@ -1576,6 +1577,35 @@ struct ConvertImpl
arguments, result_type, input_rows_count, additions);
}
}
else if constexpr (std::is_same_v<FromDataType, DataTypeInterval> && std::is_same_v<ToDataType, DataTypeInterval>)
{
IntervalKind to = typeid_cast<const DataTypeInterval *>(result_type.get())->getKind();
IntervalKind from = typeid_cast<const DataTypeInterval *>(arguments[0].type.get())->getKind();
if (from == to || arguments[0].column->empty())
return arguments[0].column;
Int64 conversion_factor = 1;
Int64 result_value;
int from_position = static_cast<int>(from.kind);
int to_position = static_cast<int>(to.kind); /// Positions of each interval according to granularity map
if (from_position < to_position)
{
for (int i = from_position; i < to_position; ++i)
conversion_factor *= interval_conversions[i];
result_value = arguments[0].column->getInt(0) / conversion_factor;
}
else
{
for (int i = from_position; i > to_position; --i)
conversion_factor *= interval_conversions[i];
result_value = arguments[0].column->getInt(0) * conversion_factor;
}
return ColumnConst::create(ColumnInt64::create(1, result_value), input_rows_count);
}
else
{
using FromFieldType = typename FromDataType::FieldType;
@ -2184,7 +2214,7 @@ private:
const DataTypePtr from_type = removeNullable(arguments[0].type);
ColumnPtr result_column;
[[maybe_unused]] FormatSettings::DateTimeOverflowBehavior date_time_overflow_behavior = default_date_time_overflow_behavior;
FormatSettings::DateTimeOverflowBehavior date_time_overflow_behavior = default_date_time_overflow_behavior;
if (context)
date_time_overflow_behavior = context->getSettingsRef().date_time_overflow_behavior.value;
@ -2280,7 +2310,7 @@ private:
}
}
else
result_column = ConvertImpl<LeftDataType, RightDataType, Name>::execute(arguments, result_type, input_rows_count, from_string_tag);
result_column = ConvertImpl<LeftDataType, RightDataType, Name>::execute(arguments, result_type, input_rows_count, from_string_tag);
return true;
};
@ -2337,6 +2367,10 @@ private:
else
done = callOnIndexAndDataType<ToDataType>(from_type->getTypeId(), call, BehaviourOnErrorFromString::ConvertDefaultBehaviorTag);
}
if constexpr (std::is_same_v<ToDataType, DataTypeInterval>)
if (WhichDataType(from_type).isInterval())
done = callOnIndexAndDataType<ToDataType>(from_type->getTypeId(), call, BehaviourOnErrorFromString::ConvertDefaultBehaviorTag);
}
if (!done)

View File

@ -0,0 +1,99 @@
Comparing nanoseconds
1
1
1
1
1
1
1
1
1
1
0
0
0
0
0
0
0
0
0
0
Comparing microseconds
1
1
1
1
1
1
1
0
0
0
0
0
0
0
Comparing milliseconds
1
1
1
1
1
1
0
0
0
0
0
0
Comparing seconds
1
1
1
1
1
0
0
0
0
0
Comparing minutes
1
1
1
1
0
0
0
0
Comparing hours
1
1
1
0
0
0
Comparing days
1
1
0
0
Comparing weeks
1
0
Comparing months
1
1
1
0
0
0
Comparing quarters
1
1
0
0
Comparing years
1
0

View File

@ -0,0 +1,142 @@
SELECT('Comparing nanoseconds');
SELECT INTERVAL 500 NANOSECOND > INTERVAL 300 NANOSECOND;
SELECT INTERVAL 1000 NANOSECOND < INTERVAL 1500 NANOSECOND;
SELECT INTERVAL 2000 NANOSECOND = INTERVAL 2000 NANOSECOND;
SELECT INTERVAL 1000 NANOSECOND >= INTERVAL 1 MICROSECOND;
SELECT INTERVAL 1000001 NANOSECOND > INTERVAL 1 MILLISECOND;
SELECT INTERVAL 2000000001 NANOSECOND > INTERVAL 2 SECOND;
SELECT INTERVAL 60000000000 NANOSECOND = INTERVAL 1 MINUTE;
SELECT INTERVAL 7199999999999 NANOSECOND < INTERVAL 2 HOUR;
SELECT INTERVAL 1 NANOSECOND < INTERVAL 2 DAY;
SELECT INTERVAL 5 NANOSECOND < INTERVAL 1 WEEK;
SELECT INTERVAL 500 NANOSECOND < INTERVAL 300 NANOSECOND;
SELECT INTERVAL 1000 NANOSECOND > INTERVAL 1500 NANOSECOND;
SELECT INTERVAL 2000 NANOSECOND != INTERVAL 2000 NANOSECOND;
SELECT INTERVAL 1000 NANOSECOND < INTERVAL 1 MICROSECOND;
SELECT INTERVAL 1000001 NANOSECOND < INTERVAL 1 MILLISECOND;
SELECT INTERVAL 2000000001 NANOSECOND < INTERVAL 2 SECOND;
SELECT INTERVAL 60000000000 NANOSECOND != INTERVAL 1 MINUTE;
SELECT INTERVAL 7199999999999 NANOSECOND > INTERVAL 2 HOUR;
SELECT INTERVAL 1 NANOSECOND > INTERVAL 2 DAY;
SELECT INTERVAL 5 NANOSECOND > INTERVAL 1 WEEK;
SELECT INTERVAL 1 NANOSECOND < INTERVAL 2 MONTH; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing microseconds');
SELECT INTERVAL 1 MICROSECOND < INTERVAL 999 MICROSECOND;
SELECT INTERVAL 1001 MICROSECOND > INTERVAL 1 MILLISECOND;
SELECT INTERVAL 2000000 MICROSECOND = INTERVAL 2 SECOND;
SELECT INTERVAL 179999999 MICROSECOND < INTERVAL 3 MINUTE;
SELECT INTERVAL 3600000000 MICROSECOND = INTERVAL 1 HOUR;
SELECT INTERVAL 36000000000000 MICROSECOND > INTERVAL 2 DAY;
SELECT INTERVAL 1209600000000 MICROSECOND = INTERVAL 2 WEEK;
SELECT INTERVAL 1 MICROSECOND > INTERVAL 999 MICROSECOND;
SELECT INTERVAL 1001 MICROSECOND < INTERVAL 1 MILLISECOND;
SELECT INTERVAL 2000000 MICROSECOND != INTERVAL 2 SECOND;
SELECT INTERVAL 179999999 MICROSECOND > INTERVAL 3 MINUTE;
SELECT INTERVAL 3600000000 MICROSECOND != INTERVAL 1 HOUR;
SELECT INTERVAL 36000000000000 MICROSECOND < INTERVAL 2 DAY;
SELECT INTERVAL 1209600000000 MICROSECOND != INTERVAL 2 WEEK;
SELECT INTERVAL 36000000000000 MICROSECOND < INTERVAL 1 QUARTER; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing milliseconds');
SELECT INTERVAL 2000 MILLISECOND > INTERVAL 2 MILLISECOND;
SELECT INTERVAL 2000 MILLISECOND = INTERVAL 2 SECOND;
SELECT INTERVAL 170000 MILLISECOND < INTERVAL 3 MINUTE;
SELECT INTERVAL 144000001 MILLISECOND > INTERVAL 40 HOUR;
SELECT INTERVAL 1728000000 MILLISECOND = INTERVAL 20 DAY;
SELECT INTERVAL 1198599999 MILLISECOND < INTERVAL 2 WEEK;
SELECT INTERVAL 2000 MILLISECOND < INTERVAL 2 MILLISECOND;
SELECT INTERVAL 2000 MILLISECOND != INTERVAL 2 SECOND;
SELECT INTERVAL 170000 MILLISECOND > INTERVAL 3 MINUTE;
SELECT INTERVAL 144000001 MILLISECOND < INTERVAL 40 HOUR;
SELECT INTERVAL 1728000000 MILLISECOND != INTERVAL 20 DAY;
SELECT INTERVAL 1198599999 MILLISECOND > INTERVAL 2 WEEK;
SELECT INTERVAL 36000000000000 MILLISECOND < INTERVAL 1 YEAR; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing seconds');
SELECT INTERVAL 120 SECOND > INTERVAL 2 SECOND;
SELECT INTERVAL 120 SECOND = INTERVAL 2 MINUTE;
SELECT INTERVAL 1 SECOND < INTERVAL 2 HOUR;
SELECT INTERVAL 86401 SECOND >= INTERVAL 1 DAY;
SELECT INTERVAL 1209600 SECOND = INTERVAL 2 WEEK;
SELECT INTERVAL 120 SECOND < INTERVAL 2 SECOND;
SELECT INTERVAL 120 SECOND != INTERVAL 2 MINUTE;
SELECT INTERVAL 1 SECOND > INTERVAL 2 HOUR;
SELECT INTERVAL 86401 SECOND < INTERVAL 1 DAY;
SELECT INTERVAL 1209600 SECOND != INTERVAL 2 WEEK;
SELECT INTERVAL 36000000000000 SECOND < INTERVAL 1 MONTH; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing minutes');
SELECT INTERVAL 1 MINUTE < INTERVAL 59 MINUTE;
SELECT INTERVAL 1 MINUTE < INTERVAL 59 HOUR;
SELECT INTERVAL 1440 MINUTE = INTERVAL 1 DAY;
SELECT INTERVAL 30241 MINUTE > INTERVAL 3 WEEK;
SELECT INTERVAL 1 MINUTE > INTERVAL 59 MINUTE;
SELECT INTERVAL 1 MINUTE > INTERVAL 59 HOUR;
SELECT INTERVAL 1440 MINUTE != INTERVAL 1 DAY;
SELECT INTERVAL 30241 MINUTE < INTERVAL 3 WEEK;
SELECT INTERVAL 2 MINUTE = INTERVAL 120 QUARTER; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing hours');
SELECT INTERVAL 48 HOUR > INTERVAL 2 HOUR;
SELECT INTERVAL 48 HOUR >= INTERVAL 2 DAY;
SELECT INTERVAL 672 HOUR = INTERVAL 4 WEEK;
SELECT INTERVAL 48 HOUR < INTERVAL 2 HOUR;
SELECT INTERVAL 48 HOUR < INTERVAL 2 DAY;
SELECT INTERVAL 672 HOUR != INTERVAL 4 WEEK;
SELECT INTERVAL 2 HOUR < INTERVAL 1 YEAR; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing days');
SELECT INTERVAL 1 DAY < INTERVAL 23 DAY;
SELECT INTERVAL 25 DAY > INTERVAL 3 WEEK;
SELECT INTERVAL 1 DAY > INTERVAL 23 DAY;
SELECT INTERVAL 25 DAY < INTERVAL 3 WEEK;
SELECT INTERVAL 2 DAY = INTERVAL 48 MONTH; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing weeks');
SELECT INTERVAL 1 WEEK < INTERVAL 6 WEEK;
SELECT INTERVAL 1 WEEK > INTERVAL 6 WEEK;
SELECT INTERVAL 124 WEEK > INTERVAL 8 QUARTER; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing months');
SELECT INTERVAL 1 MONTH < INTERVAL 3 MONTH;
SELECT INTERVAL 124 MONTH > INTERVAL 5 QUARTER;
SELECT INTERVAL 36 MONTH = INTERVAL 3 YEAR;
SELECT INTERVAL 1 MONTH > INTERVAL 3 MONTH;
SELECT INTERVAL 124 MONTH < INTERVAL 5 QUARTER;
SELECT INTERVAL 36 MONTH != INTERVAL 3 YEAR;
SELECT INTERVAL 6 MONTH = INTERVAL 26 MICROSECOND; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing quarters');
SELECT INTERVAL 5 QUARTER > INTERVAL 4 QUARTER;
SELECT INTERVAL 20 QUARTER = INTERVAL 5 YEAR;
SELECT INTERVAL 5 QUARTER < INTERVAL 4 QUARTER;
SELECT INTERVAL 20 QUARTER != INTERVAL 5 YEAR;
SELECT INTERVAL 2 QUARTER = INTERVAL 6 NANOSECOND; -- { serverError NO_COMMON_TYPE }
SELECT('Comparing years');
SELECT INTERVAL 1 YEAR < INTERVAL 3 YEAR;
SELECT INTERVAL 1 YEAR > INTERVAL 3 YEAR;
SELECT INTERVAL 2 YEAR = INTERVAL 8 SECOND; -- { serverError NO_COMMON_TYPE }