Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add addDate function for compatibility with MySQL #54400

Merged
merged 4 commits into from Sep 13, 2023
Merged
Show file tree
Hide file tree
Changes from 2 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
39 changes: 39 additions & 0 deletions docs/en/sql-reference/functions/date-time-functions.md
Expand Up @@ -987,6 +987,10 @@ Result:
└───────────────────────────────────────────────┘
```

**See Also**

- [addDate](#addDate)

## date\_sub

Subtracts the time interval or date interval from the provided date or date with time.
Expand Down Expand Up @@ -1134,6 +1138,41 @@ Result:
└──────────────────────────────────────────────────────────────┘
```

## addDate
evillique marked this conversation as resolved.
Show resolved Hide resolved

Adds the time interval or date interval to the provided date or date with time.
evillique marked this conversation as resolved.
Show resolved Hide resolved

**Syntax**

``` sql
addDate(date, interval)
```

**Arguments**

- `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).
- `interval` — Interval to add. [Interval](../../sql-reference/data-types/special-data-types/interval.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).

**Example**

```sql
SELECT addDate(toDate('2018-01-01'), INTERVAL 3 YEAR);
```

Result:

```text
┌─addDate(toDate('2018-01-01'), toIntervalYear(3))─┐
│ 2021-01-01 │
└──────────────────────────────────────────────────┘
```

## now

Returns the current date and time at the moment of query analysis. The function is a constant expression.
Expand Down
88 changes: 88 additions & 0 deletions src/Functions/addDate.cpp
@@ -0,0 +1,88 @@
#include <Functions/FunctionFactory.h>
#include <Functions/FunctionDateOrDateTimeAddInterval.h>

namespace DB
{
namespace ErrorCodes
{
extern const int ILLEGAL_TYPE_OF_ARGUMENT;
}

namespace
{

class FunctionAddDate : public IFunction
{
public:
static constexpr auto name = "addDate";

explicit FunctionAddDate(ContextPtr context_) : context(context_) {}

static FunctionPtr create(ContextPtr context) { return std::make_shared<FunctionAddDate>(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 1st argument of function {}. Should be an interval",
arguments[0].type->getName(),
getName());

auto plus = FunctionFactory::instance().get("plus", context);
auto plus_build = plus->build(arguments);

return plus_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 1st argument of function {}. Should be an interval",
arguments[0].type->getName(),
getName());

auto plus = FunctionFactory::instance().get("plus", context);
auto plus_build = plus->build(arguments);

auto res_type = plus_build->getResultType();
return plus_build->execute(arguments, res_type, input_rows_count);
}

private:
ContextPtr context;
};

}


REGISTER_FUNCTION(AddInterval)
{
factory.registerFunction<FunctionAddDate>();
}

}
Expand Up @@ -68,6 +68,7 @@ accurateCastOrDefault
accurateCastOrNull
acos
acosh
addDate
addDays
addHours
addMicroseconds
Expand Down
4 changes: 4 additions & 0 deletions tests/queries/0_stateless/02834_add_date_function.reference
@@ -0,0 +1,4 @@
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
9 changes: 9 additions & 0 deletions tests/queries/0_stateless/02834_add_date_function.sql
@@ -0,0 +1,9 @@
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);
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Maybe test what happens if addition moves the result beyond the bounds of the date time type?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The behavior will be the same as in the case with the + or - operations: 1900-01-01 00:00:00.000 with the required precision.

In MySQL we simply get NULL. Should we try to replicate this behavior?

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

So, if the result is outside the bounds of the data type, we say that the result is undefined.
The same semantics is used in makeDate(): https://fiddle.clickhouse.com/e58005b1-95f7-49fd-9989-10e295bfb82f

In my view, there is no need to replicate MySQL's behavior, it is more important to stay consistent within ClickHouse's functions and it's an edge case anyways.


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 }
1 change: 1 addition & 0 deletions utils/check-style/aspell-ignore/en/aspell-dict.txt
Expand Up @@ -982,6 +982,7 @@ acos
acosh
activecube
activerecord
addDate
evillique marked this conversation as resolved.
Show resolved Hide resolved
addDays
addHours
addMinutes
Expand Down