From 571dcd1a230e3484aafdd9d2073f1ceecc287078 Mon Sep 17 00:00:00 2001 From: "opensearch-trigger-bot[bot]" <98922864+opensearch-trigger-bot[bot]@users.noreply.github.com> Date: Mon, 9 Jan 2023 11:15:10 -0800 Subject: [PATCH] Add functions `ADDTIME` and `SUBTIME`. (#132) (#1194) (#1252) * Add functions `ADDTIME` and `SUBTIME`. (#132) Signed-off-by: Yury-Fridlyand (cherry picked from commit 7630f87335d62f7fd5ec3eb5c49697c97f94296d) Co-authored-by: Yury-Fridlyand --- .../expression/datetime/DateTimeFunction.java | 140 ++++++++++++++++++ .../function/BuiltinFunctionName.java | 2 + .../opensearch/sql/utils/DateTimeUtils.java | 11 ++ .../datetime/AddTimeAndSubTimeTest.java | 127 ++++++++++++++++ .../expression/datetime/DateTimeTestBase.java | 34 +++-- docs/user/dql/functions.rst | 122 +++++++++++++++ docs/user/ppl/functions/datetime.rst | 125 +++++++++++++++- .../sql/ppl/DateTimeFunctionIT.java | 36 +++++ .../sql/sql/DateTimeFunctionIT.java | 33 +++++ ppl/src/main/antlr/OpenSearchPPLLexer.g4 | 2 + ppl/src/main/antlr/OpenSearchPPLParser.g4 | 2 + sql/src/main/antlr/OpenSearchSQLLexer.g4 | 2 + sql/src/main/antlr/OpenSearchSQLParser.g4 | 2 + 13 files changed, 626 insertions(+), 12 deletions(-) create mode 100644 core/src/test/java/org/opensearch/sql/expression/datetime/AddTimeAndSubTimeTest.java 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 a29429fc04..ade6170102 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 @@ -30,6 +30,7 @@ import static org.opensearch.sql.utils.DateTimeFormatters.DATE_TIME_FORMATTER_SHORT_YEAR; import static org.opensearch.sql.utils.DateTimeFormatters.DATE_TIME_FORMATTER_STRICT_WITH_TZ; import static org.opensearch.sql.utils.DateTimeUtils.extractDate; +import static org.opensearch.sql.utils.DateTimeUtils.extractDateTime; import java.math.BigDecimal; import java.math.RoundingMode; @@ -95,6 +96,7 @@ public class DateTimeFunction { */ public void register(BuiltinFunctionRepository repository) { repository.register(adddate()); + repository.register(addtime()); repository.register(convert_tz()); repository.register(curtime()); repository.register(curdate()); @@ -132,6 +134,7 @@ public void register(BuiltinFunctionRepository repository) { repository.register(second(BuiltinFunctionName.SECOND)); repository.register(second(BuiltinFunctionName.SECOND_OF_MINUTE)); repository.register(subdate()); + repository.register(subtime()); repository.register(sysdate()); repository.register(time()); repository.register(time_to_sec()); @@ -247,6 +250,52 @@ private DefaultFunctionResolver adddate() { return add_date(BuiltinFunctionName.ADDDATE.getName()); } + /** + * Adds expr2 to expr1 and returns the result. + * (TIME, TIME/DATE/DATETIME/TIMESTAMP) -> TIME + * (DATE/DATETIME/TIMESTAMP, TIME/DATE/DATETIME/TIMESTAMP) -> DATETIME + * TODO: MySQL has these signatures too + * (STRING, STRING/TIME) -> STRING // second arg - string with time only + * (x, STRING) -> NULL // second arg - string with timestamp + * (x, STRING/DATE) -> x // second arg - string with date only + */ + private DefaultFunctionResolver addtime() { + return define(BuiltinFunctionName.ADDTIME.getName(), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + TIME, TIME, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + TIME, TIME, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + TIME, TIME, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + TIME, TIME, TIMESTAMP), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATETIME, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATETIME, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATETIME, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATETIME, TIMESTAMP), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATE, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATE, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATE, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, DATE, TIMESTAMP), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, TIMESTAMP, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, TIMESTAMP, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, TIMESTAMP, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprAddTime), + DATETIME, TIMESTAMP, TIMESTAMP) + ); + } + /** * Converts date/time from a specified timezone to another specified timezone. * The supported signatures: @@ -573,6 +622,52 @@ private DefaultFunctionResolver subdate() { return sub_date(BuiltinFunctionName.SUBDATE.getName()); } + /** + * Subtracts expr2 from expr1 and returns the result. + * (TIME, TIME/DATE/DATETIME/TIMESTAMP) -> TIME + * (DATE/DATETIME/TIMESTAMP, TIME/DATE/DATETIME/TIMESTAMP) -> DATETIME + * TODO: MySQL has these signatures too + * (STRING, STRING/TIME) -> STRING // second arg - string with time only + * (x, STRING) -> NULL // second arg - string with timestamp + * (x, STRING/DATE) -> x // second arg - string with date only + */ + private DefaultFunctionResolver subtime() { + return define(BuiltinFunctionName.SUBTIME.getName(), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + TIME, TIME, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + TIME, TIME, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + TIME, TIME, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + TIME, TIME, TIMESTAMP), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATETIME, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATETIME, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATETIME, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATETIME, TIMESTAMP), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATE, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATE, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATE, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, DATE, TIMESTAMP), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, TIMESTAMP, TIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, TIMESTAMP, DATE), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, TIMESTAMP, DATETIME), + implWithProperties(nullMissingHandlingWithProperties(DateTimeFunction::exprSubTime), + DATETIME, TIMESTAMP, TIMESTAMP) + ); + } + /** * Extracts the time part of a date and time value. * Also to construct a time type. The supported signatures: @@ -752,6 +847,39 @@ private ExprValue exprAddDateDays(ExprValue date, ExprValue days) { : exprValue); } + /** + * Adds or subtracts time to/from date and returns the result. + * + * @param functionProperties A FunctionProperties object. + * @param temporal A Date/Time/Datetime/Timestamp value to change. + * @param temporalDelta A Date/Time/Datetime/Timestamp object to add/subtract time from. + * @param isAdd A flag: true to add, false to subtract. + * @return A value calculated. + */ + private ExprValue exprApplyTime(FunctionProperties functionProperties, + ExprValue temporal, ExprValue temporalDelta, Boolean isAdd) { + var interval = Duration.between(LocalTime.MIN, temporalDelta.timeValue()); + var result = isAdd + ? extractDateTime(temporal, functionProperties).plus(interval) + : extractDateTime(temporal, functionProperties).minus(interval); + return temporal.type() == TIME + ? new ExprTimeValue(result.toLocalTime()) + : new ExprDatetimeValue(result); + } + + /** + * Adds time to date and returns the result. + * + * @param functionProperties A FunctionProperties object. + * @param temporal A Date/Time/Datetime/Timestamp value to change. + * @param temporalDelta A Date/Time/Datetime/Timestamp object to add time from. + * @return A value calculated. + */ + private ExprValue exprAddTime(FunctionProperties functionProperties, + ExprValue temporal, ExprValue temporalDelta) { + return exprApplyTime(functionProperties, temporal, temporalDelta, true); + } + /** * CONVERT_TZ function implementation for ExprValue. * Returns null for time zones outside of +13:00 and -12:00. @@ -1164,6 +1292,18 @@ private ExprValue exprSubDateInterval(ExprValue date, ExprValue expr) { : exprValue); } + /** + * Subtracts expr2 from expr1 and returns the result. + * + * @param temporal A Date/Time/Datetime/Timestamp value to change. + * @param temporalDelta A Date/Time/Datetime/Timestamp to subtract time from. + * @return A value calculated. + */ + private ExprValue exprSubTime(FunctionProperties functionProperties, + ExprValue temporal, ExprValue temporalDelta) { + return exprApplyTime(functionProperties, temporal, temporalDelta, false); + } + /** * Time implementation for ExprValue. * diff --git a/core/src/main/java/org/opensearch/sql/expression/function/BuiltinFunctionName.java b/core/src/main/java/org/opensearch/sql/expression/function/BuiltinFunctionName.java index 06b46b6888..cdc0b4e30d 100644 --- a/core/src/main/java/org/opensearch/sql/expression/function/BuiltinFunctionName.java +++ b/core/src/main/java/org/opensearch/sql/expression/function/BuiltinFunctionName.java @@ -59,6 +59,7 @@ public enum BuiltinFunctionName { * Date and Time Functions. */ ADDDATE(FunctionName.of("adddate")), + ADDTIME(FunctionName.of("addtime")), CONVERT_TZ(FunctionName.of("convert_tz")), DATE(FunctionName.of("date")), DATEDIFF(FunctionName.of("datediff")), @@ -88,6 +89,7 @@ public enum BuiltinFunctionName { SECOND(FunctionName.of("second")), SECOND_OF_MINUTE(FunctionName.of("second_of_minute")), SUBDATE(FunctionName.of("subdate")), + SUBTIME(FunctionName.of("subtime")), TIME(FunctionName.of("time")), TIMEDIFF(FunctionName.of("timediff")), TIME_TO_SEC(FunctionName.of("time_to_sec")), diff --git a/core/src/main/java/org/opensearch/sql/utils/DateTimeUtils.java b/core/src/main/java/org/opensearch/sql/utils/DateTimeUtils.java index 28bb4e6918..06d40ea6aa 100644 --- a/core/src/main/java/org/opensearch/sql/utils/DateTimeUtils.java +++ b/core/src/main/java/org/opensearch/sql/utils/DateTimeUtils.java @@ -130,6 +130,17 @@ public Boolean isValidMySqlTimeZoneId(ZoneId zone) { || passedTzValidator.isEqual(minTzValidator)); } + /** + * Extracts LocalDateTime from a datetime ExprValue. + * Uses `FunctionProperties` for `ExprTimeValue`. + */ + public static LocalDateTime extractDateTime(ExprValue value, + FunctionProperties functionProperties) { + return value instanceof ExprTimeValue + ? ((ExprTimeValue) value).datetimeValue(functionProperties) + : value.datetimeValue(); + } + /** * Extracts LocalDate from a datetime ExprValue. * Uses `FunctionProperties` for `ExprTimeValue`. diff --git a/core/src/test/java/org/opensearch/sql/expression/datetime/AddTimeAndSubTimeTest.java b/core/src/test/java/org/opensearch/sql/expression/datetime/AddTimeAndSubTimeTest.java new file mode 100644 index 0000000000..e917e2ee62 --- /dev/null +++ b/core/src/test/java/org/opensearch/sql/expression/datetime/AddTimeAndSubTimeTest.java @@ -0,0 +1,127 @@ +/* + * 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.opensearch.sql.data.type.ExprCoreType.DATETIME; +import static org.opensearch.sql.data.type.ExprCoreType.TIME; + +import java.time.Instant; +import java.time.LocalDate; +import java.time.LocalDateTime; +import java.time.LocalTime; +import java.time.temporal.Temporal; +import java.util.stream.Stream; +import org.junit.jupiter.api.Test; +import org.junit.jupiter.params.ParameterizedTest; +import org.junit.jupiter.params.provider.Arguments; +import org.junit.jupiter.params.provider.MethodSource; + +public class AddTimeAndSubTimeTest extends DateTimeTestBase { + + @Test + // (TIME, TIME/DATE/DATETIME/TIMESTAMP) -> TIME + public void return_time_when_first_arg_is_time() { + var res = addtime(LocalTime.of(21, 0), LocalTime.of(0, 5)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(21, 5), res.timeValue()); + + res = subtime(LocalTime.of(21, 0), LocalTime.of(0, 5)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(20, 55), res.timeValue()); + + res = addtime(LocalTime.of(12, 20), Instant.ofEpochSecond(42)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(12, 20, 42), res.timeValue()); + + res = subtime(LocalTime.of(10, 0), Instant.ofEpochSecond(42)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(9, 59, 18), res.timeValue()); + + res = addtime(LocalTime.of(2, 3, 4), LocalDateTime.of(1961, 4, 12, 9, 7)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(11, 10, 4), res.timeValue()); + + res = subtime(LocalTime.of(12, 3, 4), LocalDateTime.of(1961, 4, 12, 9, 7)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(2, 56, 4), res.timeValue()); + + res = addtime(LocalTime.of(9, 7), LocalDate.now()); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(9, 7), res.timeValue()); + + res = subtime(LocalTime.of(9, 7), LocalDate.of(1961, 4, 12)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(9, 7), res.timeValue()); + } + + @Test + public void time_limited_by_24_hours() { + var res = addtime(LocalTime.of(21, 0), LocalTime.of(14, 5)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(11, 5), res.timeValue()); + + res = subtime(LocalTime.of(14, 0), LocalTime.of(21, 5)); + assertEquals(TIME, res.type()); + assertEquals(LocalTime.of(16, 55), res.timeValue()); + } + + // Function signature is: + // (DATE/DATETIME/TIMESTAMP, TIME/DATE/DATETIME/TIMESTAMP) -> DATETIME + private static Stream getTestData() { + return Stream.of( + // DATETIME and TIME/DATE/DATETIME/TIMESTAMP + Arguments.of(LocalDateTime.of(1961, 4, 12, 9, 7), LocalTime.of(1, 48), + LocalDateTime.of(1961, 4, 12, 10, 55), LocalDateTime.of(1961, 4, 12, 7, 19)), + Arguments.of(LocalDateTime.of(1961, 4, 12, 9, 7), LocalDate.of(2000, 1, 1), + LocalDateTime.of(1961, 4, 12, 9, 7), LocalDateTime.of(1961, 4, 12, 9, 7)), + Arguments.of(LocalDateTime.of(1961, 4, 12, 9, 7), LocalDateTime.of(1235, 5, 6, 1, 48), + LocalDateTime.of(1961, 4, 12, 10, 55), LocalDateTime.of(1961, 4, 12, 7, 19)), + Arguments.of(LocalDateTime.of(1961, 4, 12, 9, 7), Instant.ofEpochSecond(42), + LocalDateTime.of(1961, 4, 12, 9, 7, 42), LocalDateTime.of(1961, 4, 12, 9, 6, 18)), + // DATE and TIME/DATE/DATETIME/TIMESTAMP + Arguments.of(LocalDate.of(1961, 4, 12), LocalTime.of(9, 7), + LocalDateTime.of(1961, 4, 12, 9, 7), LocalDateTime.of(1961, 4, 11, 14, 53)), + Arguments.of(LocalDate.of(1961, 4, 12), LocalDate.of(2000, 1, 1), + LocalDateTime.of(1961, 4, 12, 0, 0), LocalDateTime.of(1961, 4, 12, 0, 0)), + Arguments.of(LocalDate.of(1961, 4, 12), LocalDateTime.of(1235, 5, 6, 1, 48), + LocalDateTime.of(1961, 4, 12, 1, 48), LocalDateTime.of(1961, 4, 11, 22, 12)), + Arguments.of(LocalDate.of(1961, 4, 12), Instant.ofEpochSecond(42), + LocalDateTime.of(1961, 4, 12, 0, 0, 42), LocalDateTime.of(1961, 4, 11, 23, 59, 18)), + // TIMESTAMP and TIME/DATE/DATETIME/TIMESTAMP + Arguments.of(Instant.ofEpochSecond(42), LocalTime.of(9, 7), + LocalDateTime.of(1970, 1, 1, 9, 7, 42), LocalDateTime.of(1969, 12, 31, 14, 53, 42)), + Arguments.of(Instant.ofEpochSecond(42), LocalDate.of(1961, 4, 12), + LocalDateTime.of(1970, 1, 1, 0, 0, 42), LocalDateTime.of(1970, 1, 1, 0, 0, 42)), + Arguments.of(Instant.ofEpochSecond(42), LocalDateTime.of(1961, 4, 12, 9, 7), + LocalDateTime.of(1970, 1, 1, 9, 7, 42), LocalDateTime.of(1969, 12, 31, 14, 53, 42)), + Arguments.of(Instant.ofEpochSecond(42), Instant.ofEpochMilli(42), + LocalDateTime.of(1970, 1, 1, 0, 0, 42, 42000000), + LocalDateTime.of(1970, 1, 1, 0, 0, 41, 958000000)) + ); + } + + /** + * Check that `ADDTIME` and `SUBTIME` functions result value and type. + * @param arg1 First argument. + * @param arg2 Second argument. + * @param addTimeExpectedResult Expected result for `ADDTIME`. + * @param subTimeExpectedResult Expected result for `SUBTIME`. + */ + @ParameterizedTest + @MethodSource("getTestData") + public void return_datetime_when_first_arg_is_not_time(Temporal arg1, Temporal arg2, + LocalDateTime addTimeExpectedResult, + LocalDateTime subTimeExpectedResult) { + var res = addtime(arg1, arg2); + assertEquals(DATETIME, res.type()); + assertEquals(addTimeExpectedResult, res.datetimeValue()); + + res = subtime(arg1, arg2); + assertEquals(DATETIME, res.type()); + assertEquals(subTimeExpectedResult, res.datetimeValue()); + } +} 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 7517b27944..d8829ea41a 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 @@ -14,10 +14,6 @@ import java.time.LocalTime; import java.time.temporal.Temporal; import java.util.List; -import org.junit.jupiter.api.BeforeAll; -import org.junit.jupiter.api.extension.ExtendWith; -import org.mockito.Mock; -import org.mockito.junit.jupiter.MockitoExtension; import org.opensearch.sql.data.model.ExprDateValue; import org.opensearch.sql.data.model.ExprDatetimeValue; import org.opensearch.sql.data.model.ExprMissingValue; @@ -29,26 +25,31 @@ import org.opensearch.sql.expression.Expression; import org.opensearch.sql.expression.ExpressionTestBase; import org.opensearch.sql.expression.FunctionExpression; -import org.opensearch.sql.expression.env.Environment; import org.opensearch.sql.expression.function.BuiltinFunctionName; import org.opensearch.sql.expression.function.BuiltinFunctionRepository; -import org.opensearch.sql.expression.function.FunctionProperties; -@ExtendWith(MockitoExtension.class) public class DateTimeTestBase extends ExpressionTestBase { protected final BuiltinFunctionRepository functionRepository = BuiltinFunctionRepository.getInstance(); - @Mock - protected Environment env; - protected Expression nullRef = DSL.literal(ExprNullValue.of()); protected Expression missingRef = DSL.literal(ExprMissingValue.of()); protected ExprValue eval(Expression expression) { - return expression.valueOf(env); + return expression.valueOf(); + } + + protected FunctionExpression addtime(Expression date, Expression interval) { + return (FunctionExpression) functionRepository.compile( + functionProperties, + BuiltinFunctionName.ADDTIME.getName(), List.of(date, interval)); + } + + protected ExprValue addtime(Temporal first, Temporal second) { + return addtime(DSL.literal(fromObjectValue(first)), DSL.literal(fromObjectValue(second))) + .valueOf(null); } protected FunctionExpression datediff(Expression first, Expression second) { @@ -137,6 +138,17 @@ protected Integer period_diff(Integer first, Integer second) { .valueOf().integerValue(); } + protected FunctionExpression subtime(Expression date, Expression interval) { + return (FunctionExpression) functionRepository.compile( + functionProperties, + BuiltinFunctionName.SUBTIME.getName(), List.of(date, interval)); + } + + protected ExprValue subtime(Temporal first, Temporal second) { + return subtime(DSL.literal(fromObjectValue(first)), DSL.literal(fromObjectValue(second))) + .valueOf(null); + } + protected FunctionExpression timediff(Expression first, Expression second) { return (FunctionExpression) functionRepository.compile( functionProperties, diff --git a/docs/user/dql/functions.rst b/docs/user/dql/functions.rst index f95947a7b5..86d18f1c2f 100644 --- a/docs/user/dql/functions.rst +++ b/docs/user/dql/functions.rst @@ -873,6 +873,67 @@ Example:: +------------------------------------------------+----------------------------------+------------------------------------------------+ +ADDTIME +------- + +Description +>>>>>>>>>>> + +Usage: addtime(expr1, expr2) adds expr2 to expr1 and returns the result. If argument is TIME, today's date is used; if argument is DATE, time at midnight is used. + +Argument type: DATE/DATETIME/TIMESTAMP/TIME, DATE/DATETIME/TIMESTAMP/TIME + +Return type map: + +(DATE/DATETIME/TIMESTAMP, DATE/DATETIME/TIMESTAMP/TIME) -> DATETIME + +(TIME, DATE/DATETIME/TIMESTAMP/TIME) -> TIME + +Antonyms: `SUBTIME`_ + +Example:: + + os> SELECT ADDTIME(DATE('2008-12-12'), DATE('2008-11-15')) AS `'2008-12-12' + 0 ` + fetched rows / total rows = 1/1 + +---------------------+ + | '2008-12-12' + 0 | + |---------------------| + | 2008-12-12 00:00:00 | + +---------------------+ + + os> SELECT ADDTIME(TIME('23:59:59'), DATE('2004-01-01')) AS `'23:59:59' + 0` + fetched rows / total rows = 1/1 + +------------------+ + | '23:59:59' + 0 | + |------------------| + | 23:59:59 | + +------------------+ + + os> SELECT ADDTIME(DATE('2004-01-01'), TIME('23:59:59')) AS `'2004-01-01' + '23:59:59'` + fetched rows / total rows = 1/1 + +-----------------------------+ + | '2004-01-01' + '23:59:59' | + |-----------------------------| + | 2004-01-01 23:59:59 | + +-----------------------------+ + + os> SELECT ADDTIME(TIME('10:20:30'), TIME('00:05:42')) AS `'10:20:30' + '00:05:42'` + fetched rows / total rows = 1/1 + +---------------------------+ + | '10:20:30' + '00:05:42' | + |---------------------------| + | 10:26:12 | + +---------------------------+ + + os> SELECT ADDTIME(TIMESTAMP('2007-02-28 10:20:30'), DATETIME('2002-03-04 20:40:50')) AS `'2007-02-28 10:20:30' + '20:40:50'` + fetched rows / total rows = 1/1 + +--------------------------------------+ + | '2007-02-28 10:20:30' + '20:40:50' | + |--------------------------------------| + | 2007-03-01 07:01:20 | + +--------------------------------------+ + + CONVERT_TZ ---------- @@ -2017,6 +2078,67 @@ Example:: +------------------------------------------------+----------------------------------+------------------------------------------------+ +SUBTIME +------- + +Description +>>>>>>>>>>> + +Usage: subtime(expr1, expr2) subtracts expr2 from expr1 and returns the result. If argument is TIME, today's date is used; if argument is DATE, time at midnight is used. + +Argument type: DATE/DATETIME/TIMESTAMP/TIME, DATE/DATETIME/TIMESTAMP/TIME + +Return type map: + +(DATE/DATETIME/TIMESTAMP, DATE/DATETIME/TIMESTAMP/TIME) -> DATETIME + +(TIME, DATE/DATETIME/TIMESTAMP/TIME) -> TIME + +Antonyms: `ADDTIME`_ + +Example:: + + os> SELECT SUBTIME(DATE('2008-12-12'), DATE('2008-11-15')) AS `'2008-12-12' - 0` + fetched rows / total rows = 1/1 + +---------------------+ + | '2008-12-12' - 0 | + |---------------------| + | 2008-12-12 00:00:00 | + +---------------------+ + + os> SELECT SUBTIME(TIME('23:59:59'), DATE('2004-01-01')) AS `'23:59:59' - 0` + fetched rows / total rows = 1/1 + +------------------+ + | '23:59:59' - 0 | + |------------------| + | 23:59:59 | + +------------------+ + + os> SELECT SUBTIME(DATE('2004-01-01'), TIME('23:59:59')) AS `'2004-01-01' - '23:59:59'` + fetched rows / total rows = 1/1 + +-----------------------------+ + | '2004-01-01' - '23:59:59' | + |-----------------------------| + | 2003-12-31 00:00:01 | + +-----------------------------+ + + os> SELECT SUBTIME(TIME('10:20:30'), TIME('00:05:42')) AS `'10:20:30' - '00:05:42'` + fetched rows / total rows = 1/1 + +---------------------------+ + | '10:20:30' - '00:05:42' | + |---------------------------| + | 10:14:48 | + +---------------------------+ + + os> SELECT SUBTIME(TIMESTAMP('2007-03-01 10:20:30'), DATETIME('2002-03-04 20:40:50')) AS `'2007-03-01 10:20:30' - '20:40:50'` + fetched rows / total rows = 1/1 + +--------------------------------------+ + | '2007-03-01 10:20:30' - '20:40:50' | + |--------------------------------------| + | 2007-02-28 13:39:40 | + +--------------------------------------+ + + SYSDATE ------- diff --git a/docs/user/ppl/functions/datetime.rst b/docs/user/ppl/functions/datetime.rst index 60a8660c7a..5e54d8e80f 100644 --- a/docs/user/ppl/functions/datetime.rst +++ b/docs/user/ppl/functions/datetime.rst @@ -38,8 +38,70 @@ Example:: | 2020-08-26 01:00:00 | 2020-08-27 | 2020-08-27 01:01:01 | +------------------------------------------------+----------------------------------+------------------------------------------------+ + +ADDTIME +------- + +Description +>>>>>>>>>>> + +Usage: addtime(expr1, expr2) adds expr2 to expr1 and returns the result. If argument is TIME, today's date is used; if argument is DATE, time at midnight is used. + +Argument type: DATE/DATETIME/TIMESTAMP/TIME, DATE/DATETIME/TIMESTAMP/TIME + +Return type map: + +(DATE/DATETIME/TIMESTAMP, DATE/DATETIME/TIMESTAMP/TIME) -> DATETIME + +(TIME, DATE/DATETIME/TIMESTAMP/TIME) -> TIME + +Antonyms: `SUBTIME`_ + +Example:: + + os> source=people | eval `'2008-12-12' + 0` = ADDTIME(DATE('2008-12-12'), DATE('2008-11-15')) | fields `'2008-12-12' + 0` + fetched rows / total rows = 1/1 + +---------------------+ + | '2008-12-12' + 0 | + |---------------------| + | 2008-12-12 00:00:00 | + +---------------------+ + + os> source=people | eval `'23:59:59' + 0` = ADDTIME(TIME('23:59:59'), DATE('2004-01-01')) | fields `'23:59:59' + 0` + fetched rows / total rows = 1/1 + +------------------+ + | '23:59:59' + 0 | + |------------------| + | 23:59:59 | + +------------------+ + + os> source=people | eval `'2004-01-01' + '23:59:59'` = ADDTIME(DATE('2004-01-01'), TIME('23:59:59')) | fields `'2004-01-01' + '23:59:59'` + fetched rows / total rows = 1/1 + +-----------------------------+ + | '2004-01-01' + '23:59:59' | + |-----------------------------| + | 2004-01-01 23:59:59 | + +-----------------------------+ + + os> source=people | eval `'10:20:30' + '00:05:42'` = ADDTIME(TIME('10:20:30'), TIME('00:05:42')) | fields `'10:20:30' + '00:05:42'` + fetched rows / total rows = 1/1 + +---------------------------+ + | '10:20:30' + '00:05:42' | + |---------------------------| + | 10:26:12 | + +---------------------------+ + + os> source=people | eval `'2007-02-28 10:20:30' + '20:40:50'` = ADDTIME(TIMESTAMP('2007-02-28 10:20:30'), DATETIME('2002-03-04 20:40:50')) | fields `'2007-02-28 10:20:30' + '20:40:50'` + fetched rows / total rows = 1/1 + +--------------------------------------+ + | '2007-02-28 10:20:30' + '20:40:50' | + |--------------------------------------| + | 2007-03-01 07:01:20 | + +--------------------------------------+ + + CONVERT_TZ ----- +---------- Description >>>>>>>>>>> @@ -1102,6 +1164,67 @@ Example:: +------------------------------------------------+----------------------------------+------------------------------------------------+ +SUBTIME +------- + +Description +>>>>>>>>>>> + +Usage: subtime(expr1, expr2) subtracts expr2 from expr1 and returns the result. If argument is TIME, today's date is used; if argument is DATE, time at midnight is used. + +Argument type: DATE/DATETIME/TIMESTAMP/TIME, DATE/DATETIME/TIMESTAMP/TIME + +Return type map: + +(DATE/DATETIME/TIMESTAMP, DATE/DATETIME/TIMESTAMP/TIME) -> DATETIME + +(TIME, DATE/DATETIME/TIMESTAMP/TIME) -> TIME + +Antonyms: `ADDTIME`_ + +Example:: + + os> source=people | eval `'2008-12-12' - 0` = SUBTIME(DATE('2008-12-12'), DATE('2008-11-15')) | fields `'2008-12-12' - 0` + fetched rows / total rows = 1/1 + +---------------------+ + | '2008-12-12' - 0 | + |---------------------| + | 2008-12-12 00:00:00 | + +---------------------+ + + os> source=people | eval `'23:59:59' - 0` = SUBTIME(TIME('23:59:59'), DATE('2004-01-01')) | fields `'23:59:59' - 0` + fetched rows / total rows = 1/1 + +------------------+ + | '23:59:59' - 0 | + |------------------| + | 23:59:59 | + +------------------+ + + os> source=people | eval `'2004-01-01' - '23:59:59'` = SUBTIME(DATE('2004-01-01'), TIME('23:59:59')) | fields `'2004-01-01' - '23:59:59'` + fetched rows / total rows = 1/1 + +-----------------------------+ + | '2004-01-01' - '23:59:59' | + |-----------------------------| + | 2003-12-31 00:00:01 | + +-----------------------------+ + + os> source=people | eval `'10:20:30' - '00:05:42'` = SUBTIME(TIME('10:20:30'), TIME('00:05:42')) | fields `'10:20:30' - '00:05:42'` + fetched rows / total rows = 1/1 + +---------------------------+ + | '10:20:30' - '00:05:42' | + |---------------------------| + | 10:14:48 | + +---------------------------+ + + os> source=people | eval `'2007-03-01 10:20:30' - '20:40:50'` = SUBTIME(TIMESTAMP('2007-03-01 10:20:30'), DATETIME('2002-03-04 20:40:50')) | fields `'2007-03-01 10:20:30' - '20:40:50'` + fetched rows / total rows = 1/1 + +--------------------------------------+ + | '2007-03-01 10:20:30' - '20:40:50' | + |--------------------------------------| + | 2007-02-28 13:39:40 | + +--------------------------------------+ + + SYSDATE ------- 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 9f59caefc6..23f2df69c8 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 @@ -865,6 +865,42 @@ public void testNowLikeFunctions() throws IOException { TimeZone.setDefault(testTz); } + @Test + public void testAddTime() throws IOException { + var result = executeQuery(String.format("source=%s | eval" + + " `'2008-12-12' + 0` = ADDTIME(DATE('2008-12-12'), DATE('2008-11-15'))," + + " `'23:59:59' + 0` = ADDTIME(TIME('23:59:59'), DATE('2004-01-01'))," + + " `'2004-01-01' + '23:59:59'` = ADDTIME(DATE('2004-01-01'), TIME('23:59:59'))," + + " `'10:20:30' + '00:05:42'` = ADDTIME(TIME('10:20:30'), TIME('00:05:42'))," + + " `'15:42:13' + '09:07:00'` = ADDTIME(TIMESTAMP('1999-12-31 15:42:13'), DATETIME('1961-04-12 09:07:00'))" + + " | fields `'2008-12-12' + 0`, `'23:59:59' + 0`, `'2004-01-01' + '23:59:59'`, `'10:20:30' + '00:05:42'`, `'15:42:13' + '09:07:00'`", TEST_INDEX_DATE)); + verifySchema(result, + schema("'2008-12-12' + 0", null, "datetime"), + schema("'23:59:59' + 0", null, "time"), + schema("'2004-01-01' + '23:59:59'", null, "datetime"), + schema("'10:20:30' + '00:05:42'", null, "time"), + schema("'15:42:13' + '09:07:00'", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2008-12-12 00:00:00", "23:59:59", "2004-01-01 23:59:59", "10:26:12", "2000-01-01 00:49:13")); + } + + @Test + public void testSubTime() throws IOException { + var result = executeQuery(String.format("source=%s | eval" + + " `'2008-12-12' - 0` = SUBTIME(DATE('2008-12-12'), DATE('2008-11-15'))," + + " `'23:59:59' - 0` = SUBTIME(TIME('23:59:59'), DATE('2004-01-01'))," + + " `'2004-01-01' - '23:59:59'` = SUBTIME(DATE('2004-01-01'), TIME('23:59:59'))," + + " `'10:20:30' - '00:05:42'` = SUBTIME(TIME('10:20:30'), TIME('00:05:42'))," + + " `'15:42:13' - '09:07:00'` = SUBTIME(TIMESTAMP('1999-12-31 15:42:13'), DATETIME('1961-04-12 09:07:00'))" + + " | fields `'2008-12-12' - 0`, `'23:59:59' - 0`, `'2004-01-01' - '23:59:59'`, `'10:20:30' - '00:05:42'`, `'15:42:13' - '09:07:00'`", TEST_INDEX_DATE)); + verifySchema(result, + schema("'2008-12-12' - 0", null, "datetime"), + schema("'23:59:59' - 0", null, "time"), + schema("'2004-01-01' - '23:59:59'", null, "datetime"), + schema("'10:20:30' - '00:05:42'", null, "time"), + schema("'15:42:13' - '09:07:00'", null, "datetime")); + verifySome(result.getJSONArray("datarows"), rows("2008-12-12 00:00:00", "23:59:59", "2003-12-31 00:00:01", "10:14:48", "1999-12-31 06:35:13")); + } + @Test public void testFromUnixTime() throws IOException { var result = executeQuery(String.format( 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 62bb033af3..389c976f5c 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 @@ -949,6 +949,39 @@ public void testPeriodDiff() throws IOException { verifyDataRows(result, rows(11, -25)); } + public void testAddTime() throws IOException { + var result = executeQuery("SELECT" + + " ADDTIME(DATE('2008-12-12'), DATE('2008-11-15')) AS `'2008-12-12' + 0`," + + " ADDTIME(TIME('23:59:59'), DATE('2004-01-01')) AS `'23:59:59' + 0`," + + " ADDTIME(DATE('2004-01-01'), TIME('23:59:59')) AS `'2004-01-01' + '23:59:59'`," + + " ADDTIME(TIME('10:20:30'), TIME('00:05:42')) AS `'10:20:30' + '00:05:42'`," + + " ADDTIME(TIMESTAMP('1999-12-31 15:42:13'), DATETIME('1961-04-12 09:07:00')) AS `'15:42:13' + '09:07:00'`"); + verifySchema(result, + schema("ADDTIME(DATE('2008-12-12'), DATE('2008-11-15'))", "'2008-12-12' + 0", "datetime"), + schema("ADDTIME(TIME('23:59:59'), DATE('2004-01-01'))", "'23:59:59' + 0", "time"), + schema("ADDTIME(DATE('2004-01-01'), TIME('23:59:59'))", "'2004-01-01' + '23:59:59'", "datetime"), + schema("ADDTIME(TIME('10:20:30'), TIME('00:05:42'))", "'10:20:30' + '00:05:42'", "time"), + schema("ADDTIME(TIMESTAMP('1999-12-31 15:42:13'), DATETIME('1961-04-12 09:07:00'))", "'15:42:13' + '09:07:00'", "datetime")); + verifyDataRows(result, rows("2008-12-12 00:00:00", "23:59:59", "2004-01-01 23:59:59", "10:26:12", "2000-01-01 00:49:13")); + } + + @Test + public void testSubTime() throws IOException { + var result = executeQuery("SELECT" + + " SUBTIME(DATE('2008-12-12'), DATE('2008-11-15')) AS `'2008-12-12' - 0`," + + " SUBTIME(TIME('23:59:59'), DATE('2004-01-01')) AS `'23:59:59' - 0`," + + " SUBTIME(DATE('2004-01-01'), TIME('23:59:59')) AS `'2004-01-01' - '23:59:59'`," + + " SUBTIME(TIME('10:20:30'), TIME('00:05:42')) AS `'10:20:30' - '00:05:42'`," + + " SUBTIME(TIMESTAMP('1999-12-31 15:42:13'), DATETIME('1961-04-12 09:07:00')) AS `'15:42:13' - '09:07:00'`"); + verifySchema(result, + schema("SUBTIME(DATE('2008-12-12'), DATE('2008-11-15'))", "'2008-12-12' - 0", "datetime"), + schema("SUBTIME(TIME('23:59:59'), DATE('2004-01-01'))", "'23:59:59' - 0", "time"), + schema("SUBTIME(DATE('2004-01-01'), TIME('23:59:59'))", "'2004-01-01' - '23:59:59'", "datetime"), + schema("SUBTIME(TIME('10:20:30'), TIME('00:05:42'))", "'10:20:30' - '00:05:42'", "time"), + schema("SUBTIME(TIMESTAMP('1999-12-31 15:42:13'), DATETIME('1961-04-12 09:07:00'))", "'15:42:13' - '09:07:00'", "datetime")); + verifyDataRows(result, rows("2008-12-12 00:00:00", "23:59:59", "2003-12-31 00:00:01", "10:14:48", "1999-12-31 06:35:13")); + } + public void testDateDiff() throws IOException { var result = executeQuery("SELECT" + " DATEDIFF(TIMESTAMP('2000-01-02 00:00:00'), TIMESTAMP('2000-01-01 23:59:59')) AS `'2000-01-02' - '2000-01-01'`," diff --git a/ppl/src/main/antlr/OpenSearchPPLLexer.g4 b/ppl/src/main/antlr/OpenSearchPPLLexer.g4 index 778d9fb3f9..12c24bd531 100644 --- a/ppl/src/main/antlr/OpenSearchPPLLexer.g4 +++ b/ppl/src/main/antlr/OpenSearchPPLLexer.g4 @@ -243,6 +243,7 @@ CURRENT_DATE: 'CURRENT_DATE'; CURRENT_TIME: 'CURRENT_TIME'; CURRENT_TIMESTAMP: 'CURRENT_TIMESTAMP'; CURTIME: 'CURTIME'; +ADDTIME: 'ADDTIME'; DATE: 'DATE'; DATE_ADD: 'DATE_ADD'; DATE_FORMAT: 'DATE_FORMAT'; @@ -263,6 +264,7 @@ NOW: 'NOW'; PERIOD_ADD: 'PERIOD_ADD'; PERIOD_DIFF: 'PERIOD_DIFF'; SUBDATE: 'SUBDATE'; +SUBTIME: 'SUBTIME'; SYSDATE: 'SYSDATE'; TIME: 'TIME'; TIME_TO_SEC: 'TIME_TO_SEC'; diff --git a/ppl/src/main/antlr/OpenSearchPPLParser.g4 b/ppl/src/main/antlr/OpenSearchPPLParser.g4 index cb9bfae32f..dbb63ef12a 100644 --- a/ppl/src/main/antlr/OpenSearchPPLParser.g4 +++ b/ppl/src/main/antlr/OpenSearchPPLParser.g4 @@ -433,6 +433,7 @@ trigonometricFunctionName dateAndTimeFunctionBase : ADDDATE + | ADDTIME | CONVERT_TZ | CURRENT_DATE | CURRENT_TIME @@ -467,6 +468,7 @@ dateAndTimeFunctionBase | QUARTER | SECOND | SUBDATE + | SUBTIME | SYSDATE | TIME | TIME_TO_SEC diff --git a/sql/src/main/antlr/OpenSearchSQLLexer.g4 b/sql/src/main/antlr/OpenSearchSQLLexer.g4 index 63fd51fc5d..941c1a4c4e 100644 --- a/sql/src/main/antlr/OpenSearchSQLLexer.g4 +++ b/sql/src/main/antlr/OpenSearchSQLLexer.g4 @@ -176,6 +176,7 @@ TABLES: 'TABLES'; ABS: 'ABS'; ACOS: 'ACOS'; ADD: 'ADD'; +ADDTIME: 'ADDTIME'; ASCII: 'ASCII'; ASIN: 'ASIN'; ATAN: 'ATAN'; @@ -251,6 +252,7 @@ SIN: 'SIN'; SINH: 'SINH'; SQRT: 'SQRT'; SUBDATE: 'SUBDATE'; +SUBTIME: 'SUBTIME'; SUBTRACT: 'SUBTRACT'; SYSDATE: 'SYSDATE'; TAN: 'TAN'; diff --git a/sql/src/main/antlr/OpenSearchSQLParser.g4 b/sql/src/main/antlr/OpenSearchSQLParser.g4 index cc8f5e0a8d..cb2c690316 100644 --- a/sql/src/main/antlr/OpenSearchSQLParser.g4 +++ b/sql/src/main/antlr/OpenSearchSQLParser.g4 @@ -426,6 +426,7 @@ trigonometricFunctionName dateTimeFunctionName : datetimeConstantLiteral | ADDDATE + | ADDTIME | CONVERT_TZ | CURDATE | CURTIME @@ -457,6 +458,7 @@ dateTimeFunctionName | SECOND | SECOND_OF_MINUTE | SUBDATE + | SUBTIME | SYSDATE | TIME | TIME_TO_SEC