Merge pull request #54400 from evillique/adddate-function

Add `addDate` function for compatibility with MySQL
This commit is contained in:
Nikolay Degterinsky 2023-09-13 18:59:26 +02:00 committed by GitHub
commit 140a466a1e
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
6 changed files with 258 additions and 9 deletions

View File

@ -983,6 +983,8 @@ Result:
Adds the time interval or date interval to the provided date or date with time.
If the addition results in a value outside the bounds of the data type, the result is undefined.
**Syntax**
``` sql
@ -1006,13 +1008,13 @@ Aliases: `dateAdd`, `DATE_ADD`.
- `year`
- `value` — Value of interval to add. [Int](../../sql-reference/data-types/int-uint.md).
- `date` — The date or date with time to which `value` is added. [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
- `date` — The date or date with time to which `value` is added. [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).
**Returned value**
Date or date with time obtained by adding `value`, expressed in `unit`, to `date`.
Type: [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
Type: [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).
**Example**
@ -1028,10 +1030,16 @@ Result:
└───────────────────────────────────────────────┘
```
**See Also**
- [addDate](#addDate)
## date\_sub
Subtracts the time interval or date interval from the provided date or date with time.
If the subtraction results in a value outside the bounds of the data type, the result is undefined.
**Syntax**
``` sql
@ -1056,13 +1064,13 @@ Aliases: `dateSub`, `DATE_SUB`.
- `year`
- `value` — Value of interval to subtract. [Int](../../sql-reference/data-types/int-uint.md).
- `date` — The date or date with time from which `value` is subtracted. [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
- `date` — The date or date with time from which `value` is subtracted. [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).
**Returned value**
Date or date with time obtained by subtracting `value`, expressed in `unit`, from `date`.
Type: [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
Type: [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).
**Example**
@ -1078,10 +1086,15 @@ Result:
└────────────────────────────────────────────────┘
```
**See Also**
- [subDate](#subDate)
## timestamp\_add
Adds the specified time value with the provided date or date time value.
If the addition results in a value outside the bounds of the data type, the result is undefined.
**Syntax**
``` sql
@ -1092,7 +1105,7 @@ Aliases: `timeStampAdd`, `TIMESTAMP_ADD`.
**Arguments**
- `date` — Date or date with time. [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
- `date` — Date or date with time. [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).
- `value` — Value of interval to add. [Int](../../sql-reference/data-types/int-uint.md).
- `unit` — The type of interval to add. [String](../../sql-reference/data-types/string.md).
Possible values:
@ -1110,7 +1123,7 @@ Aliases: `timeStampAdd`, `TIMESTAMP_ADD`.
Date or date with time with the specified `value` expressed in `unit` added to `date`.
Type: [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
Type: [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).
**Example**
@ -1130,6 +1143,8 @@ Result:
Subtracts the time interval from the provided date or date with time.
If the subtraction results in a value outside the bounds of the data type, the result is undefined.
**Syntax**
``` sql
@ -1153,13 +1168,13 @@ Aliases: `timeStampSub`, `TIMESTAMP_SUB`.
- `year`
- `value` — Value of interval to subtract. [Int](../../sql-reference/data-types/int-uint.md).
- `date` — Date or date with time. [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
- `date` — Date or date with time. [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).
**Returned value**
Date or date with time obtained by subtracting `value`, expressed in `unit`, from `date`.
Type: [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
Type: [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).
**Example**
@ -1175,6 +1190,90 @@ Result:
└──────────────────────────────────────────────────────────────┘
```
## addDate
Adds the time interval or date interval to the provided date or date with time.
If the addition results in a value outside the bounds of the data type, the result is undefined.
**Syntax**
``` sql
addDate(date, interval)
```
**Arguments**
- `date` — The date or date with time to which `interval` is added. [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).
- `interval` — Interval to add. [Interval](../../sql-reference/data-types/special-data-types/interval.md).
**Returned value**
Date or date with time obtained by adding `interval` to `date`.
Type: [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).
**Example**
```sql
SELECT addDate(toDate('2018-01-01'), INTERVAL 3 YEAR);
```
Result:
```text
┌─addDate(toDate('2018-01-01'), toIntervalYear(3))─┐
│ 2021-01-01 │
└──────────────────────────────────────────────────┘
```
Alias: `ADDDATE`
**See Also**
- [date_add](#date_add)
## subDate
Subtracts the time interval or date interval from the provided date or date with time.
If the subtraction results in a value outside the bounds of the data type, the result is undefined.
**Syntax**
``` sql
subDate(date, interval)
```
**Arguments**
- `date` — The date or date with time from which `interval` is subtracted. [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).
- `interval` — Interval to subtract. [Interval](../../sql-reference/data-types/special-data-types/interval.md).
**Returned value**
Date or date with time obtained by subtracting `interval` from `date`.
Type: [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).
**Example**
```sql
SELECT subDate(toDate('2018-01-01'), INTERVAL 3 YEAR);
```
Result:
```text
┌─subDate(toDate('2018-01-01'), toIntervalYear(3))─┐
│ 2015-01-01 │
└──────────────────────────────────────────────────┘
```
Alias: `SUBDATE`
**See Also**
- [date_sub](#date_sub)
## now
Returns the current date and time at the moment of query analysis. The function is a constant expression.
@ -1671,7 +1770,7 @@ monthName(date)
**Arguments**
- `date` — Date or date with time. [Date](../../sql-reference/data-types/date.md) or [DateTime](../../sql-reference/data-types/datetime.md).
- `date` — Date or date with time. [Date](../../sql-reference/data-types/date.md), [DateTime](../../sql-reference/data-types/datetime.md) or [DateTime64](../../sql-reference/data-types/datetime64.md).
**Returned value**

View File

@ -0,0 +1,108 @@
#include <Functions/FunctionFactory.h>
#include <DataTypes/DataTypeDate.h>
#include <DataTypes/DataTypeDate32.h>
#include <DataTypes/DataTypeDateTime.h>
#include <DataTypes/DataTypeDateTime64.h>
namespace DB
{
namespace ErrorCodes
{
extern const int ILLEGAL_TYPE_OF_ARGUMENT;
}
namespace
{
template <typename Op>
class FunctionOpDate : public IFunction
{
public:
static constexpr auto name = Op::name;
explicit FunctionOpDate(ContextPtr context_) : context(context_) {}
static FunctionPtr create(ContextPtr context) { return std::make_shared<FunctionOpDate<Op>>(context); }
String getName() const override { return name; }
bool isSuitableForShortCircuitArgumentsExecution(const DataTypesWithConstInfo & /*arguments*/) const override { return false; }
size_t getNumberOfArguments() const override { return 2; }
DataTypePtr getReturnTypeImpl(const ColumnsWithTypeAndName & arguments) const override
{
if (!isDateOrDate32(arguments[0].type) && !isDateTime(arguments[0].type) && !isDateTime64(arguments[0].type))
throw Exception(
ErrorCodes::ILLEGAL_TYPE_OF_ARGUMENT,
"Illegal type {} of 1st argument of function {}. Should be a date or a date with time",
arguments[0].type->getName(),
getName());
if (!isInterval(arguments[1].type))
throw Exception(
ErrorCodes::ILLEGAL_TYPE_OF_ARGUMENT,
"Illegal type {} of 2nd argument of function {}. Should be an interval",
arguments[1].type->getName(),
getName());
auto op = FunctionFactory::instance().get(Op::internal_name, context);
auto op_build = op->build(arguments);
return op_build->getResultType();
}
bool useDefaultImplementationForConstants() const override { return true; }
ColumnNumbers getArgumentsThatAreAlwaysConstant() const override { return {0, 2}; }
ColumnPtr executeImpl(const ColumnsWithTypeAndName & arguments, const DataTypePtr &, size_t input_rows_count) const override
{
if (!isDateOrDate32(arguments[0].type) && !isDateTime(arguments[0].type) && !isDateTime64(arguments[0].type))
throw Exception(
ErrorCodes::ILLEGAL_TYPE_OF_ARGUMENT,
"Illegal type {} of 1st argument of function {}. Should be a date or a date with time",
arguments[0].type->getName(),
getName());
if (!isInterval(arguments[1].type))
throw Exception(
ErrorCodes::ILLEGAL_TYPE_OF_ARGUMENT,
"Illegal type {} of 2nd argument of function {}. Should be an interval",
arguments[1].type->getName(),
getName());
auto op = FunctionFactory::instance().get(Op::internal_name, context);
auto op_build = op->build(arguments);
auto res_type = op_build->getResultType();
return op_build->execute(arguments, res_type, input_rows_count);
}
private:
ContextPtr context;
};
}
struct AddDate
{
static constexpr auto name = "addDate";
static constexpr auto internal_name = "plus";
};
struct SubDate
{
static constexpr auto name = "subDate";
static constexpr auto internal_name = "minus";
};
using FunctionAddDate = FunctionOpDate<AddDate>;
using FunctionSubDate = FunctionOpDate<SubDate>;
REGISTER_FUNCTION(AddInterval)
{
factory.registerFunction<FunctionAddDate>({}, FunctionFactory::CaseInsensitive);
factory.registerFunction<FunctionSubDate>({}, FunctionFactory::CaseInsensitive);
}
}

View File

@ -68,6 +68,7 @@ accurateCastOrDefault
accurateCastOrNull
acos
acosh
addDate
addDays
addHours
addMicroseconds
@ -668,6 +669,7 @@ splitByWhitespace
sqrt
startsWith
subBitmap
subDate
substring
substringIndex
substringIndexUTF8

View File

@ -0,0 +1,11 @@
2022-05-07 00:05:00
2022-05-07 00:05:00
2022-05-07 00:05:00.000
2022-05-07 00:05:00
2022-05-07 00:05:00.000
---
2022-05-06 23:55:00
2022-05-06 23:55:00
2022-05-06 23:55:00.000
2022-05-06 23:55:00
2022-05-06 23:55:00.000

View File

@ -0,0 +1,27 @@
SET session_timezone = 'UTC';
SELECT ADDDATE('2022-05-07'::Date, INTERVAL 5 MINUTE);
SELECT addDate('2022-05-07'::Date, INTERVAL 5 MINUTE);
SELECT addDate('2022-05-07'::Date32, INTERVAL 5 MINUTE);
SELECT addDate('2022-05-07'::DateTime, INTERVAL 5 MINUTE);
SELECT addDate('2022-05-07'::DateTime64, INTERVAL 5 MINUTE);
SELECT addDate('2022-05-07'::Date); -- { serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH }
SELECT addDate('2022-05-07'::Date, INTERVAL 5 MINUTE, 5); -- { serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH }
SELECT addDate('2022-05-07'::Date, 10); -- { serverError ILLEGAL_TYPE_OF_ARGUMENT }
SELECT addDate('1234', INTERVAL 5 MINUTE); -- { serverError ILLEGAL_TYPE_OF_ARGUMENT }
SELECT '---';
SELECT SUBDATE('2022-05-07'::Date, INTERVAL 5 MINUTE);
SELECT subDate('2022-05-07'::Date, INTERVAL 5 MINUTE);
SELECT subDate('2022-05-07'::Date32, INTERVAL 5 MINUTE);
SELECT subDate('2022-05-07'::DateTime, INTERVAL 5 MINUTE);
SELECT subDate('2022-05-07'::DateTime64, INTERVAL 5 MINUTE);
SELECT subDate('2022-05-07'::Date); -- { serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH }
SELECT subDate('2022-05-07'::Date, INTERVAL 5 MINUTE, 5); -- { serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH }
SELECT subDate('2022-05-07'::Date, 10); -- { serverError ILLEGAL_TYPE_OF_ARGUMENT }
SELECT subDate('1234', INTERVAL 5 MINUTE); -- { serverError ILLEGAL_TYPE_OF_ARGUMENT }

View File

@ -987,6 +987,7 @@ acos
acosh
activecube
activerecord
addDate
addDays
addHours
addMinutes
@ -2255,6 +2256,7 @@ structureToProtobufSchema
studentTTest
studentttest
subBitmap
subDate
subarray
subarrays
subcolumn