From a6ba442ba7f89d9f762f7541f60b476c1d6a45c2 Mon Sep 17 00:00:00 2001 From: "opensearch-trigger-bot[bot]" <98922864+opensearch-trigger-bot[bot]@users.noreply.github.com> Date: Mon, 6 Feb 2023 09:11:03 -0800 Subject: [PATCH] Update `DATE_ADD`/`ADDDATE` and `DATE_SUB`/`SUBDATE` functions. (#122) (#1182) (#1325) * Update `DATE_ADD`/`ADDDATE` and `DATE_SUB`/`SUBDATE` functions. (#122) Signed-off-by: Yury-Fridlyand (cherry picked from commit af188a3fe364f03eb9495f18b58ee9d707b1fb80) Co-authored-by: Yury-Fridlyand --- .../sql/data/model/ExprValueUtils.java | 2 + .../org/opensearch/sql/expression/DSL.java | 16 - .../expression/datetime/DateTimeFunction.java | 191 +++++++---- .../expression/datetime/IntervalClause.java | 2 +- .../datetime/DateAddAndAddDateTest.java | 166 ++++++++++ .../datetime/DateSubAndSubDateTest.java | 166 ++++++++++ .../datetime/DateTimeFunctionTest.java | 257 --------------- .../expression/datetime/DateTimeTestBase.java | 41 ++- .../datetime/IntervalClauseTest.java | 2 +- docs/user/dql/functions.rst | 102 +++--- docs/user/ppl/functions/datetime.rst | 107 ++++--- .../sql/ppl/DateTimeFunctionIT.java | 300 +++++++++++++----- .../sql/sql/DateTimeFunctionIT.java | 217 +++++++++---- 13 files changed, 981 insertions(+), 588 deletions(-) create mode 100644 core/src/test/java/org/opensearch/sql/expression/datetime/DateAddAndAddDateTest.java create mode 100644 core/src/test/java/org/opensearch/sql/expression/datetime/DateSubAndSubDateTest.java diff --git a/core/src/main/java/org/opensearch/sql/data/model/ExprValueUtils.java b/core/src/main/java/org/opensearch/sql/data/model/ExprValueUtils.java index 932a1f3b0c..43a3140ef3 100644 --- a/core/src/main/java/org/opensearch/sql/data/model/ExprValueUtils.java +++ b/core/src/main/java/org/opensearch/sql/data/model/ExprValueUtils.java @@ -142,6 +142,8 @@ public static ExprValue fromObjectValue(Object o) { return timeValue((LocalTime) o); } else if (o instanceof Instant) { return timestampValue((Instant) o); + } else if (o instanceof TemporalAmount) { + return intervalValue((TemporalAmount) o); } else { throw new ExpressionEvaluationException("unsupported object " + o.getClass()); } diff --git a/core/src/main/java/org/opensearch/sql/expression/DSL.java b/core/src/main/java/org/opensearch/sql/expression/DSL.java index 57ba773d30..4d928ef20f 100644 --- a/core/src/main/java/org/opensearch/sql/expression/DSL.java +++ b/core/src/main/java/org/opensearch/sql/expression/DSL.java @@ -290,10 +290,6 @@ public static FunctionExpression multiply(Expression... expressions) { return compile(FunctionProperties.None, BuiltinFunctionName.MULTIPLY, expressions); } - public static FunctionExpression adddate(Expression... expressions) { - return compile(FunctionProperties.None, BuiltinFunctionName.ADDDATE, expressions); - } - public static FunctionExpression convert_tz(Expression... expressions) { return compile(FunctionProperties.None, BuiltinFunctionName.CONVERT_TZ, expressions); } @@ -306,14 +302,6 @@ public static FunctionExpression datetime(Expression... expressions) { return compile(FunctionProperties.None, BuiltinFunctionName.DATETIME, expressions); } - public static FunctionExpression date_add(Expression... expressions) { - return compile(FunctionProperties.None, BuiltinFunctionName.DATE_ADD, expressions); - } - - public static FunctionExpression date_sub(Expression... expressions) { - return compile(FunctionProperties.None, BuiltinFunctionName.DATE_SUB, expressions); - } - public static FunctionExpression day(Expression... expressions) { return compile(FunctionProperties.None, BuiltinFunctionName.DAY, expressions); } @@ -406,10 +394,6 @@ public static FunctionExpression second_of_minute(Expression... expressions) { return compile(FunctionProperties.None, BuiltinFunctionName.SECOND_OF_MINUTE, expressions); } - public static FunctionExpression subdate(Expression... expressions) { - return compile(FunctionProperties.None, BuiltinFunctionName.SUBDATE, expressions); - } - public static FunctionExpression time(Expression... expressions) { return compile(FunctionProperties.None, BuiltinFunctionName.TIME, expressions); } diff --git a/core/src/main/java/org/opensearch/sql/expression/datetime/DateTimeFunction.java b/core/src/main/java/org/opensearch/sql/expression/datetime/DateTimeFunction.java index 89a870087e..02bd911fc7 100644 --- a/core/src/main/java/org/opensearch/sql/expression/datetime/DateTimeFunction.java +++ b/core/src/main/java/org/opensearch/sql/expression/datetime/DateTimeFunction.java @@ -50,10 +50,14 @@ import java.time.format.DateTimeFormatter; import java.time.format.DateTimeParseException; import java.time.format.TextStyle; +import java.time.temporal.TemporalAmount; +import java.util.Arrays; import java.util.Locale; import java.util.TimeZone; import java.util.concurrent.TimeUnit; +import java.util.stream.Stream; import lombok.experimental.UtilityClass; +import org.apache.commons.lang3.tuple.Pair; import org.opensearch.sql.data.model.ExprDateValue; import org.opensearch.sql.data.model.ExprDatetimeValue; import org.opensearch.sql.data.model.ExprDoubleValue; @@ -69,10 +73,14 @@ import org.opensearch.sql.expression.function.BuiltinFunctionName; import org.opensearch.sql.expression.function.BuiltinFunctionRepository; import org.opensearch.sql.expression.function.DefaultFunctionResolver; +import org.opensearch.sql.expression.function.FunctionBuilder; import org.opensearch.sql.expression.function.FunctionDSL; import org.opensearch.sql.expression.function.FunctionName; import org.opensearch.sql.expression.function.FunctionProperties; import org.opensearch.sql.expression.function.FunctionResolver; +import org.opensearch.sql.expression.function.FunctionSignature; +import org.opensearch.sql.expression.function.SerializableFunction; +import org.opensearch.sql.expression.function.SerializableTriFunction; import org.opensearch.sql.utils.DateTimeUtils; /** @@ -232,30 +240,51 @@ private FunctionResolver current_date() { } /** - * Specify a start date and add a temporal amount to the date. + * A common signature for `date_add` and `date_sub`. + * Specify a start date and add/subtract a temporal amount to/from the date. * The return type depends on the date type and the interval unit. Detailed supported signatures: - * (STRING/DATE/DATETIME/TIMESTAMP, INTERVAL) -> DATETIME - * (DATE, LONG) -> DATE - * (STRING/DATETIME/TIMESTAMP, LONG) -> DATETIME - */ - private DefaultFunctionResolver add_date(FunctionName functionName) { - return define(functionName, - impl(nullMissingHandling(DateTimeFunction::exprAddDateInterval), - DATETIME, STRING, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprAddDateInterval), DATETIME, DATE, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprAddDateInterval), + * (DATE/DATETIME/TIMESTAMP/TIME, INTERVAL) -> DATETIME + * MySQL has these signatures too + * (DATE, INTERVAL) -> DATE // when interval has no time part + * (TIME, INTERVAL) -> TIME // when interval has no date part + * (STRING, INTERVAL) -> STRING // when argument has date or datetime string, + * // result has date or datetime depending on interval type + */ + private Stream> get_date_add_date_sub_signatures( + SerializableTriFunction function) { + return Stream.of( + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, DATE, INTERVAL), + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, DATETIME, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprAddDateInterval), + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, TIMESTAMP, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprAddDateDays), DATE, DATE, LONG), - impl(nullMissingHandling(DateTimeFunction::exprAddDateDays), DATETIME, DATETIME, LONG), - impl(nullMissingHandling(DateTimeFunction::exprAddDateDays), DATETIME, TIMESTAMP, LONG), - impl(nullMissingHandling(DateTimeFunction::exprAddDateDays), DATETIME, STRING, LONG) + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, TIME, INTERVAL) + ); + } + + /** + * A common signature for `adddate` and `subdate`. + * Adds/subtracts an integer number of days to/from the first argument. + * (DATE, LONG) -> DATE + * (TIME/DATETIME/TIMESTAMP, LONG) -> DATETIME + */ + private Stream> get_adddate_subdate_signatures( + SerializableTriFunction function) { + return Stream.of( + implWithProperties(nullMissingHandlingWithProperties(function), DATE, DATE, LONG), + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, DATETIME, LONG), + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, TIMESTAMP, LONG), + implWithProperties(nullMissingHandlingWithProperties(function), DATETIME, TIME, LONG) ); } private DefaultFunctionResolver adddate() { - return add_date(BuiltinFunctionName.ADDDATE.getName()); + return define(BuiltinFunctionName.ADDDATE.getName(), + (SerializableFunction>[]) + (Stream.concat( + get_date_add_date_sub_signatures(DateTimeFunction::exprAddDateInterval), + get_adddate_subdate_signatures(DateTimeFunction::exprAddDateDays)) + .toArray(SerializableFunction[]::new))); } /** @@ -388,34 +417,17 @@ private FunctionResolver datetime() { } private DefaultFunctionResolver date_add() { - return add_date(BuiltinFunctionName.DATE_ADD.getName()); - } - - /** - * Specify a start date and subtract a temporal amount to the date. - * The return type depends on the date type and the interval unit. Detailed supported signatures: - * (STRING/DATE/DATETIME/TIMESTAMP, INTERVAL) -> DATETIME - * (DATE, LONG) -> DATE - * (STRING/DATETIME/TIMESTAMP, LONG) -> DATETIME - */ - private DefaultFunctionResolver sub_date(FunctionName functionName) { - return define(functionName, - impl(nullMissingHandling(DateTimeFunction::exprSubDateInterval), - DATETIME, STRING, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprSubDateInterval), DATETIME, DATE, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprSubDateInterval), - DATETIME, DATETIME, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprSubDateInterval), - DATETIME, TIMESTAMP, INTERVAL), - impl(nullMissingHandling(DateTimeFunction::exprSubDateDays), DATE, DATE, LONG), - impl(nullMissingHandling(DateTimeFunction::exprSubDateDays), DATETIME, DATETIME, LONG), - impl(nullMissingHandling(DateTimeFunction::exprSubDateDays), DATETIME, TIMESTAMP, LONG), - impl(nullMissingHandling(DateTimeFunction::exprSubDateDays), DATETIME, STRING, LONG) - ); + return define(BuiltinFunctionName.DATE_ADD.getName(), + (SerializableFunction>[]) + get_date_add_date_sub_signatures(DateTimeFunction::exprAddDateInterval) + .toArray(SerializableFunction[]::new)); } private DefaultFunctionResolver date_sub() { - return sub_date(BuiltinFunctionName.DATE_SUB.getName()); + return define(BuiltinFunctionName.DATE_SUB.getName(), + (SerializableFunction>[]) + get_date_add_date_sub_signatures(DateTimeFunction::exprSubDateInterval) + .toArray(SerializableFunction[]::new)); } /** @@ -641,7 +653,12 @@ private DefaultFunctionResolver second(BuiltinFunctionName name) { } private DefaultFunctionResolver subdate() { - return sub_date(BuiltinFunctionName.SUBDATE.getName()); + return define(BuiltinFunctionName.SUBDATE.getName(), + (SerializableFunction>[]) + (Stream.concat( + get_date_add_date_sub_signatures(DateTimeFunction::exprSubDateInterval), + get_adddate_subdate_signatures(DateTimeFunction::exprSubDateDays)) + .toArray(SerializableFunction[]::new))); } /** @@ -876,29 +893,65 @@ private ExprValue dayOfWeekToday(Clock clock) { } /** - * ADDDATE function implementation for ExprValue. + * DATE_ADD function implementation for ExprValue. + * + * @param functionProperties An FunctionProperties object. + * @param datetime ExprValue of Date/Time/Datetime/Timestamp type. + * @param interval ExprValue of Interval type, the temporal amount to add. + * @return Datetime resulted from `interval` added to `datetime`. + */ + private ExprValue exprAddDateInterval(FunctionProperties functionProperties, + ExprValue datetime, ExprValue interval) { + return exprDateApplyInterval(functionProperties, datetime, interval.intervalValue(), true); + } + + /** + * Adds or subtracts `interval` to/from `datetime`. * - * @param date ExprValue of String/Date/Datetime/Timestamp type. - * @param expr ExprValue of Interval type, the temporal amount to add. - * @return Datetime resulted from expr added to date. + * @param functionProperties An FunctionProperties object. + * @param datetime A Date/Time/Datetime/Timestamp value to change. + * @param interval An Interval to isAdd or subtract. + * @param isAdd A flag: true to isAdd, false to subtract. + * @return Datetime calculated. */ - private ExprValue exprAddDateInterval(ExprValue date, ExprValue expr) { - ExprValue exprValue = new ExprDatetimeValue(date.datetimeValue().plus(expr.intervalValue())); - return (exprValue.timeValue().toSecondOfDay() == 0 ? new ExprDateValue(exprValue.dateValue()) - : exprValue); + private ExprValue exprDateApplyInterval(FunctionProperties functionProperties, + ExprValue datetime, + TemporalAmount interval, + Boolean isAdd) { + var dt = extractDateTime(datetime, functionProperties); + return new ExprDatetimeValue(isAdd ? dt.plus(interval) : dt.minus(interval)); } /** * ADDDATE function implementation for ExprValue. * - * @param date ExprValue of String/Date/Datetime/Timestamp type. + * @param functionProperties An FunctionProperties object. + * @param datetime ExprValue of Time/Date/Datetime/Timestamp type. * @param days ExprValue of Long type, representing the number of days to add. - * @return Date/Datetime resulted from days added to date. + * @return Date/Datetime resulted from days added to `datetime`. */ - private ExprValue exprAddDateDays(ExprValue date, ExprValue days) { - ExprValue exprValue = new ExprDatetimeValue(date.datetimeValue().plusDays(days.longValue())); - return (exprValue.timeValue().toSecondOfDay() == 0 ? new ExprDateValue(exprValue.dateValue()) - : exprValue); + private ExprValue exprAddDateDays(FunctionProperties functionProperties, + ExprValue datetime, ExprValue days) { + return exprDateApplyDays(functionProperties, datetime, days.longValue(), true); + } + + /** + * Adds or subtracts `days` to/from `datetime`. + * + * @param functionProperties An FunctionProperties object. + * @param datetime A Date/Time/Datetime/Timestamp value to change. + * @param days A days amount to add or subtract. + * @param isAdd A flag: true to add, false to subtract. + * @return Datetime calculated. + */ + private ExprValue exprDateApplyDays(FunctionProperties functionProperties, + ExprValue datetime, Long days, Boolean isAdd) { + if (datetime.type() == DATE) { + return new ExprDateValue(isAdd ? datetime.dateValue().plusDays(days) + : datetime.dateValue().minusDays(days)); + } + var dt = extractDateTime(datetime, functionProperties); + return new ExprDatetimeValue(isAdd ? dt.plusDays(days) : dt.minusDays(days)); } /** @@ -1325,27 +1378,27 @@ private ExprValue exprSecond(ExprValue time) { /** * SUBDATE function implementation for ExprValue. * - * @param date ExprValue of String/Date/Datetime/Timestamp type. + * @param functionProperties An FunctionProperties object. + * @param date ExprValue of Time/Date/Datetime/Timestamp type. * @param days ExprValue of Long type, representing the number of days to subtract. * @return Date/Datetime resulted from days subtracted to date. */ - private ExprValue exprSubDateDays(ExprValue date, ExprValue days) { - ExprValue exprValue = new ExprDatetimeValue(date.datetimeValue().minusDays(days.longValue())); - return (exprValue.timeValue().toSecondOfDay() == 0 ? new ExprDateValue(exprValue.dateValue()) - : exprValue); + private ExprValue exprSubDateDays(FunctionProperties functionProperties, + ExprValue date, ExprValue days) { + return exprDateApplyDays(functionProperties, date, days.longValue(), false); } /** - * SUBDATE function implementation for ExprValue. + * DATE_SUB function implementation for ExprValue. * - * @param date ExprValue of String/Date/Datetime/Timestamp type. + * @param functionProperties An FunctionProperties object. + * @param datetime ExprValue of Time/Date/Datetime/Timestamp type. * @param expr ExprValue of Interval type, the temporal amount to subtract. - * @return Datetime resulted from expr subtracted to date. + * @return Datetime resulted from expr subtracted to `datetime`. */ - private ExprValue exprSubDateInterval(ExprValue date, ExprValue expr) { - ExprValue exprValue = new ExprDatetimeValue(date.datetimeValue().minus(expr.intervalValue())); - return (exprValue.timeValue().toSecondOfDay() == 0 ? new ExprDateValue(exprValue.dateValue()) - : exprValue); + private ExprValue exprSubDateInterval(FunctionProperties functionProperties, + ExprValue datetime, ExprValue expr) { + return exprDateApplyInterval(functionProperties, datetime, expr.intervalValue(), false); } /** diff --git a/core/src/main/java/org/opensearch/sql/expression/datetime/IntervalClause.java b/core/src/main/java/org/opensearch/sql/expression/datetime/IntervalClause.java index c5076431cc..3df8489b20 100644 --- a/core/src/main/java/org/opensearch/sql/expression/datetime/IntervalClause.java +++ b/core/src/main/java/org/opensearch/sql/expression/datetime/IntervalClause.java @@ -93,7 +93,7 @@ private ExprValue hour(ExprValue value) { } private ExprValue day(ExprValue value) { - return new ExprIntervalValue(Duration.ofDays(getIntegerValue(value))); + return new ExprIntervalValue(Period.ofDays(getIntegerValue(value))); } private ExprValue week(ExprValue value) { diff --git a/core/src/test/java/org/opensearch/sql/expression/datetime/DateAddAndAddDateTest.java b/core/src/test/java/org/opensearch/sql/expression/datetime/DateAddAndAddDateTest.java new file mode 100644 index 0000000000..973b168355 --- /dev/null +++ b/core/src/test/java/org/opensearch/sql/expression/datetime/DateAddAndAddDateTest.java @@ -0,0 +1,166 @@ +/* + * Copyright OpenSearch Contributors + * SPDX-License-Identifier: Apache-2.0 + */ + +package org.opensearch.sql.expression.datetime; + +import static org.junit.jupiter.api.Assertions.assertEquals; +import static org.junit.jupiter.api.Assertions.assertThrows; +import static org.opensearch.sql.data.type.ExprCoreType.DATE; +import static org.opensearch.sql.data.type.ExprCoreType.DATETIME; + +import java.time.Duration; +import java.time.Instant; +import java.time.LocalDate; +import java.time.LocalDateTime; +import java.time.LocalTime; +import java.time.Period; +import java.time.ZoneOffset; +import org.junit.jupiter.api.Test; +import org.opensearch.sql.exception.ExpressionEvaluationException; + +public class DateAddAndAddDateTest extends DateTimeTestBase { + + private LocalDate today() { + return LocalDate.now(functionProperties.getQueryStartClock()); + } + + @Test + public void adddate_returns_datetime_when_args_are_time_and_time_interval() { + var res = adddate(LocalTime.MIN, Duration.ofHours(1).plusMinutes(2)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.of(1, 2).atDate(today()), res.datetimeValue()); + } + + @Test + public void date_add_returns_datetime_when_args_are_time_and_time_interval() { + var res = date_add(LocalTime.of(10, 20, 30), + Duration.ofHours(1).plusMinutes(2).plusSeconds(42)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.of(11, 23, 12).atDate(today()), res.datetimeValue()); + } + + @Test + public void adddate_time_limited_by_24_hours() { + var res = adddate(LocalTime.MAX, Duration.ofNanos(1)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.MIN, res.datetimeValue().toLocalTime()); + } + + @Test + public void date_add_time_limited_by_24_hours() { + var res = date_add(LocalTime.of(10, 20, 30), + Duration.ofHours(20).plusMinutes(50).plusSeconds(7)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.of(7, 10, 37), res.datetimeValue().toLocalTime()); + } + + @Test + public void adddate_returns_datetime_when_args_are_date_and_date_interval() { + var res = adddate(LocalDate.of(2020, 2, 20), Period.of(3, 11, 21)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDate.of(2024, 2, 10).atStartOfDay(), res.datetimeValue()); + } + + @Test + public void date_add_returns_datetime_when_args_are_date_and_date_interval() { + var res = date_add(LocalDate.of(1961, 4, 12), Period.of(50, 50, 50)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDate.of(2015, 8, 1).atStartOfDay(), res.datetimeValue()); + } + + @Test + public void adddate_returns_datetime_when_args_are_date_and_time_interval() { + var res = adddate(LocalDate.of(2020, 2, 20), Duration.ofHours(1).plusMinutes(2)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2020, 2, 20, 1, 2), res.datetimeValue()); + } + + @Test + public void date_add_returns_datetime_when_args_are_date_and_time_interval() { + var res = date_add(LocalDate.of(1961, 4, 12), Duration.ofHours(9).plusMinutes(7)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1961, 4, 12, 9, 7), res.datetimeValue()); + } + + @Test + public void adddate_returns_datetime_when_args_are_time_and_date_interval() { + // Date based on today + var res = adddate(LocalTime.of(1, 2, 0), Period.ofDays(1)); + assertEquals(DATETIME, res.type()); + assertEquals(today().plusDays(1).atTime(LocalTime.of(1, 2, 0)), res.datetimeValue()); + } + + @Test + public void date_add_returns_datetime_when_args_are_time_and_date_interval() { + var res = date_add(LocalTime.MIDNIGHT, Period.ofDays(0)); + assertEquals(DATETIME, res.type()); + assertEquals(today().atStartOfDay(), res.datetimeValue()); + } + + @Test + public void adddate_returns_datetime_when_first_arg_is_datetime() { + var res = adddate(LocalDateTime.of(1961, 4, 12, 9, 7), Duration.ofMinutes(108)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1961, 4, 12, 10, 55), res.datetimeValue()); + } + + @Test + public void date_add_returns_datetime_when_first_arg_is_timestamp() { + var res = date_add(LocalDateTime.of(1961, 4, 12, 9, 7).toInstant(ZoneOffset.UTC), + Duration.ofMinutes(108)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1961, 4, 12, 10, 55), res.datetimeValue()); + } + + @Test + public void adddate_accepts_negative_interval() { + var res = adddate(LocalDateTime.of(2020, 10, 20, 14, 42), Duration.ofDays(-10)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2020, 10, 10, 14, 42), res.datetimeValue()); + assertEquals(subdate(LocalDateTime.of(2020, 10, 20, 14, 42), Duration.ofDays(10)), res); + } + + @Test + public void adddate_has_second_signature_but_not_date_add() { + var res = adddate(LocalDateTime.of(1961, 4, 12, 9, 7), 100500); + assertEquals(DATETIME, res.type()); + + var exception = assertThrows(ExpressionEvaluationException.class, + () -> date_add(LocalDateTime.of(1961, 4, 12, 9, 7), 100500)); + assertEquals("date_add function expected {[DATE,INTERVAL],[DATETIME,INTERVAL]," + + "[TIMESTAMP,INTERVAL],[TIME,INTERVAL]}, but get [DATETIME,INTEGER]", + exception.getMessage()); + } + + @Test + public void adddate_returns_date_when_args_are_date_and_days() { + var res = adddate(LocalDate.of(1961, 4, 12), 100500); + assertEquals(DATE, res.type()); + assertEquals(LocalDate.of(1961, 4, 12).plusDays(100500), res.dateValue()); + } + + @Test + public void adddate_returns_datetime_when_args_are_date_but_days() { + var res = adddate(LocalDate.of(2000, 1, 1).atStartOfDay(), 2); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2000, 1, 3, 0, 0), res.datetimeValue()); + + res = adddate(LocalTime.now(), 2); + assertEquals(DATETIME, res.type()); + assertEquals(today().plusDays(2), res.dateValue()); + + res = adddate(Instant.ofEpochSecond(42), 2); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1970, 1, 3, 0, 0, 42), res.datetimeValue()); + } + + @Test + public void adddate_accepts_negative_days() { + var res = adddate(LocalDateTime.of(2020, 10, 20, 8, 16, 32), -40); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2020, 10, 20, 8, 16, 32).minusDays(40), res.datetimeValue()); + assertEquals(subdate(LocalDateTime.of(2020, 10, 20, 8, 16, 32), 40), res); + } +} diff --git a/core/src/test/java/org/opensearch/sql/expression/datetime/DateSubAndSubDateTest.java b/core/src/test/java/org/opensearch/sql/expression/datetime/DateSubAndSubDateTest.java new file mode 100644 index 0000000000..37c62313db --- /dev/null +++ b/core/src/test/java/org/opensearch/sql/expression/datetime/DateSubAndSubDateTest.java @@ -0,0 +1,166 @@ +/* + * Copyright OpenSearch Contributors + * SPDX-License-Identifier: Apache-2.0 + */ + +package org.opensearch.sql.expression.datetime; + +import static org.junit.jupiter.api.Assertions.assertEquals; +import static org.junit.jupiter.api.Assertions.assertThrows; +import static org.opensearch.sql.data.type.ExprCoreType.DATE; +import static org.opensearch.sql.data.type.ExprCoreType.DATETIME; + +import java.time.Duration; +import java.time.Instant; +import java.time.LocalDate; +import java.time.LocalDateTime; +import java.time.LocalTime; +import java.time.Period; +import java.time.ZoneOffset; +import org.junit.jupiter.api.Test; +import org.opensearch.sql.exception.ExpressionEvaluationException; + +public class DateSubAndSubDateTest extends DateTimeTestBase { + + private LocalDate today() { + return LocalDate.now(functionProperties.getQueryStartClock()); + } + + @Test + public void subdate_returns_datetime_when_args_are_time_and_time_interval() { + var res = subdate(LocalTime.of(21, 0), Duration.ofHours(1).plusMinutes(2)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.of(19, 58).atDate(today()), res.datetimeValue()); + } + + @Test + public void date_sub_returns_datetime_when_args_are_time_and_time_interval() { + var res = date_sub(LocalTime.of(10, 20, 30), + Duration.ofHours(1).plusMinutes(2).plusSeconds(42)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.of(9, 17, 48).atDate(today()), res.datetimeValue()); + } + + @Test + public void subdate_time_limited_by_24_hours() { + var res = subdate(LocalTime.MIN, Duration.ofNanos(1)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.MAX, res.datetimeValue().toLocalTime()); + } + + @Test + public void date_sub_time_limited_by_24_hours() { + var res = date_sub(LocalTime.of(10, 20, 30), + Duration.ofHours(20).plusMinutes(50).plusSeconds(7)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalTime.of(13, 30, 23), res.datetimeValue().toLocalTime()); + } + + @Test + public void subdate_returns_datetime_when_args_are_date_and_date_interval() { + var res = subdate(LocalDate.of(2020, 2, 20), Period.of(3, 11, 21)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDate.of(2016, 2, 28).atStartOfDay(), res.datetimeValue()); + } + + @Test + public void date_sub_returns_datetime_when_args_are_date_and_date_interval() { + var res = date_sub(LocalDate.of(1961, 4, 12), Period.of(50, 50, 50)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDate.of(1906, 12, 24).atStartOfDay(), res.datetimeValue()); + } + + @Test + public void subdate_returns_datetime_when_args_are_date_and_time_interval() { + var res = subdate(LocalDate.of(2020, 2, 20), Duration.ofHours(1).plusMinutes(2)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2020, 2, 19, 22, 58), res.datetimeValue()); + } + + @Test + public void date_sub_returns_datetime_when_args_are_date_and_time_interval() { + var res = date_sub(LocalDate.of(1961, 4, 12), Duration.ofHours(9).plusMinutes(7)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1961, 4, 11, 14, 53), res.datetimeValue()); + } + + @Test + public void subdate_returns_datetime_when_args_are_time_and_date_interval() { + // Date based on today + var res = subdate(LocalTime.of(1, 2, 0), Period.ofDays(1)); + assertEquals(DATETIME, res.type()); + assertEquals(today().minusDays(1).atTime(LocalTime.of(1, 2, 0)), res.datetimeValue()); + } + + @Test + public void date_sub_returns_datetime_when_args_are_time_and_date_interval() { + var res = date_sub(LocalTime.MIDNIGHT, Period.ofDays(0)); + assertEquals(DATETIME, res.type()); + assertEquals(today().atStartOfDay(), res.datetimeValue()); + } + + @Test + public void subdate_returns_datetime_when_first_arg_is_datetime() { + var res = subdate(LocalDateTime.of(1961, 4, 12, 9, 7), Duration.ofMinutes(108)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1961, 4, 12, 7, 19), res.datetimeValue()); + } + + @Test + public void date_sub_returns_datetime_when_first_arg_is_timestamp() { + var res = date_sub(LocalDateTime.of(1961, 4, 12, 9, 7).toInstant(ZoneOffset.UTC), + Duration.ofMinutes(108)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1961, 4, 12, 7, 19), res.datetimeValue()); + } + + @Test + public void subdate_accepts_negative_interval() { + var res = subdate(LocalDateTime.of(2020, 10, 20, 14, 42), Duration.ofDays(-10)); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2020, 10, 30, 14, 42), res.datetimeValue()); + assertEquals(adddate(LocalDateTime.of(2020, 10, 20, 14, 42), Duration.ofDays(10)), res); + } + + @Test + public void subdate_has_second_signature_but_not_date_sub() { + var res = subdate(LocalDateTime.of(1961, 4, 12, 9, 7), 100500); + assertEquals(DATETIME, res.type()); + + var exception = assertThrows(ExpressionEvaluationException.class, + () -> date_sub(LocalDateTime.of(1961, 4, 12, 9, 7), 100500)); + assertEquals("date_sub function expected {[DATE,INTERVAL],[DATETIME,INTERVAL]," + + "[TIMESTAMP,INTERVAL],[TIME,INTERVAL]}, but get [DATETIME,INTEGER]", + exception.getMessage()); + } + + @Test + public void subdate_returns_date_when_args_are_date_and_days() { + var res = subdate(LocalDate.of(1961, 4, 12), 100500); + assertEquals(DATE, res.type()); + assertEquals(LocalDate.of(1961, 4, 12).minusDays(100500), res.dateValue()); + } + + @Test + public void subdate_returns_datetime_when_args_are_date_but_days() { + var res = subdate(LocalDate.of(2000, 1, 1).atStartOfDay(), 2); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1999, 12, 30, 0, 0), res.datetimeValue()); + + res = subdate(LocalTime.now(), 2); + assertEquals(DATETIME, res.type()); + assertEquals(today().minusDays(2), res.dateValue()); + + res = subdate(Instant.ofEpochSecond(42), 2); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(1969, 12, 30, 0, 0, 42), res.datetimeValue()); + } + + @Test + public void subdate_accepts_negative_days() { + var res = subdate(LocalDateTime.of(2020, 10, 20, 8, 16, 32), -40); + assertEquals(DATETIME, res.type()); + assertEquals(LocalDateTime.of(2020, 10, 20, 8, 16, 32).plusDays(40), res.datetimeValue()); + assertEquals(adddate(LocalDateTime.of(2020, 10, 20, 8, 16, 32), 40), res); + } +} diff --git a/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeFunctionTest.java b/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeFunctionTest.java index ff9f154f75..a8e42d10b8 100644 --- a/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeFunctionTest.java +++ b/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeFunctionTest.java @@ -20,7 +20,6 @@ import static org.opensearch.sql.data.type.ExprCoreType.DATE; import static org.opensearch.sql.data.type.ExprCoreType.DATETIME; import static org.opensearch.sql.data.type.ExprCoreType.INTEGER; -import static org.opensearch.sql.data.type.ExprCoreType.INTERVAL; import static org.opensearch.sql.data.type.ExprCoreType.LONG; import static org.opensearch.sql.data.type.ExprCoreType.STRING; import static org.opensearch.sql.data.type.ExprCoreType.TIME; @@ -166,73 +165,6 @@ FunctionExpression getDateFormatExpression() { } } - @Test - public void adddate() { - FunctionExpression expr = DSL.adddate(DSL.date(DSL.literal("2020-08-26")), DSL.literal(7)); - assertEquals(DATE, expr.type()); - assertEquals(new ExprDateValue("2020-09-02"), expr.valueOf(env)); - assertEquals("adddate(date(\"2020-08-26\"), 7)", expr.toString()); - - expr = DSL.adddate(DSL.timestamp(DSL.literal("2020-08-26 12:05:00")), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-09-02 12:05:00"), expr.valueOf(env)); - assertEquals("adddate(timestamp(\"2020-08-26 12:05:00\"), 7)", expr.toString()); - - expr = DSL.adddate( - DSL.date(DSL.literal("2020-08-26")), DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 01:00:00"), expr.valueOf(env)); - assertEquals("adddate(date(\"2020-08-26\"), interval(1, \"hour\"))", expr.toString()); - - expr = DSL.adddate(DSL.literal("2020-08-26"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDateValue("2020-09-02"), expr.valueOf(env)); - assertEquals("adddate(\"2020-08-26\", 7)", expr.toString()); - - expr = DSL.adddate(DSL.literal("2020-08-26 12:05:00"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-09-02 12:05:00"), expr.valueOf(env)); - assertEquals("adddate(\"2020-08-26 12:05:00\", 7)", expr.toString()); - - expr = DSL - .adddate(DSL.literal("2020-08-26"), DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 01:00:00"), expr.valueOf(env)); - assertEquals("adddate(\"2020-08-26\", interval(1, \"hour\"))", expr.toString()); - - expr = DSL - .adddate(DSL.literal("2020-08-26"), DSL.interval(DSL.literal(1), DSL.literal("day"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDateValue("2020-08-27"), expr.valueOf(env)); - assertEquals("adddate(\"2020-08-26\", interval(1, \"day\"))", expr.toString()); - - when(nullRef.type()).thenReturn(DATE); - assertEquals(nullValue(), eval(DSL.adddate(nullRef, DSL.literal(1L)))); - assertEquals(nullValue(), - eval(DSL.adddate(nullRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(missingRef.type()).thenReturn(DATE); - assertEquals(missingValue(), eval(DSL.adddate(missingRef, DSL.literal(1L)))); - assertEquals(missingValue(), - eval(DSL.adddate(missingRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(nullRef.type()).thenReturn(LONG); - when(missingRef.type()).thenReturn(LONG); - assertEquals(nullValue(), eval(DSL.adddate(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.adddate(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(INTERVAL); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(nullValue(), eval(DSL.adddate(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.adddate(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(DATE); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(missingValue(), eval(DSL.adddate(nullRef, missingRef))); - } - @Test public void date() { when(nullRef.type()).thenReturn(DATE); @@ -263,125 +195,6 @@ public void date() { } - @Test - public void date_add() { - FunctionExpression expr = DSL.date_add(DSL.date(DSL.literal("2020-08-26")), DSL.literal(7)); - assertEquals(DATE, expr.type()); - assertEquals(new ExprDateValue("2020-09-02"), expr.valueOf(env)); - assertEquals("date_add(date(\"2020-08-26\"), 7)", expr.toString()); - - expr = DSL.date_add(DSL.literal("2020-08-26 12:05:00"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-09-02 12:05:00"), expr.valueOf(env)); - assertEquals("date_add(\"2020-08-26 12:05:00\", 7)", expr.toString()); - - expr = DSL.date_add(DSL.timestamp(DSL.literal("2020-08-26 12:05:00")), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-09-02 12:05:00"), expr.valueOf(env)); - assertEquals("date_add(timestamp(\"2020-08-26 12:05:00\"), 7)", expr.toString()); - - expr = DSL.date_add( - DSL.date(DSL.literal("2020-08-26")), DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 01:00:00"), expr.valueOf(env)); - assertEquals("date_add(date(\"2020-08-26\"), interval(1, \"hour\"))", expr.toString()); - - expr = DSL - .date_add(DSL.literal("2020-08-26"), DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 01:00:00"), expr.valueOf(env)); - assertEquals("date_add(\"2020-08-26\", interval(1, \"hour\"))", expr.toString()); - - when(nullRef.type()).thenReturn(DATE); - assertEquals(nullValue(), eval(DSL.date_add(nullRef, DSL.literal(1L)))); - assertEquals(nullValue(), - eval(DSL.date_add(nullRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(missingRef.type()).thenReturn(DATE); - assertEquals(missingValue(), eval(DSL.date_add(missingRef, DSL.literal(1L)))); - assertEquals(missingValue(), - eval(DSL.date_add(missingRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(nullRef.type()).thenReturn(LONG); - when(missingRef.type()).thenReturn(LONG); - assertEquals(nullValue(), eval(DSL.date_add(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.date_add(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(INTERVAL); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(nullValue(), eval(DSL.date_add(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.date_add(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(DATE); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(missingValue(), eval(DSL.date_add(nullRef, missingRef))); - } - - @Test - public void date_sub() { - FunctionExpression expr = DSL.date_sub(DSL.date(DSL.literal("2020-08-26")), DSL.literal(7)); - assertEquals(DATE, expr.type()); - assertEquals(new ExprDateValue("2020-08-19"), expr.valueOf(env)); - assertEquals("date_sub(date(\"2020-08-26\"), 7)", expr.toString()); - - expr = DSL.date_sub(DSL.literal("2020-08-26"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDateValue("2020-08-19"), expr.valueOf(env)); - assertEquals("date_sub(\"2020-08-26\", 7)", expr.toString()); - - expr = DSL.date_sub(DSL.timestamp(DSL.literal("2020-08-26 12:05:00")), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-19 12:05:00"), expr.valueOf(env)); - assertEquals("date_sub(timestamp(\"2020-08-26 12:05:00\"), 7)", expr.toString()); - - expr = DSL.date_sub(DSL.literal("2020-08-26 12:05:00"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-19 12:05:00"), expr.valueOf(env)); - assertEquals("date_sub(\"2020-08-26 12:05:00\", 7)", expr.toString()); - - expr = DSL.date_sub(DSL.timestamp(DSL.literal("2020-08-26 12:05:00")), - DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 11:05:00"), expr.valueOf(env)); - assertEquals("date_sub(timestamp(\"2020-08-26 12:05:00\"), interval(1, \"hour\"))", - expr.toString()); - - expr = DSL.date_sub(DSL.literal("2020-08-26 12:05:00"), - DSL.interval(DSL.literal(1), DSL.literal("year"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2019-08-26 12:05:00"), expr.valueOf(env)); - assertEquals("date_sub(\"2020-08-26 12:05:00\", interval(1, \"year\"))", - expr.toString()); - - when(nullRef.type()).thenReturn(DATE); - assertEquals(nullValue(), eval(DSL.date_sub(nullRef, DSL.literal(1L)))); - assertEquals(nullValue(), - eval(DSL.date_sub(nullRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(missingRef.type()).thenReturn(DATE); - assertEquals(missingValue(), eval(DSL.date_sub(missingRef, DSL.literal(1L)))); - assertEquals(missingValue(), - eval(DSL.date_sub(missingRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(nullRef.type()).thenReturn(LONG); - when(missingRef.type()).thenReturn(LONG); - assertEquals(nullValue(), eval(DSL.date_sub(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.date_sub(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(INTERVAL); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(nullValue(), eval(DSL.date_sub(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.date_sub(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(DATE); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(missingValue(), eval(DSL.date_sub(nullRef, missingRef))); - } - @Test public void day() { when(nullRef.type()).thenReturn(DATE); @@ -1464,76 +1277,6 @@ public void secondOfMinuteInvalidArguments() { } - @Test - public void subdate() { - FunctionExpression expr = DSL.subdate(DSL.date(DSL.literal("2020-08-26")), DSL.literal(7)); - assertEquals(DATE, expr.type()); - assertEquals(new ExprDateValue("2020-08-19"), expr.valueOf(env)); - assertEquals("subdate(date(\"2020-08-26\"), 7)", expr.toString()); - - expr = DSL.subdate(DSL.literal("2020-08-26"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDateValue("2020-08-19"), expr.valueOf(env)); - assertEquals("subdate(\"2020-08-26\", 7)", expr.toString()); - - expr = DSL.subdate(DSL.timestamp(DSL.literal("2020-08-26 12:05:00")), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-19 12:05:00"), expr.valueOf(env)); - assertEquals("subdate(timestamp(\"2020-08-26 12:05:00\"), 7)", expr.toString()); - - expr = DSL.subdate(DSL.literal("2020-08-26 12:05:00"), DSL.literal(7)); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-19 12:05:00"), expr.valueOf(env)); - assertEquals("subdate(\"2020-08-26 12:05:00\", 7)", expr.toString()); - - expr = DSL.subdate(DSL.timestamp(DSL.literal("2020-08-26 12:05:00")), - DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 11:05:00"), expr.valueOf(env)); - assertEquals("subdate(timestamp(\"2020-08-26 12:05:00\"), interval(1, \"hour\"))", - expr.toString()); - - expr = DSL.subdate(DSL.literal("2020-08-26 12:05:00"), - DSL.interval(DSL.literal(1), DSL.literal("hour"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDatetimeValue("2020-08-26 11:05:00"), expr.valueOf(env)); - assertEquals("subdate(\"2020-08-26 12:05:00\", interval(1, \"hour\"))", - expr.toString()); - - expr = DSL.subdate(DSL.literal("2020-08-26"), - DSL.interval(DSL.literal(1), DSL.literal("day"))); - assertEquals(DATETIME, expr.type()); - assertEquals(new ExprDateValue("2020-08-25"), expr.valueOf(env)); - assertEquals("subdate(\"2020-08-26\", interval(1, \"day\"))", - expr.toString()); - - when(nullRef.type()).thenReturn(DATE); - assertEquals(nullValue(), eval(DSL.subdate(nullRef, DSL.literal(1L)))); - assertEquals(nullValue(), - eval(DSL.subdate(nullRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(missingRef.type()).thenReturn(DATE); - assertEquals(missingValue(), eval(DSL.subdate(missingRef, DSL.literal(1L)))); - assertEquals(missingValue(), - eval(DSL.subdate(missingRef, DSL.interval(DSL.literal(1), DSL.literal("month"))))); - - when(nullRef.type()).thenReturn(LONG); - when(missingRef.type()).thenReturn(LONG); - assertEquals(nullValue(), eval(DSL.subdate(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.subdate(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(INTERVAL); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(nullValue(), eval(DSL.subdate(DSL.date(DSL.literal("2020-08-26")), nullRef))); - assertEquals(missingValue(), - eval(DSL.subdate(DSL.date(DSL.literal("2020-08-26")), missingRef))); - - when(nullRef.type()).thenReturn(DATE); - when(missingRef.type()).thenReturn(INTERVAL); - assertEquals(missingValue(), eval(DSL.subdate(nullRef, missingRef))); - } - @Test public void time_to_sec() { when(nullRef.type()).thenReturn(TIME); diff --git a/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeTestBase.java b/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeTestBase.java index d8829ea41a..7c041da243 100644 --- a/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeTestBase.java +++ b/core/src/test/java/org/opensearch/sql/expression/datetime/DateTimeTestBase.java @@ -41,6 +41,16 @@ protected ExprValue eval(Expression expression) { return expression.valueOf(); } + protected FunctionExpression adddate(Expression date, Expression interval) { + return (FunctionExpression) functionRepository.compile(functionProperties, + BuiltinFunctionName.ADDDATE.getName(), List.of(date, interval)); + } + + protected ExprValue adddate(Object first, Object interval) { + return adddate(DSL.literal(fromObjectValue(first)), DSL.literal(fromObjectValue(interval))) + .valueOf(null); + } + protected FunctionExpression addtime(Expression date, Expression interval) { return (FunctionExpression) functionRepository.compile( functionProperties, @@ -52,6 +62,26 @@ protected ExprValue addtime(Temporal first, Temporal second) { .valueOf(null); } + protected FunctionExpression date_add(Expression date, Expression interval) { + return (FunctionExpression) functionRepository.compile(functionProperties, + BuiltinFunctionName.DATE_ADD.getName(), List.of(date, interval)); + } + + protected ExprValue date_add(Object first, Object second) { + return date_add(DSL.literal(fromObjectValue(first)), DSL.literal(fromObjectValue(second))) + .valueOf(null); + } + + protected FunctionExpression date_sub(Expression date, Expression interval) { + return (FunctionExpression) functionRepository.compile(functionProperties, + BuiltinFunctionName.DATE_SUB.getName(), List.of(date, interval)); + } + + protected ExprValue date_sub(Object first, Object second) { + return date_sub(DSL.literal(fromObjectValue(first)), DSL.literal(fromObjectValue(second))) + .valueOf(null); + } + protected FunctionExpression datediff(Expression first, Expression second) { return (FunctionExpression) functionRepository.compile( functionProperties, @@ -138,6 +168,16 @@ protected Integer period_diff(Integer first, Integer second) { .valueOf().integerValue(); } + protected FunctionExpression subdate(Expression date, Expression interval) { + return (FunctionExpression) functionRepository.compile(functionProperties, + BuiltinFunctionName.SUBDATE.getName(), List.of(date, interval)); + } + + protected ExprValue subdate(Object first, Object interval) { + return subdate(DSL.literal(fromObjectValue(first)), DSL.literal(fromObjectValue(interval))) + .valueOf(null); + } + protected FunctionExpression subtime(Expression date, Expression interval) { return (FunctionExpression) functionRepository.compile( functionProperties, @@ -175,7 +215,6 @@ protected FunctionExpression unixTimeStampOf(Expression value) { BuiltinFunctionName.UNIX_TIMESTAMP.getName(), List.of(value)); } - protected Double unixTimeStampOf(Double value) { return unixTimeStampOf(DSL.literal(value)).valueOf().doubleValue(); } diff --git a/core/src/test/java/org/opensearch/sql/expression/datetime/IntervalClauseTest.java b/core/src/test/java/org/opensearch/sql/expression/datetime/IntervalClauseTest.java index 3e2d7f04cb..e63acc94c0 100644 --- a/core/src/test/java/org/opensearch/sql/expression/datetime/IntervalClauseTest.java +++ b/core/src/test/java/org/opensearch/sql/expression/datetime/IntervalClauseTest.java @@ -72,7 +72,7 @@ public void hour() { public void day() { FunctionExpression expr = DSL.interval(DSL.literal(1), DSL.literal("day")); assertEquals(INTERVAL, expr.type()); - assertEquals(intervalValue(Duration.ofDays(1)), expr.valueOf(env)); + assertEquals(intervalValue(Period.ofDays(1)), expr.valueOf(env)); } @Test diff --git a/docs/user/dql/functions.rst b/docs/user/dql/functions.rst index ab96075ac3..749017078b 100644 --- a/docs/user/dql/functions.rst +++ b/docs/user/dql/functions.rst @@ -908,28 +908,31 @@ Description >>>>>>>>>>> Usage: adddate(date, INTERVAL expr unit)/ adddate(date, expr) adds the time interval of second argument to date; adddate(date, days) adds the second argument as integer number of days to date. +If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL/LONG Return type map: -(DATE/DATETIME/TIMESTAMP/STRING, INTERVAL) -> DATETIME +(DATE/DATETIME/TIMESTAMP/TIME, INTERVAL) -> DATETIME (DATE, LONG) -> DATE -(DATETIME/TIMESTAMP/STRING, LONG) -> DATETIME +(DATETIME/TIMESTAMP/TIME, LONG) -> DATETIME -Synonyms: `DATE_ADD`_ +Synonyms: `DATE_ADD`_ when invoked with the INTERVAL form of the second argument. + +Antonyms: `SUBDATE`_ Example:: - os> SELECT ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR), ADDDATE(DATE('2020-08-26'), 1), ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) + os> SELECT ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR) AS `'2020-08-26' + 1h`, ADDDATE(DATE('2020-08-26'), 1) AS `'2020-08-26' + 1`, ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) AS `ts '2020-08-26 01:01:01' + 1` fetched rows / total rows = 1/1 - +------------------------------------------------+----------------------------------+------------------------------------------------+ - | ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR) | ADDDATE(DATE('2020-08-26'), 1) | ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |------------------------------------------------+----------------------------------+------------------------------------------------| - | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | - +------------------------------------------------+----------------------------------+------------------------------------------------+ + +---------------------+--------------------+--------------------------------+ + | '2020-08-26' + 1h | '2020-08-26' + 1 | ts '2020-08-26 01:01:01' + 1 | + |---------------------+--------------------+--------------------------------| + | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | + +---------------------+--------------------+--------------------------------+ ADDTIME @@ -1319,29 +1322,25 @@ DATE_ADD Description >>>>>>>>>>> -Usage: date_add(date, INTERVAL expr unit)/ date_add(date, expr) adds the time interval expr to date - -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG - -Return type map: - -DATE/DATETIME/TIMESTAMP/STRING, INTERVAL -> DATETIME +Usage: date_add(date, INTERVAL expr unit) adds the interval expr to date. If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -DATE, LONG -> DATE +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL -DATETIME/TIMESTAMP/STRING, LONG -> DATETIME +Return type: DATETIME Synonyms: `ADDDATE`_ +Antonyms: `DATE_SUB`_ + Example:: - os> SELECT DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR), DATE_ADD(DATE('2020-08-26'), 1), DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), 1) + os> SELECT DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR) AS `'2020-08-26' + 1h`, DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), INTERVAL 1 DAY) as `ts '2020-08-26 01:01:01' + 1d` fetched rows / total rows = 1/1 - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ - | DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR) | DATE_ADD(DATE('2020-08-26'), 1) | DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |-------------------------------------------------+-----------------------------------+-------------------------------------------------| - | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ + +---------------------+---------------------------------+ + | '2020-08-26' + 1h | ts '2020-08-26 01:01:01' + 1d | + |---------------------+---------------------------------| + | 2020-08-26 01:00:00 | 2020-08-27 01:01:01 | + +---------------------+---------------------------------+ DATE_FORMAT @@ -1448,29 +1447,25 @@ DATE_SUB Description >>>>>>>>>>> -Usage: date_sub(date, INTERVAL expr unit)/ date_sub(date, expr) subtracts the time interval expr from date +Usage: date_sub(date, INTERVAL expr unit) subtracts the interval expr from date. If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL -Return type map: - -DATE/DATETIME/TIMESTAMP/STRING, INTERVAL -> DATETIME - -DATE, LONG -> DATE - -DATETIME/TIMESTAMP/STRING, LONG -> DATETIME +Return type: DATETIME Synonyms: `SUBDATE`_ +Antonyms: `DATE_ADD`_ + Example:: - os> SELECT DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY), DATE_SUB(DATE('2020-08-26'), 1), DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), 1) + os> SELECT DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY) AS `'2008-01-02' - 31d`, DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), INTERVAL 1 HOUR) AS `ts '2020-08-26 01:01:01' + 1h` fetched rows / total rows = 1/1 - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ - | DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY) | DATE_SUB(DATE('2020-08-26'), 1) | DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |-------------------------------------------------+-----------------------------------+-------------------------------------------------| - | 2007-12-02 | 2020-08-25 | 2020-08-25 01:01:01 | - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ + +----------------------+---------------------------------+ + | '2008-01-02' - 31d | ts '2020-08-26 01:01:01' + 1h | + |----------------------+---------------------------------| + | 2007-12-02 00:00:00 | 2020-08-26 00:01:01 | + +----------------------+---------------------------------+ DATEDIFF @@ -2140,29 +2135,32 @@ SUBDATE Description >>>>>>>>>>> -Usage: subdate(date, INTERVAL expr unit)/ subdate(date, expr) subtracts the time interval expr from date +Usage: subdate(date, INTERVAL expr unit) / subdate(date, days) subtracts the time interval expr from date; subdate(date, days) subtracts the second argument as integer number of days from date. +If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL/LONG Return type map: -DATE/DATETIME/TIMESTAMP/STRING, INTERVAL -> DATETIME +(DATE/DATETIME/TIMESTAMP/TIME, INTERVAL) -> DATETIME + +(DATE, LONG) -> DATE -DATE, LONG -> DATE +(DATETIME/TIMESTAMP/TIME, LONG) -> DATETIME -DATETIME/TIMESTAMP/STRING, LONG -> DATETIME +Synonyms: `DATE_SUB`_ when invoked with the INTERVAL form of the second argument. -Synonyms: `DATE_SUB`_ +Antonyms: `ADDDATE`_ Example:: - os> SELECT SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY), SUBDATE(DATE('2020-08-26'), 1), SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) + os> SELECT SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY) AS `'2008-01-02' - 31d`, SUBDATE(DATE('2020-08-26'), 1) AS `'2020-08-26' - 1`, SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) AS `ts '2020-08-26 01:01:01' - 1` fetched rows / total rows = 1/1 - +------------------------------------------------+----------------------------------+------------------------------------------------+ - | SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY) | SUBDATE(DATE('2020-08-26'), 1) | SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |------------------------------------------------+----------------------------------+------------------------------------------------| - | 2007-12-02 | 2020-08-25 | 2020-08-25 01:01:01 | - +------------------------------------------------+----------------------------------+------------------------------------------------+ + +----------------------+--------------------+--------------------------------+ + | '2008-01-02' - 31d | '2020-08-26' - 1 | ts '2020-08-26 01:01:01' - 1 | + |----------------------+--------------------+--------------------------------| + | 2007-12-02 00:00:00 | 2020-08-25 | 2020-08-25 01:01:01 | + +----------------------+--------------------+--------------------------------+ SUBTIME diff --git a/docs/user/ppl/functions/datetime.rst b/docs/user/ppl/functions/datetime.rst index 5e54d8e80f..d747d96386 100644 --- a/docs/user/ppl/functions/datetime.rst +++ b/docs/user/ppl/functions/datetime.rst @@ -14,29 +14,33 @@ ADDDATE Description >>>>>>>>>>> -Usage: adddate(date, INTERVAL expr unit)/ adddate(date, expr) adds the time interval of second argument to date; adddate(date, days) adds the second argument as integer number of days to date. +Usage: adddate(date, INTERVAL expr unit) / adddate(date, days) adds the interval of second argument to date; adddate(date, days) adds the second argument as integer number of days to date. +If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL/LONG Return type map: -(DATE/DATETIME/TIMESTAMP/STRING, INTERVAL) -> DATETIME +(DATE/DATETIME/TIMESTAMP/TIME, INTERVAL) -> DATETIME (DATE, LONG) -> DATE -(DATETIME/TIMESTAMP/STRING, LONG) -> DATETIME +(DATETIME/TIMESTAMP/TIME, LONG) -> DATETIME -Synonyms: `DATE_ADD`_ +Synonyms: `DATE_ADD`_ when invoked with the INTERVAL form of the second argument. + +Antonyms: `SUBDATE`_ Example:: - os> source=people | eval `ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR)` = ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR), `ADDDATE(DATE('2020-08-26'), 1)` = ADDDATE(DATE('2020-08-26'), 1), `ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1)` = ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | fields `ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR)`, `ADDDATE(DATE('2020-08-26'), 1)`, `ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1)` + os> source=people | eval `'2020-08-26' + 1h` = ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR), `'2020-08-26' + 1` = ADDDATE(DATE('2020-08-26'), 1), `ts '2020-08-26 01:01:01' + 1` = ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | fields `'2020-08-26' + 1h`, `'2020-08-26' + 1`, `ts '2020-08-26 01:01:01' + 1` fetched rows / total rows = 1/1 - +------------------------------------------------+----------------------------------+------------------------------------------------+ - | ADDDATE(DATE('2020-08-26'), INTERVAL 1 HOUR) | ADDDATE(DATE('2020-08-26'), 1) | ADDDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |------------------------------------------------+----------------------------------+------------------------------------------------| - | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | - +------------------------------------------------+----------------------------------+------------------------------------------------+ + +---------------------+--------------------+--------------------------------+ + | '2020-08-26' + 1h | '2020-08-26' + 1 | ts '2020-08-26 01:01:01' + 1 | + |---------------------+--------------------+--------------------------------| + | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | + +---------------------+--------------------+--------------------------------+ + ADDTIME @@ -393,29 +397,25 @@ DATE_ADD Description >>>>>>>>>>> -Usage: date_add(date, INTERVAL expr unit)/ date_add(date, expr) adds the time interval expr to date - -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG - -Return type map: - -DATE/DATETIME/TIMESTAMP/STRING, INTERVAL -> DATETIME +Usage: date_add(date, INTERVAL expr unit) adds the interval expr to date. If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -DATE, LONG -> DATE +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL -DATETIME/TIMESTAMP/STRING, LONG -> DATETIME +Return type: DATETIME Synonyms: `ADDDATE`_ +Antonyms: `DATE_SUB`_ + Example:: - os> source=people | eval `DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR)` = DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR), `DATE_ADD(DATE('2020-08-26'), 1)` = DATE_ADD(DATE('2020-08-26'), 1), `DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), 1)` = DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), 1) | fields `DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR)`, `DATE_ADD(DATE('2020-08-26'), 1)`, `DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), 1)` + os> source=people | eval `'2020-08-26' + 1h` = DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR), `ts '2020-08-26 01:01:01' + 1d` = DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), INTERVAL 1 DAY) | fields `'2020-08-26' + 1h`, `ts '2020-08-26 01:01:01' + 1d` fetched rows / total rows = 1/1 - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ - | DATE_ADD(DATE('2020-08-26'), INTERVAL 1 HOUR) | DATE_ADD(DATE('2020-08-26'), 1) | DATE_ADD(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |-------------------------------------------------+-----------------------------------+-------------------------------------------------| - | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ + +---------------------+---------------------------------+ + | '2020-08-26' + 1h | ts '2020-08-26 01:01:01' + 1d | + |---------------------+---------------------------------| + | 2020-08-26 01:00:00 | 2020-08-27 01:01:01 | + +---------------------+---------------------------------+ DATE_FORMAT @@ -574,29 +574,25 @@ DATE_SUB Description >>>>>>>>>>> -Usage: date_sub(date, INTERVAL expr unit)/ date_sub(date, expr) subtracts the time interval expr from date +Usage: date_sub(date, INTERVAL expr unit) subtracts the interval expr from date. If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL -Return type map: - -DATE/DATETIME/TIMESTAMP/STRING, INTERVAL -> DATETIME - -DATE, LONG -> DATE - -DATETIME/TIMESTAMP/STRING, LONG -> DATETIME +Return type: DATETIME Synonyms: `SUBDATE`_ +Antonyms: `DATE_ADD`_ + Example:: - os> source=people | eval `DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY)` = DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY), `DATE_SUB(DATE('2020-08-26'), 1)` = DATE_SUB(DATE('2020-08-26'), 1), `DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), 1)` = DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), 1) | fields `DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY)`, `DATE_SUB(DATE('2020-08-26'), 1)`, `DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), 1)` + os> source=people | eval `'2008-01-02' - 31d` = DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY), `ts '2020-08-26 01:01:01' + 1h` = DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), INTERVAL 1 HOUR) | fields `'2008-01-02' - 31d`, `ts '2020-08-26 01:01:01' + 1h` fetched rows / total rows = 1/1 - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ - | DATE_SUB(DATE('2008-01-02'), INTERVAL 31 DAY) | DATE_SUB(DATE('2020-08-26'), 1) | DATE_SUB(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |-------------------------------------------------+-----------------------------------+-------------------------------------------------| - | 2007-12-02 | 2020-08-25 | 2020-08-25 01:01:01 | - +-------------------------------------------------+-----------------------------------+-------------------------------------------------+ + +----------------------+---------------------------------+ + | '2008-01-02' - 31d | ts '2020-08-26 01:01:01' + 1h | + |----------------------+---------------------------------| + | 2007-12-02 00:00:00 | 2020-08-26 00:01:01 | + +----------------------+---------------------------------+ DATEDIFF @@ -631,7 +627,7 @@ Argument type: STRING/DATE/DATETIME/TIMESTAMP Return type: INTEGER -Synonyms: DAYOFMONTH +Synonyms: `DAYOFMONTH`_ Example:: @@ -1139,29 +1135,32 @@ SUBDATE Description >>>>>>>>>>> -Usage: subdate(date, INTERVAL expr unit)/ subdate(date, expr) subtracts the time interval expr from date +Usage: subdate(date, INTERVAL expr unit) / subdate(date, days) subtracts the interval expr from date; subdate(date, days) subtracts the second argument as integer number of days from date. +If first argument is TIME, today's date is used; if first argument is DATE, time at midnight is used. -Argument type: DATE/DATETIME/TIMESTAMP/STRING, INTERVAL/LONG +Argument type: DATE/DATETIME/TIMESTAMP/TIME, INTERVAL/LONG Return type map: -DATE/DATETIME/TIMESTAMP/STRING, INTERVAL -> DATETIME +(DATE/DATETIME/TIMESTAMP/TIME, INTERVAL) -> DATETIME + +(DATE, LONG) -> DATE -DATE, LONG -> DATE +(DATETIME/TIMESTAMP/TIME, LONG) -> DATETIME -DATETIME/TIMESTAMP/STRING, LONG -> DATETIME +Synonyms: `DATE_SUB`_ when invoked with the INTERVAL form of the second argument. -Synonyms: `DATE_SUB`_ +Antonyms: `ADDDATE`_ Example:: - os> source=people | eval `SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY)` = SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY), `SUBDATE(DATE('2020-08-26'), 1)` = SUBDATE(DATE('2020-08-26'), 1), `SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1)` = SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | fields `SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY)`, `SUBDATE(DATE('2020-08-26'), 1)`, `SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1)` + os> source=people | eval `'2008-01-02' - 31d` = SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY), `'2020-08-26' - 1` = SUBDATE(DATE('2020-08-26'), 1), `ts '2020-08-26 01:01:01' - 1` = SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | fields `'2008-01-02' - 31d`, `'2020-08-26' - 1`, `ts '2020-08-26 01:01:01' - 1` fetched rows / total rows = 1/1 - +------------------------------------------------+----------------------------------+------------------------------------------------+ - | SUBDATE(DATE('2008-01-02'), INTERVAL 31 DAY) | SUBDATE(DATE('2020-08-26'), 1) | SUBDATE(TIMESTAMP('2020-08-26 01:01:01'), 1) | - |------------------------------------------------+----------------------------------+------------------------------------------------| - | 2007-12-02 | 2020-08-25 | 2020-08-25 01:01:01 | - +------------------------------------------------+----------------------------------+------------------------------------------------+ + +----------------------+--------------------+--------------------------------+ + | '2008-01-02' - 31d | '2020-08-26' - 1 | ts '2020-08-26 01:01:01' - 1 | + |----------------------+--------------------+--------------------------------| + | 2007-12-02 00:00:00 | 2020-08-25 | 2020-08-25 01:01:01 | + +----------------------+--------------------+--------------------------------+ SUBTIME diff --git a/integ-test/src/test/java/org/opensearch/sql/ppl/DateTimeFunctionIT.java b/integ-test/src/test/java/org/opensearch/sql/ppl/DateTimeFunctionIT.java index 23f2df69c8..0ebfd73265 100644 --- a/integ-test/src/test/java/org/opensearch/sql/ppl/DateTimeFunctionIT.java +++ b/integ-test/src/test/java/org/opensearch/sql/ppl/DateTimeFunctionIT.java @@ -8,11 +8,13 @@ import static org.junit.jupiter.api.Assertions.assertEquals; import static org.junit.jupiter.api.Assertions.assertTrue; +import static org.opensearch.sql.legacy.TestsConstants.TEST_INDEX_BANK; import static org.opensearch.sql.legacy.TestsConstants.TEST_INDEX_DATE; import static org.opensearch.sql.legacy.TestsConstants.TEST_INDEX_PEOPLE2; import static org.opensearch.sql.sql.DateTimeFunctionIT.utcDateTimeNow; import static org.opensearch.sql.util.MatcherUtils.rows; import static org.opensearch.sql.util.MatcherUtils.schema; +import static org.opensearch.sql.util.MatcherUtils.verifyDataRows; import static org.opensearch.sql.util.MatcherUtils.verifySchema; import static org.opensearch.sql.util.MatcherUtils.verifySome; @@ -23,6 +25,7 @@ import java.time.Duration; import java.time.LocalDateTime; import java.time.Period; +import java.time.ZoneId; import java.time.format.DateTimeFormatter; import java.time.format.DateTimeFormatterBuilder; import java.time.temporal.ChronoField; @@ -35,6 +38,8 @@ import java.util.stream.Collectors; import org.json.JSONArray; import org.json.JSONObject; +import org.junit.After; +import org.junit.Before; import org.junit.jupiter.api.Test; import org.opensearch.sql.common.utils.StringUtils; @@ -45,33 +50,93 @@ public class DateTimeFunctionIT extends PPLIntegTestCase { public void init() throws IOException { loadIndex(Index.DATE); loadIndex(Index.PEOPLE2); + loadIndex(Index.BANK); } - @Test - public void testAddDate() throws IOException { - JSONObject result = - executeQuery(String.format( - "source=%s | eval f = adddate(timestamp('2020-09-16 17:30:00'), interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); + // Integration test framework sets for OpenSearch instance a random timezone. + // If server's TZ doesn't match localhost's TZ, time measurements for some tests would differ. + // We should set localhost's TZ now and recover the value back in the end of the test. + private final TimeZone testTz = TimeZone.getDefault(); + private final TimeZone systemTz = TimeZone.getTimeZone(System.getProperty("user.timezone")); - result = executeQuery(String.format( - "source=%s | eval f = adddate(date('2020-09-16'), 1) | fields f", TEST_INDEX_DATE)); + @Before + public void setTimeZone() { + TimeZone.setDefault(systemTz); + } + + @After + public void resetTimeZone() { + TimeZone.setDefault(testTz); + } + + @Test + public void testAddDateWithDays() throws IOException { + var result = executeQuery(String.format("source=%s | eval " + + " f = adddate(date('2020-09-16'), 1)" + + " | fields f", TEST_INDEX_DATE)); verifySchema(result, schema("f", null, "date")); verifySome(result.getJSONArray("datarows"), rows("2020-09-17")); - result = executeQuery(String.format( - "source=%s | eval f = adddate('2020-09-16', 1) | fields f", TEST_INDEX_DATE)); + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(timestamp('2020-09-16 17:30:00'), 1)" + + " | fields f", TEST_INDEX_DATE)); verifySchema(result, schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-17")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); - result = - executeQuery(String.format( - "source=%s | eval f = adddate('2020-09-16 17:30:00', interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(DATETIME('2020-09-16 07:40:00'), 1)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-17 07:40:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(TIME('07:40:00'), 0)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows(LocalDate.now() + " 07:40:00")); + } + + @Test + public void testAddDateWithInterval() throws IOException { + JSONObject result = executeQuery(String.format("source=%s | eval " + + " f = adddate(timestamp('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(DATETIME('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(date('2020-09-16'), interval 1 day) " + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-17 00:00:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(date('2020-09-16'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-16 01:00:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(TIME('07:40:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().plusDays(1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery(String.format("source=%s | eval " + + " f = adddate(TIME('07:40:00'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().atTime(LocalTime.of(8, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); } @Test @@ -151,29 +216,58 @@ public void testConvertTZ() throws IOException { @Test public void testDateAdd() throws IOException { - JSONObject result = - executeQuery(String.format( - "source=%s | eval f = date_add(timestamp('2020-09-16 17:30:00'), interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); + JSONObject result = executeQuery(String.format("source=%s | eval " + + " f = date_add(timestamp('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); - result = executeQuery(String.format( - "source=%s | eval f = date_add(date('2020-09-16'), 1) | fields f", TEST_INDEX_DATE)); - verifySchema(result, schema("f", null, "date")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-17")); + result = executeQuery(String.format("source=%s | eval " + + " f = date_add(DATETIME('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); - result = executeQuery(String.format( - "source=%s | eval f = date_add('2020-09-16', 1) | fields f", TEST_INDEX_DATE)); + result = executeQuery(String.format("source=%s | eval " + + " f = date_add(date('2020-09-16'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); verifySchema(result, schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-17")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-17 00:00:00")); - result = - executeQuery(String.format( - "source=%s | eval f = date_add('2020-09-16 17:30:00', interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-17 17:30:00")); + result = executeQuery(String.format("source=%s | eval " + + " f = date_add(date('2020-09-16'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-16 01:00:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = date_add(TIME('07:40:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().plusDays(1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery(String.format("source=%s | eval " + + " f = date_add(TIME('07:40:00'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().atTime(LocalTime.of(8, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery(String.format("source=%s | eval " + + " f = DATE_ADD(birthdate, INTERVAL 1 YEAR)" + + " | fields f", TEST_INDEX_BANK)); + verifySchema(result, schema("f", null, "datetime")); + verifyDataRows(result, + rows("2018-10-23 00:00:00"), + rows("2018-11-20 00:00:00"), + rows("2019-06-23 00:00:00"), + rows("2019-11-13 23:33:20"), + rows("2019-06-27 00:00:00"), + rows("2019-08-19 00:00:00"), + rows("2019-08-11 00:00:00")); } @Test @@ -277,29 +371,45 @@ public void testDateTime() throws IOException { @Test public void testDateSub() throws IOException { - JSONObject result = - executeQuery(String.format( - "source=%s | eval f = date_sub(timestamp('2020-09-16 17:30:00'), interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); + JSONObject result = executeQuery(String.format("source=%s | eval " + + " f = date_sub(timestamp('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); verifySome(result.getJSONArray("datarows"), rows("2020-09-15 17:30:00")); - result = executeQuery(String.format( - "source=%s | eval f = date_sub(date('2020-09-16'), 1) | fields f", TEST_INDEX_DATE)); - verifySchema(result, schema("f", null, "date")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-15")); + result = executeQuery(String.format("source=%s | eval " + + " f = date_sub(DATETIME('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15 17:30:00")); - result = executeQuery(String.format( - "source=%s | eval f = date_sub('2020-09-16', 1) | fields f", TEST_INDEX_DATE)); + result = executeQuery(String.format("source=%s | eval " + + " f = date_sub(date('2020-09-16'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); verifySchema(result, schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-15")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15 00:00:00")); - result = - executeQuery(String.format( - "source=%s | eval f = date_sub('2020-09-16 17:30:00', interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-15 17:30:00")); + result = executeQuery(String.format("source=%s | eval " + + " f = date_sub(date('2020-09-16'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15 23:00:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = date_sub(TIME('07:40:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().plusDays(-1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery(String.format("source=%s | eval " + + " f = date_sub(TIME('07:40:00'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().atTime(LocalTime.of(6, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); } @Test @@ -531,30 +641,73 @@ public void testSecond() throws IOException { } @Test - public void testSubDate() throws IOException { - JSONObject result = - executeQuery(String.format( - "source=%s | eval f = subdate(timestamp('2020-09-16 17:30:00'), interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); + public void testSubDateDays() throws IOException { + var result = executeQuery(String.format("source=%s | eval " + + " f = subdate(date('2020-09-16'), 1)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "date")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15")); + + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(timestamp('2020-09-16 17:30:00'), 1)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); verifySome(result.getJSONArray("datarows"), rows("2020-09-15 17:30:00")); - result = executeQuery(String.format( - "source=%s | eval f = subdate(date('2020-09-16'), 1) | fields f", TEST_INDEX_DATE)); + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(date('2020-09-16'), 1)" + + " | fields f", TEST_INDEX_DATE)); verifySchema(result, schema("f", null, "date")); verifySome(result.getJSONArray("datarows"), rows("2020-09-15")); - result = - executeQuery(String.format( - "source=%s | eval f = subdate('2020-09-16 17:30:00', interval 1 day) | fields f", TEST_INDEX_DATE)); - verifySchema(result, - schema("f", null, "datetime")); + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(TIME('07:40:00'), 0)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows(LocalDate.now() + " 07:40:00")); + } + + @Test + public void testSubDateInterval() throws IOException { + JSONObject result = executeQuery(String.format("source=%s | eval " + + " f = subdate(timestamp('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); verifySome(result.getJSONArray("datarows"), rows("2020-09-15 17:30:00")); - result = executeQuery(String.format( - "source=%s | eval f = subdate('2020-09-16', 1) | fields f", TEST_INDEX_DATE)); + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(DATETIME('2020-09-16 17:30:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); verifySchema(result, schema("f", null, "datetime")); - verifySome(result.getJSONArray("datarows"), rows("2020-09-15")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15 17:30:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(date('2020-09-16'), interval 1 day) " + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15 00:00:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(date('2020-09-16'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2020-09-15 23:00:00")); + + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(TIME('07:40:00'), interval 1 day)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().plusDays(-1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery(String.format("source=%s | eval " + + " f = subdate(TIME('07:40:00'), interval 1 hour)" + + " | fields f", TEST_INDEX_DATE)); + verifySchema(result, schema("f", null, "datetime")); + verifySome(result.getJSONArray("datarows"), + rows(LocalDate.now().atTime(LocalTime.of(6, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); } @Test @@ -797,12 +950,6 @@ private long getDiff(Temporal sample, Temporal reference) { @Test public void testNowLikeFunctions() throws IOException { - // Integration test framework sets for OpenSearch instance a random timezone. - // If server's TZ doesn't match localhost's TZ, time measurements for `now` would differ. - // We should set localhost's TZ now and recover the value back in the end of the test. - var testTz = TimeZone.getDefault(); - TimeZone.setDefault(TimeZone.getTimeZone(System.getProperty("user.timezone"))); - for (var funcData : nowLikeFunctionsData()) { String name = (String) funcData.get("name"); Boolean hasFsp = (Boolean) funcData.get("hasFsp"); @@ -862,7 +1009,6 @@ public void testNowLikeFunctions() throws IOException { } } } - TimeZone.setDefault(testTz); } @Test diff --git a/integ-test/src/test/java/org/opensearch/sql/sql/DateTimeFunctionIT.java b/integ-test/src/test/java/org/opensearch/sql/sql/DateTimeFunctionIT.java index af8748deab..938f7f664a 100644 --- a/integ-test/src/test/java/org/opensearch/sql/sql/DateTimeFunctionIT.java +++ b/integ-test/src/test/java/org/opensearch/sql/sql/DateTimeFunctionIT.java @@ -38,6 +38,8 @@ import java.util.function.Supplier; import org.json.JSONArray; import org.json.JSONObject; +import org.junit.After; +import org.junit.Before; import org.junit.jupiter.api.Test; import org.opensearch.client.Request; import org.opensearch.client.RequestOptions; @@ -56,6 +58,22 @@ public void init() throws Exception { loadIndex(Index.CALCS); } + // Integration test framework sets for OpenSearch instance a random timezone. + // If server's TZ doesn't match localhost's TZ, time measurements for some tests would differ. + // We should set localhost's TZ now and recover the value back in the end of the test. + private final TimeZone testTz = TimeZone.getDefault(); + private final TimeZone systemTz = TimeZone.getTimeZone(System.getProperty("user.timezone")); + + @Before + public void setTimeZone() { + TimeZone.setDefault(systemTz); + } + + @After + public void resetTimeZone() { + TimeZone.setDefault(testTz); + } + @Test public void testDateInGroupBy() throws IOException{ JSONObject result = @@ -82,30 +100,60 @@ public void testDateWithHavingClauseOnly() throws IOException { } @Test - public void testAddDate() throws IOException { + public void testAddDateWithDays() throws IOException { + var result = executeQuery("select adddate(date('2020-09-16'), 1)"); + verifySchema(result, schema("adddate(date('2020-09-16'), 1)", null, "date")); + verifyDataRows(result, rows("2020-09-17")); + + result = executeQuery("select adddate(timestamp('2020-09-16 17:30:00'), 1)"); + verifySchema(result, schema("adddate(timestamp('2020-09-16 17:30:00'), 1)", null, "datetime")); + verifyDataRows(result, rows("2020-09-17 17:30:00")); + + result = executeQuery("select adddate(DATETIME('2020-09-16 07:40:00'), 1)"); + verifySchema(result, schema("adddate(DATETIME('2020-09-16 07:40:00'), 1)", null, "datetime")); + verifyDataRows(result, rows("2020-09-17 07:40:00")); + + result = executeQuery("select adddate(TIME('07:40:00'), 0)"); + verifySchema(result, schema("adddate(TIME('07:40:00'), 0)", null, "datetime")); + verifyDataRows(result, rows(LocalDate.now() + " 07:40:00")); + } + + @Test + public void testAddDateWithInterval() throws IOException { JSONObject result = executeQuery("select adddate(timestamp('2020-09-16 17:30:00'), interval 1 day)"); verifySchema(result, schema("adddate(timestamp('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); verifyDataRows(result, rows("2020-09-17 17:30:00")); - result = executeQuery("select adddate(date('2020-09-16'), 1)"); - verifySchema(result, schema("adddate(date('2020-09-16'), 1)", null, "date")); - verifyDataRows(result, rows("2020-09-17")); + result = executeQuery("select adddate(DATETIME('2020-09-16 17:30:00'), interval 1 day)"); + verifySchema(result, + schema("adddate(DATETIME('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-17 17:30:00")); - result = executeQuery("select adddate('2020-09-16', 1)"); - verifySchema(result, schema("adddate('2020-09-16', 1)", null, "datetime")); - verifyDataRows(result, rows("2020-09-17")); + result = executeQuery("select adddate(date('2020-09-16'), interval 1 day)"); + verifySchema(result, + schema("adddate(date('2020-09-16'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-17 00:00:00")); - result = executeQuery("select adddate('2020-09-16 17:30:00', interval 1 day)"); + result = executeQuery("select adddate(date('2020-09-16'), interval 1 hour)"); verifySchema(result, - schema("adddate('2020-09-16 17:30:00', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-17 17:30:00")); + schema("adddate(date('2020-09-16'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, rows("2020-09-16 01:00:00")); - result = executeQuery("select adddate('2020-09-16', interval 1 day)"); + result = executeQuery("select adddate(TIME('07:40:00'), interval 1 day)"); verifySchema(result, - schema("adddate('2020-09-16', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-17")); + schema("adddate(TIME('07:40:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().plusDays(1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery("select adddate(TIME('07:40:00'), interval 1 hour)"); + verifySchema(result, + schema("adddate(TIME('07:40:00'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().atTime(LocalTime.of(8, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); } @Test @@ -116,26 +164,38 @@ public void testDateAdd() throws IOException { schema("date_add(timestamp('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); verifyDataRows(result, rows("2020-09-17 17:30:00")); - result = executeQuery("select date_add(date('2020-09-16'), 1)"); - verifySchema(result, schema("date_add(date('2020-09-16'), 1)", null, "date")); - verifyDataRows(result, rows("2020-09-17")); + result = executeQuery("select date_add(DATETIME('2020-09-16 17:30:00'), interval 1 day)"); + verifySchema(result, + schema("date_add(DATETIME('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-17 17:30:00")); - result = executeQuery("select date_add('2020-09-16', 1)"); - verifySchema(result, schema("date_add('2020-09-16', 1)", null, "datetime")); - verifyDataRows(result, rows("2020-09-17")); + result = executeQuery("select date_add(date('2020-09-16'), interval 1 day)"); + verifySchema(result, + schema("date_add(date('2020-09-16'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-17 00:00:00")); - result = executeQuery("select date_add('2020-09-16 17:30:00', interval 1 day)"); + result = executeQuery("select date_add(date('2020-09-16'), interval 1 hour)"); verifySchema(result, - schema("date_add('2020-09-16 17:30:00', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-17 17:30:00")); + schema("date_add(date('2020-09-16'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, rows("2020-09-16 01:00:00")); - result = executeQuery("select date_add('2020-09-16', interval 1 day)"); + result = executeQuery("select date_add(TIME('07:40:00'), interval 1 day)"); verifySchema(result, - schema("date_add('2020-09-16', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-17")); + schema("date_add(TIME('07:40:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().plusDays(1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery("select date_add(TIME('07:40:00'), interval 1 hour)"); + verifySchema(result, + schema("date_add(TIME('07:40:00'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().atTime(LocalTime.of(8, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery(String.format("SELECT DATE_ADD(birthdate, INTERVAL 1 YEAR) FROM %s", + TEST_INDEX_BANK)); - result = - executeQuery(String.format("SELECT DATE_ADD(birthdate, INTERVAL 1 YEAR) FROM %s GROUP BY 1",TEST_INDEX_BANK) ); verifySchema(result, schema("DATE_ADD(birthdate, INTERVAL 1 YEAR)", null, "datetime")); verifyDataRows(result, @@ -156,23 +216,34 @@ public void testDateSub() throws IOException { schema("date_sub(timestamp('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); verifyDataRows(result, rows("2020-09-15 17:30:00")); - result = executeQuery("select date_sub(date('2020-09-16'), 1)"); - verifySchema(result, schema("date_sub(date('2020-09-16'), 1)", null, "date")); - verifyDataRows(result, rows("2020-09-15")); + result = executeQuery("select date_sub(DATETIME('2020-09-16 17:30:00'), interval 1 day)"); + verifySchema(result, + schema("date_sub(DATETIME('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 17:30:00")); - result = executeQuery("select date_sub('2020-09-16', 1)"); - verifySchema(result, schema("date_sub('2020-09-16', 1)", null, "datetime")); - verifyDataRows(result, rows("2020-09-15")); + result = executeQuery("select date_sub(date('2020-09-16'), interval 1 day)"); + verifySchema(result, + schema("date_sub(date('2020-09-16'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 00:00:00")); - result = executeQuery("select date_sub('2020-09-16 17:30:00', interval 1 day)"); + result = executeQuery("select date_sub(date('2020-09-16'), interval 1 hour)"); verifySchema(result, - schema("date_sub('2020-09-16 17:30:00', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-15 17:30:00")); + schema("date_sub(date('2020-09-16'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 23:00:00")); - result = executeQuery("select date_sub('2020-09-16', interval 1 day)"); + result = executeQuery("select date_sub(TIME('07:40:00'), interval 1 day)"); verifySchema(result, - schema("date_sub('2020-09-16', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-15")); + schema("date_sub(TIME('07:40:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().plusDays(-1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery("select date_sub(TIME('07:40:00'), interval 1 hour)"); + verifySchema(result, + schema("date_sub(TIME('07:40:00'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().atTime(LocalTime.of(6, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); } @Test @@ -675,7 +746,6 @@ public void testSecond() throws IOException { verifyDataRows(result, rows(0)); } - @Test public void testSecondOfMinute() throws IOException { JSONObject result = executeQuery("select second_of_minute(timestamp('2020-09-16 17:30:00'))"); verifySchema(result, schema("second_of_minute(timestamp('2020-09-16 17:30:00'))", null, "integer")); @@ -721,30 +791,64 @@ public void testSecondFunctionAliasesReturnTheSameResults() throws IOException { } @Test - public void testSubDate() throws IOException { + public void testSubDateWithDays() throws IOException { + var result = + executeQuery("select subdate(date('2020-09-16'), 1)"); + verifySchema(result, + schema("subdate(date('2020-09-16'), 1)", null, "date")); + verifyDataRows(result, rows("2020-09-15")); + + result = + executeQuery("select subdate(timestamp('2020-09-16 17:30:00'), 1)"); + verifySchema(result, + schema("subdate(timestamp('2020-09-16 17:30:00'), 1)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 17:30:00")); + + result = executeQuery("select subdate(DATETIME('2020-09-16 07:40:00'), 1)"); + verifySchema(result, schema("subdate(DATETIME('2020-09-16 07:40:00'), 1)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 07:40:00")); + + result = executeQuery("select subdate(TIME('07:40:00'), 0)"); + verifySchema(result, schema("subdate(TIME('07:40:00'), 0)", null, "datetime")); + verifyDataRows(result, rows(LocalDate.now() + " 07:40:00")); + } + + @Test + public void testSubDateWithInterval() throws IOException { JSONObject result = executeQuery("select subdate(timestamp('2020-09-16 17:30:00'), interval 1 day)"); verifySchema(result, schema("subdate(timestamp('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); verifyDataRows(result, rows("2020-09-15 17:30:00")); - result = executeQuery("select subdate(date('2020-09-16'), 1)"); - verifySchema(result, schema("subdate(date('2020-09-16'), 1)", null, "date")); - verifyDataRows(result, rows("2020-09-15")); - - result = executeQuery("select subdate('2020-09-16 17:30:00', interval 1 day)"); + result = executeQuery("select subdate(DATETIME('2020-09-16 17:30:00'), interval 1 day)"); verifySchema(result, - schema("subdate('2020-09-16 17:30:00', interval 1 day)", null, "datetime")); + schema("subdate(DATETIME('2020-09-16 17:30:00'), interval 1 day)", null, "datetime")); verifyDataRows(result, rows("2020-09-15 17:30:00")); - result = executeQuery("select subdate('2020-09-16', 1)"); - verifySchema(result, schema("subdate('2020-09-16', 1)", null, "datetime")); - verifyDataRows(result, rows("2020-09-15")); + result = executeQuery("select subdate(date('2020-09-16'), interval 1 day)"); + verifySchema(result, + schema("subdate(date('2020-09-16'), interval 1 day)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 00:00:00")); - result = executeQuery("select subdate('2020-09-16', interval 1 day)"); + result = executeQuery("select subdate(date('2020-09-16'), interval 1 hour)"); verifySchema(result, - schema("subdate('2020-09-16', interval 1 day)", null, "datetime")); - verifyDataRows(result, rows("2020-09-15")); + schema("subdate(date('2020-09-16'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, rows("2020-09-15 23:00:00")); + + result = executeQuery("select subdate(TIME('07:40:00'), interval 1 day)"); + verifySchema(result, + schema("subdate(TIME('07:40:00'), interval 1 day)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().plusDays(-1).atTime(LocalTime.of(7, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); + + result = executeQuery("select subdate(TIME('07:40:00'), interval 1 hour)"); + verifySchema(result, + schema("subdate(TIME('07:40:00'), interval 1 hour)", null, "datetime")); + verifyDataRows(result, + rows(LocalDate.now().atTime(LocalTime.of(6, 40)).atZone(systemTz.toZoneId()) + .format(DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss")))); } @Test @@ -1021,12 +1125,6 @@ private long getDiff(Temporal sample, Temporal reference) { @Test public void testNowLikeFunctions() throws IOException { - // Integration test framework sets for OpenSearch instance a random timezone. - // If server's TZ doesn't match localhost's TZ, time measurements for `now` would differ. - // We should set localhost's TZ now and recover the value back in the end of the test. - var testTz = TimeZone.getDefault(); - TimeZone.setDefault(TimeZone.getTimeZone(System.getProperty("user.timezone"))); - for (var funcData : nowLikeFunctionsData()) { String name = (String) funcData.get("name"); Boolean hasFsp = (Boolean) funcData.get("hasFsp"); @@ -1082,7 +1180,6 @@ public void testNowLikeFunctions() throws IOException { } } } - TimeZone.setDefault(testTz); } @Test