diff --git a/be/src/exprs/timestamp_functions.cpp b/be/src/exprs/timestamp_functions.cpp index c1acd0f1e5..cb80c1c9cd 100644 --- a/be/src/exprs/timestamp_functions.cpp +++ b/be/src/exprs/timestamp_functions.cpp @@ -351,6 +351,106 @@ DateTimeVal TimestampFunctions::timestamp_time_op( return new_ts_val; } +BigIntVal TimestampFunctions::years_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +BigIntVal TimestampFunctions::months_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +BigIntVal TimestampFunctions::weeks_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +BigIntVal TimestampFunctions::days_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +BigIntVal TimestampFunctions::hours_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +BigIntVal TimestampFunctions::minutes_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +BigIntVal TimestampFunctions::seconds_diff( + FunctionContext* ctx, const DateTimeVal& ts_val1, const DateTimeVal& ts_val2) { + return timestamp_diff(ctx, ts_val1, ts_val2); +} + +template +BigIntVal TimestampFunctions::timestamp_diff(FunctionContext* ctx, const DateTimeVal& ts_val2, const DateTimeVal& ts_val1) { + if (ts_val1.is_null || ts_val2.is_null) { + return BigIntVal::null(); + } + + DateTimeValue ts_value1 = DateTimeValue::from_datetime_val(ts_val1); + DateTimeValue ts_value2 = DateTimeValue::from_datetime_val(ts_val2); + + switch (unit) { + case YEAR: { + int year = (ts_value2.year() - ts_value1.year()); + if (year >= 0) { + year -= (ts_value2.to_int64() % 10000000000 - ts_value1.to_int64() % 10000000000) < 0; + } else { + year += (ts_value2.to_int64() % 10000000000 - ts_value1.to_int64() % 10000000000) > 0; + } + return year; + } + case MONTH: { + int month = (ts_value2.year() - ts_value1.year()) * 12 + (ts_value2.month() - ts_value1.month()); + if (month >= 0) { + month -= (ts_value2.to_int64() % 100000000 - ts_value1.to_int64() % 100000000) < 0; + } else { + month += (ts_value2.to_int64() % 100000000 - ts_value1.to_int64() % 100000000) > 0; + } + return month; + } + case WEEK: { + int day = ts_value2.daynr() - ts_value1.daynr(); + if (day >= 0) { + day -= ts_value2.time_part_diff(ts_value1) < 0; + } else { + day += ts_value2.time_part_diff(ts_value1) > 0; + } + return day / 7; + } + case DAY: { + int day = ts_value2.daynr() - ts_value1.daynr(); + if (day >= 0) { + day -= ts_value2.time_part_diff(ts_value1) < 0; + } else { + day += ts_value2.time_part_diff(ts_value1) > 0; + } + return day; + } + case HOUR: { + int64_t second = ts_value2.second_diff(ts_value1); + int64_t hour = second / 60 / 60; + return hour; + } + case MINUTE: { + int64_t second = ts_value2.second_diff(ts_value1); + int64_t minute = second / 60; + return minute; + } + case SECOND: { + int64_t second = ts_value2.second_diff(ts_value1); + return second; + } + default: + return BigIntVal::null(); + } +} + StringVal TimestampFunctions::date_format( FunctionContext* ctx, const DateTimeVal& ts_val, const StringVal& format) { if (ts_val.is_null || format.is_null) { diff --git a/be/src/exprs/timestamp_functions.h b/be/src/exprs/timestamp_functions.h index 317d496574..1f71e9379c 100644 --- a/be/src/exprs/timestamp_functions.h +++ b/be/src/exprs/timestamp_functions.h @@ -130,6 +130,25 @@ public: static doris_udf::StringVal day_name( doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val); + // timestamp function + template + static doris_udf::BigIntVal timestamp_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal years_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal months_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal weeks_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal days_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal hours_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal minutes_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + static doris_udf::BigIntVal seconds_diff( + doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& ts_val1, const doris_udf::DateTimeVal& ts_val2); + // TimeZone correlation functions. static doris_udf::DateTimeVal timestamp( doris_udf::FunctionContext* ctx, const doris_udf::DateTimeVal& val); diff --git a/be/src/runtime/datetime_value.h b/be/src/runtime/datetime_value.h index b6d04af4bd..815bce6262 100644 --- a/be/src/runtime/datetime_value.h +++ b/be/src/runtime/datetime_value.h @@ -446,6 +446,12 @@ public: return day_diff * 3600 * 24 + time_diff; } + int64_t time_part_diff(const DateTimeValue& rhs) const { + int time_diff = (hour() * 3600 + minute() * 60 + second()) + - (rhs.hour() * 3600 + rhs.minute() * 60 + rhs.second()); + return time_diff; + } + void set_type(int type); static const char* _s_llvm_class_name; diff --git a/be/test/exprs/timestamp_functions_test.cpp b/be/test/exprs/timestamp_functions_test.cpp index f1ae1ce292..a79ac176e3 100644 --- a/be/test/exprs/timestamp_functions_test.cpp +++ b/be/test/exprs/timestamp_functions_test.cpp @@ -122,6 +122,57 @@ TEST_F(TimestampFunctionsTest, convert_tz_test) { ASSERT_EQ(20190806013857, dt3.to_int64()); } +TEST_F(TimestampFunctionsTest, timestampdiff_test) { + doris_udf::FunctionContext *context = new doris_udf::FunctionContext(); + DateTimeValue dt1(20120824000001); + doris_udf::DateTimeVal tv1; + dt1.to_datetime_val(&tv1); + DateTimeValue dt2(20120830000000); + doris_udf::DateTimeVal tv2; + dt2.to_datetime_val(&tv2); + + //YEAR + ASSERT_EQ(0, TimestampFunctions::years_diff(context, tv2, tv1).val); + DateTimeValue dt_year(20100930000000); + doris_udf::DateTimeVal tv_year; + dt_year.to_datetime_val(&tv_year); + ASSERT_EQ(-1, TimestampFunctions::years_diff(context, tv_year, tv1).val); + //MONTH + ASSERT_EQ(0, TimestampFunctions::months_diff(context, tv2, tv1).val); + DateTimeValue dt3(20120924000000); + doris_udf::DateTimeVal tv3; + dt3.to_datetime_val(&tv3); + ASSERT_EQ(0, TimestampFunctions::months_diff(context, tv3, tv1).val); + DateTimeValue dt_month(20120631000000); + doris_udf::DateTimeVal tv_month; + dt_month.to_datetime_val(&tv_month); + ASSERT_EQ(-1, TimestampFunctions::months_diff(context, tv_month, tv1).val); + //WEEK + ASSERT_EQ(0, TimestampFunctions::weeks_diff(context, tv2, tv1).val); + //DAY + ASSERT_EQ(5, TimestampFunctions::days_diff(context, tv2, tv1).val); + DateTimeValue dt4(20120830000001); + doris_udf::DateTimeVal tv4; + dt4.to_datetime_val(&tv4); + ASSERT_EQ(6, TimestampFunctions::days_diff(context, tv4, tv1).val); + DateTimeValue dt5(20120901000001); + doris_udf::DateTimeVal tv5; + dt5.to_datetime_val(&tv5); + ASSERT_EQ(8, TimestampFunctions::days_diff(context, tv5, tv1).val); + + DateTimeValue dt_day(20120823000005); + doris_udf::DateTimeVal tv_day; + dt_day.to_datetime_val(&tv_day); + ASSERT_EQ(0, TimestampFunctions::days_diff(context, tv_day, tv1).val); + + //HOUR + ASSERT_EQ(143, TimestampFunctions::hours_diff(context, tv2, tv1).val); + //MINUTE + ASSERT_EQ(8639, TimestampFunctions::minutes_diff(context, tv2, tv1).val); + //SECOND + ASSERT_EQ(518399, TimestampFunctions::seconds_diff(context, tv2, tv1).val); +} + } int main(int argc, char** argv) { ::testing::InitGoogleTest(&argc, argv); diff --git a/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/hour.md b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/hour.md new file mode 100644 index 0000000000..c935697ca7 --- /dev/null +++ b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/hour.md @@ -0,0 +1,42 @@ + + +# hour +## description +### Syntax + +`INT HOUR(DATETIME date)` + + +获得日期中的小时的信息,返回值范围从0-23。 + +参数为Date或者Datetime类型 + +## example + +``` +mysql> select hour('2018-12-31 23:59:59'); ++-----------------------------+ +| hour('2018-12-31 23:59:59') | ++-----------------------------+ +| 23 | ++-----------------------------+ +``` +##keyword +HOUR diff --git a/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/minute.md b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/minute.md new file mode 100644 index 0000000000..84c3c9efdf --- /dev/null +++ b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/minute.md @@ -0,0 +1,42 @@ + + +# minute +## description +### Syntax + +`INT MINUTE(DATETIME date)` + + +获得日期中的分钟的信息,返回值范围从0-59。 + +参数为Date或者Datetime类型 + +## example + +``` +mysql> select minute('2018-12-31 23:59:59'); ++-----------------------------+ +| minute('2018-12-31 23:59:59') | ++-----------------------------+ +| 59 | ++-----------------------------+ +``` +##keyword +MINUTE diff --git a/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/second.md b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/second.md new file mode 100644 index 0000000000..d9226d3403 --- /dev/null +++ b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/second.md @@ -0,0 +1,42 @@ + + +# second +## description +### Syntax + +`INT SECOND(DATETIME date)` + + +获得日期中的秒的信息,返回值范围从0-59。 + +参数为Date或者Datetime类型 + +## example + +``` +mysql> select second('2018-12-31 23:59:59'); ++-----------------------------+ +| second('2018-12-31 23:59:59') | ++-----------------------------+ +| 59 | ++-----------------------------+ +``` +##keyword +SECOND diff --git a/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/timestampadd.md b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/timestampadd.md new file mode 100644 index 0000000000..34848e6067 --- /dev/null +++ b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/timestampadd.md @@ -0,0 +1,52 @@ + + +# timestampadd +## description +### Syntax + +`DATETIME TIMESTAMPADD(unit, interval, DATETIME datetime_expr)` + + +将整数表达式间隔添加到日期或日期时间表达式datetime_expr中。 + +interval的单位由unit参数给出,它应该是下列值之一: + +SECOND, MINUTE, HOUR, DAY, WEEK, MONTH, or YEAR。 + +## example + +``` + +mysql> SELECT TIMESTAMPADD(MINUTE,1,'2019-01-02'); ++------------------------------------------------+ +| timestampadd(MINUTE, 1, '2019-01-02 00:00:00') | ++------------------------------------------------+ +| 2019-01-02 00:01:00 | ++------------------------------------------------+ + +mysql> SELECT TIMESTAMPADD(WEEK,1,'2019-01-02'); ++----------------------------------------------+ +| timestampadd(WEEK, 1, '2019-01-02 00:00:00') | ++----------------------------------------------+ +| 2019-01-09 00:00:00 | ++----------------------------------------------+ +``` +##keyword +TIMESTAMPADD diff --git a/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/timestampdiff.md b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/timestampdiff.md new file mode 100644 index 0000000000..86a3557ef1 --- /dev/null +++ b/docs/documentation/cn/sql-reference/sql-functions/date-time-functions/timestampdiff.md @@ -0,0 +1,60 @@ + + +# timestampdiff +## description +### Syntax + +`INT TIMESTAMPDIFF(unit,DATETIME datetime_expr1, DATETIME datetime_expr2)` + +返回datetime_expr2−datetime_expr1,其中datetime_expr1和datetime_expr2是日期或日期时间表达式。 + +结果(整数)的单位由unit参数给出。interval的单位由unit参数给出,它应该是下列值之一: + +SECOND, MINUTE, HOUR, DAY, WEEK, MONTH, or YEAR。 + +## example + +``` + +MySQL> SELECT TIMESTAMPDIFF(MONTH,'2003-02-01','2003-05-01'); ++--------------------------------------------------------------------+ +| timestampdiff(MONTH, '2003-02-01 00:00:00', '2003-05-01 00:00:00') | ++--------------------------------------------------------------------+ +| 3 | ++--------------------------------------------------------------------+ + +MySQL> SELECT TIMESTAMPDIFF(YEAR,'2002-05-01','2001-01-01'); ++-------------------------------------------------------------------+ +| timestampdiff(YEAR, '2002-05-01 00:00:00', '2001-01-01 00:00:00') | ++-------------------------------------------------------------------+ +| -1 | ++-------------------------------------------------------------------+ + + +MySQL> SELECT TIMESTAMPDIFF(MINUTE,'2003-02-01','2003-05-01 12:05:55'); ++---------------------------------------------------------------------+ +| timestampdiff(MINUTE, '2003-02-01 00:00:00', '2003-05-01 12:05:55') | ++---------------------------------------------------------------------+ +| 128885 | ++---------------------------------------------------------------------+ + +``` +##keyword +TIMESTAMPDIFF diff --git a/docs/documentation/en/sql-reference/sql-functions/date-time-functions/hour_EN.md b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/hour_EN.md new file mode 100644 index 0000000000..b245269b79 --- /dev/null +++ b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/hour_EN.md @@ -0,0 +1,41 @@ + + +# hour +## description +### Syntax + +`INT HOUR(DATETIME date)` + +Returns hour information in the time type, ranging from 0,23 + +The parameter is Date or Datetime type + +## example + +``` +mysql> select hour('2018-12-31 23:59:59'); ++-----------------------------+ +| hour('2018-12-31 23:59:59') | ++-----------------------------+ +| 23 | ++-----------------------------+ +``` +##keyword +HOUR diff --git a/docs/documentation/en/sql-reference/sql-functions/date-time-functions/minute_EN.md b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/minute_EN.md new file mode 100644 index 0000000000..c43c26c3fd --- /dev/null +++ b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/minute_EN.md @@ -0,0 +1,41 @@ + + +# minute +## description +### Syntax + +`INT MINUTE(DATETIME date)` + +Returns minute information in the time type, ranging from 0,59 + +The parameter is Date or Datetime type + +## example + +``` +mysql> select minute('2018-12-31 23:59:59'); ++-----------------------------+ +| minute('2018-12-31 23:59:59') | ++-----------------------------+ +| 59 | ++-----------------------------+ +``` +##keyword +MINUTE diff --git a/docs/documentation/en/sql-reference/sql-functions/date-time-functions/second_EN.md b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/second_EN.md new file mode 100644 index 0000000000..8318a1c117 --- /dev/null +++ b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/second_EN.md @@ -0,0 +1,41 @@ + + +# second +## description +### Syntax + +`INT SECOND(DATETIME date)` + +Returns second information in the time type, ranging from 0,59 + +The parameter is Date or Datetime type + +## example + +``` +mysql> select second('2018-12-31 23:59:59'); ++-----------------------------+ +| second('2018-12-31 23:59:59') | ++-----------------------------+ +| 59 | ++-----------------------------+ +``` +##keyword +SECOND diff --git a/docs/documentation/en/sql-reference/sql-functions/date-time-functions/timestampadd_EN.md b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/timestampadd_EN.md new file mode 100644 index 0000000000..71dcd7bc7d --- /dev/null +++ b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/timestampadd_EN.md @@ -0,0 +1,51 @@ + + +# timestampadd +## description +### Syntax + +`DATETIME TIMESTAMPADD(unit, interval, DATETIME datetime_expr)` + +Adds the integer expression interval to the date or datetime expression datetime_expr. + +The unit for interval is given by the unit argument, which should be one of the following values: + +SECOND, MINUTE, HOUR, DAY, WEEK, MONTH, or YEAR. + +## example + +``` + +mysql> SELECT TIMESTAMPADD(MINUTE,1,'2019-01-02'); ++------------------------------------------------+ +| timestampadd(MINUTE, 1, '2019-01-02 00:00:00') | ++------------------------------------------------+ +| 2019-01-02 00:01:00 | ++------------------------------------------------+ + +mysql> SELECT TIMESTAMPADD(WEEK,1,'2019-01-02'); ++----------------------------------------------+ +| timestampadd(WEEK, 1, '2019-01-02 00:00:00') | ++----------------------------------------------+ +| 2019-01-09 00:00:00 | ++----------------------------------------------+ +``` +##keyword +TIMESTAMPADD diff --git a/docs/documentation/en/sql-reference/sql-functions/date-time-functions/timestampdiff_EN.md b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/timestampdiff_EN.md new file mode 100644 index 0000000000..2eb8c0046e --- /dev/null +++ b/docs/documentation/en/sql-reference/sql-functions/date-time-functions/timestampdiff_EN.md @@ -0,0 +1,60 @@ + + +# timestampdiff +## description +### Syntax + +`INT TIMESTAMPDIFF(unit,DATETIME datetime_expr1, DATETIME datetime_expr2)` + +Returns datetime_expr2 − datetime_expr1, where datetime_expr1 and datetime_expr2 are date or datetime expressions. + +The unit for the result (an integer) is given by the unit argument. + +The legal values for unit are the same as those listed in the description of the TIMESTAMPADD() function. + +## example + +``` + +MySQL> SELECT TIMESTAMPDIFF(MONTH,'2003-02-01','2003-05-01'); ++--------------------------------------------------------------------+ +| timestampdiff(MONTH, '2003-02-01 00:00:00', '2003-05-01 00:00:00') | ++--------------------------------------------------------------------+ +| 3 | ++--------------------------------------------------------------------+ + +MySQL> SELECT TIMESTAMPDIFF(YEAR,'2002-05-01','2001-01-01'); ++-------------------------------------------------------------------+ +| timestampdiff(YEAR, '2002-05-01 00:00:00', '2001-01-01 00:00:00') | ++-------------------------------------------------------------------+ +| -1 | ++-------------------------------------------------------------------+ + + +MySQL> SELECT TIMESTAMPDIFF(MINUTE,'2003-02-01','2003-05-01 12:05:55'); ++---------------------------------------------------------------------+ +| timestampdiff(MINUTE, '2003-02-01 00:00:00', '2003-05-01 12:05:55') | ++---------------------------------------------------------------------+ +| 128885 | ++---------------------------------------------------------------------+ + +``` +##keyword +TIMESTAMPDIFF diff --git a/fe/src/main/cup/sql_parser.cup b/fe/src/main/cup/sql_parser.cup index 8c6ac18df6..4a47b0e412 100644 --- a/fe/src/main/cup/sql_parser.cup +++ b/fe/src/main/cup/sql_parser.cup @@ -195,12 +195,12 @@ terminal String KW_ADD, KW_ADMIN, KW_AFTER, KW_AGGREGATE, KW_ALL, KW_ALTER, KW_A KW_CANCEL, KW_CASE, KW_CAST, KW_CHAIN, KW_CHAR, KW_CHARSET, KW_CLUSTER, KW_CLUSTERS, KW_COLLATE, KW_COLLATION, KW_COLUMN, KW_COLUMNS, KW_COMMENT, KW_COMMIT, KW_COMMITTED, KW_CONFIG, KW_CONNECTION, KW_CONNECTION_ID, KW_CONSISTENT, KW_COUNT, KW_CREATE, KW_CROSS, KW_CURRENT, KW_CURRENT_USER, - KW_DATA, KW_DATABASE, KW_DATABASES, KW_DATE, KW_DATETIME, KW_TIME, KW_DECIMAL, KW_DECOMMISSION, KW_DEFAULT, KW_DESC, KW_DESCRIBE, + KW_DATA, KW_DATABASE, KW_DATABASES, KW_DATE, KW_DATETIME, KW_DAY, KW_DECIMAL, KW_DECOMMISSION, KW_DEFAULT, KW_DESC, KW_DESCRIBE, KW_DELETE, KW_DISTINCT, KW_DISTINCTPC, KW_DISTINCTPCSA, KW_DISTRIBUTED, KW_DISTRIBUTION, KW_DYNAMIC, KW_BUCKETS, KW_DIV, KW_DOUBLE, KW_DROP, KW_DROPP, KW_DUPLICATE, KW_ELSE, KW_END, KW_ENGINE, KW_ENGINES, KW_ENTER, KW_ERRORS, KW_EVENTS, KW_EXISTS, KW_EXPORT, KW_EXTERNAL, KW_EXTRACT, KW_FALSE, KW_FOLLOWER, KW_FOLLOWING, KW_FREE, KW_FROM, KW_FILE, KW_FIRST, KW_FLOAT, KW_FOR, KW_FORMAT, KW_FRONTEND, KW_FRONTENDS, KW_FULL, KW_FUNCTION, KW_GLOBAL, KW_GRANT, KW_GRANTS, KW_GROUP, - KW_HASH, KW_HAVING, KW_HELP,KW_HLL, KW_HLL_UNION, KW_HUB, + KW_HASH, KW_HAVING, KW_HELP,KW_HLL, KW_HLL_UNION, KW_HOUR, KW_HUB, KW_IDENTIFIED, KW_IF, KW_IN, KW_INDEX, KW_INDEXES, KW_INFILE, KW_INNER, KW_INSERT, KW_INT, KW_INTERMEDIATE, KW_INTERVAL, KW_INTO, KW_IS, KW_ISNULL, KW_ISOLATION, KW_JOIN, @@ -208,7 +208,7 @@ terminal String KW_ADD, KW_ADMIN, KW_AFTER, KW_AGGREGATE, KW_ALL, KW_ALTER, KW_A KW_LABEL, KW_LARGEINT, KW_LAST, KW_LEFT, KW_LESS, KW_LEVEL, KW_LIKE, KW_LIMIT, KW_LINK, KW_LOAD, KW_ROUTINE, KW_PAUSE, KW_RESUME, KW_STOP, KW_TASK, KW_LOCAL, KW_LOCATION, - KW_MAX, KW_MAX_VALUE, KW_MERGE, KW_MIN, KW_MIGRATE, KW_MIGRATIONS, KW_MODIFY, + KW_MAX, KW_MAX_VALUE, KW_MERGE, KW_MIN, KW_MINUTE, KW_MIGRATE, KW_MIGRATIONS, KW_MODIFY, KW_MONTH, KW_NAME, KW_NAMES, KW_NEGATIVE, KW_NO, KW_NOT, KW_NULL, KW_NULLS, KW_OBSERVER, KW_OFFSET, KW_ON, KW_ONLY, KW_OPEN, KW_OR, KW_PIPE, KW_ORDER, KW_OUTER, KW_OVER, KW_PARTITION, KW_PARTITIONS, KW_PATH, KW_PRECEDING, @@ -219,14 +219,15 @@ terminal String KW_ADD, KW_ADMIN, KW_AFTER, KW_AGGREGATE, KW_ALL, KW_ALTER, KW_A KW_RANDOM, KW_RANGE, KW_READ, KW_RECOVER, KW_REGEXP, KW_RELEASE, KW_RENAME, KW_REPAIR, KW_REPEATABLE, KW_REPOSITORY, KW_REPOSITORIES, KW_REPLACE, KW_REPLACE_IF_NOT_NULL, KW_REPLICA, KW_RESOURCE, KW_RESTORE, KW_RETURNS, KW_REVOKE, KW_RIGHT, KW_ROLE, KW_ROLES, KW_ROLLBACK, KW_ROLLUP, KW_ROW, KW_ROWS, - KW_SCHEMAS, KW_SELECT, KW_SEMI, KW_SERIALIZABLE, KW_SESSION, KW_SET, KW_SHOW, + KW_SCHEMAS, KW_SECOND, KW_SELECT, KW_SEMI, KW_SERIALIZABLE, KW_SESSION, KW_SET, KW_SHOW, KW_SMALLINT, KW_SNAPSHOT, KW_SONAME, KW_SPLIT, KW_START, KW_STATUS, KW_STORAGE, KW_STRING, KW_SUM, KW_SUPERUSER, KW_SYNC, KW_SYSTEM, - KW_TABLE, KW_TABLES, KW_TABLET, KW_TERMINATED, KW_THAN, KW_THEN, KW_TIMESTAMP, KW_TINYINT, + KW_TABLE, KW_TABLES, KW_TABLET, KW_TERMINATED, KW_THAN, KW_THEN, KW_TIME, KW_TIMESTAMP, KW_TINYINT, KW_TO, KW_TRANSACTION, KW_TRIGGERS, KW_TRIM, KW_TRUE, KW_TRUNCATE, KW_TYPE, KW_TYPES, KW_UNCOMMITTED, KW_UNBOUNDED, KW_UNION, KW_UNIQUE, KW_UNSIGNED, KW_USE, KW_USER, KW_USING, KW_VALUE, KW_VALUES, KW_VARCHAR, KW_VARIABLES, KW_VIEW, KW_MATERIALIZED, - KW_WARNINGS, KW_WHEN, KW_WHITELIST, KW_WHERE, KW_WITH, KW_WORK, KW_WRITE; + KW_WARNINGS, KW_WEEK, KW_WHEN, KW_WHITELIST, KW_WHERE, KW_WITH, KW_WORK, KW_WRITE, + KW_YEAR; terminal COMMA, DOT, DOTDOTDOT, AT, STAR, LPAREN, RPAREN, SEMICOLON, LBRACKET, RBRACKET, DIVIDE, MOD, ADD, SUBTRACT; terminal BITAND, BITOR, BITXOR, BITNOT; @@ -3783,6 +3784,10 @@ timestamp_arithmetic_expr ::= RESULT = new TimestampArithmeticExpr(functionName.getFunction(), l.get(0), v, u); :} + | function_name:functionName LPAREN keyword:u COMMA expr:e1 COMMA expr:e2 RPAREN + {: + RESULT = new TimestampArithmeticExpr(functionName.getFunction(), e2, e1, u); + :} ; literal ::= @@ -4352,6 +4357,20 @@ keyword ::= {: RESULT = id; :} | KW_DYNAMIC:id {: RESULT = id; :} + | KW_YEAR:id + {: RESULT = id; :} + | KW_MONTH:id + {: RESULT = id; :} + | KW_WEEK:id + {: RESULT = id; :} + | KW_DAY:id + {: RESULT = id; :} + | KW_HOUR:id + {: RESULT = id; :} + | KW_MINUTE:id + {: RESULT = id; :} + | KW_SECOND:id + {: RESULT = id; :} ; // Identifier that contain keyword diff --git a/fe/src/main/java/org/apache/doris/analysis/TimestampArithmeticExpr.java b/fe/src/main/java/org/apache/doris/analysis/TimestampArithmeticExpr.java index 57dd403cc0..c04f16c6b8 100644 --- a/fe/src/main/java/org/apache/doris/analysis/TimestampArithmeticExpr.java +++ b/fe/src/main/java/org/apache/doris/analysis/TimestampArithmeticExpr.java @@ -120,75 +120,108 @@ public class TimestampArithmeticExpr extends Expr { @Override public void analyzeImpl(Analyzer analyzer) throws AnalysisException { // Check if name of function call is date_sub or date_add. - if (funcName != null) { - if (funcName.toUpperCase().equals("DATE_ADD") - || funcName.toUpperCase().equals("DAYS_ADD") - || funcName.toUpperCase().equals("ADDDATE")) { - op = ArithmeticExpr.Operator.ADD; - } else if (funcName.toUpperCase().equals("DATE_SUB") - || funcName.toUpperCase().equals("DAYS_SUB") - || funcName.toUpperCase().equals("SUBDATE")) { - op = ArithmeticExpr.Operator.SUBTRACT; - } else { - throw new AnalysisException("Encountered function name '" + funcName - + "' in timestamp arithmetic expression '" + toSql() + "'. " - + "Expected function name 'DATE_ADD/DAYS_ADD/ADDDATE'" - + "or 'DATE_SUB/DAYS_SUB/SUBDATE"); + String funcOpName; + if (funcName != null && funcName.equalsIgnoreCase("TIMESTAMPDIFF")) { + timeUnit = TIME_UNITS_MAP.get(timeUnitIdent.toUpperCase()); + if (timeUnit == null) { + throw new AnalysisException("Invalid time unit '" + timeUnitIdent + + "' in timestamp arithmetic expression '" + toSql() + "'."); } - } - timeUnit = TIME_UNITS_MAP.get(timeUnitIdent.toUpperCase()); - if (timeUnit == null) { - throw new AnalysisException("Invalid time unit '" + timeUnitIdent - + "' in timestamp arithmetic expression '" + toSql() + "'."); - } - - Type dateType = fixType(); - if (dateType.isDate() && timeUnit.isDateTime()) { - dateType = Type.DATETIME; - } - // The first child must return a timestamp or null. - if (!getChild(0).getType().isDateType() && !getChild(0).getType().isNull()) { - if (!dateType.isValid()) { - throw new AnalysisException("Operand '" + getChild(0).toSql() - + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" - + getChild(0).getType() + "'. Expected type 'TIMESTAMP/DATE/DATETIME'."); + Type dateType = fixType(); + if (dateType.isDate() && timeUnit.isDateTime()) { + dateType = Type.DATETIME; } - castChild(dateType, 0); - } - - if (!getChild(1).getType().isScalarType()) { - throw new AnalysisException("must be a scalar type."); - } - - // The second child must be of type 'INT' or castable to it. - if (!getChild(1).getType().isScalarType(PrimitiveType.INT)) { - if (!ScalarType.canCastTo((ScalarType) getChild(1).getType(), Type.INT)) { - throw new AnalysisException("Operand '" + getChild(1).toSql() - + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" - + getChild(1).getType() + "' which is incompatible with expected type 'INT'."); + // The first child must return a timestamp or null. + if (!getChild(0).getType().isDateType() && !getChild(0).getType().isNull()) { + if (!dateType.isValid()) { + throw new AnalysisException("Operand '" + getChild(0).toSql() + + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" + + getChild(0).getType() + "'. Expected type 'TIMESTAMP/DATE/DATETIME'."); + } + castChild(dateType, 0); } - castChild(Type.INT, 1); - } - type = dateType; - opcode = getOpCode(); - String funcOpName = String.format("%sS_%s", timeUnit, - (op == ArithmeticExpr.Operator.ADD) ? "ADD" : "SUB"); - // For the month interval, use the invisible special-case implementation. - // "ADD_MONTHS(t, m)" by definition is different from "t + INTERVAL m MONTHS". - // if (timeUnit == TimeUnit.MONTH) { - // funcOpName += "_INTERVAL"; - // } + // The first child must return a timestamp or null. + if (!getChild(1).getType().isDateType() && !getChild(1).getType().isNull()) { + if (!dateType.isValid()) { + throw new AnalysisException("Operand '" + getChild(1).toSql() + + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" + + getChild(1).getType() + "'. Expected type 'TIMESTAMP/DATE/DATETIME'."); + } + castChild(dateType, 1); + } + + type = Type.BIGINT; + opcode = getOpCode(); + funcOpName = String.format("%sS_%s", timeUnit, "DIFF"); + } else { + if (funcName != null) { + if (funcName.toUpperCase().equals("DATE_ADD") + || funcName.toUpperCase().equals("DAYS_ADD") + || funcName.toUpperCase().equals("ADDDATE") + || funcName.toUpperCase().equals("TIMESTAMPADD")) { + op = ArithmeticExpr.Operator.ADD; + } else if (funcName.toUpperCase().equals("DATE_SUB") + || funcName.toUpperCase().equals("DAYS_SUB") + || funcName.toUpperCase().equals("SUBDATE")) { + op = ArithmeticExpr.Operator.SUBTRACT; + } else { + throw new AnalysisException("Encountered function name '" + funcName + + "' in timestamp arithmetic expression '" + toSql() + "'. " + + "Expected function name 'DATE_ADD/DAYS_ADD/ADDDATE/TIMESTAMPADD'" + + "or 'DATE_SUB/DAYS_SUB/SUBDATE"); + } + } + + timeUnit = TIME_UNITS_MAP.get(timeUnitIdent.toUpperCase()); + if (timeUnit == null) { + throw new AnalysisException("Invalid time unit '" + timeUnitIdent + + "' in timestamp arithmetic expression '" + toSql() + "'."); + } + + Type dateType = fixType(); + if (dateType.isDate() && timeUnit.isDateTime()) { + dateType = Type.DATETIME; + } + // The first child must return a timestamp or null. + if (!getChild(0).getType().isDateType() && !getChild(0).getType().isNull()) { + if (!dateType.isValid()) { + throw new AnalysisException("Operand '" + getChild(0).toSql() + + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" + + getChild(0).getType() + "'. Expected type 'TIMESTAMP/DATE/DATETIME'."); + } + castChild(dateType, 0); + } + + if (!getChild(1).getType().isScalarType()) { + throw new AnalysisException("must be a scalar type."); + } + + // The second child must be of type 'INT' or castable to it. + if (!getChild(1).getType().isScalarType(PrimitiveType.INT)) { + if (!ScalarType.canCastTo((ScalarType) getChild(1).getType(), Type.INT)) { + throw new AnalysisException("Operand '" + getChild(1).toSql() + + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" + + getChild(1).getType() + "' which is incompatible with expected type 'INT'."); + } + castChild(Type.INT, 1); + } + + type = dateType; + opcode = getOpCode(); + funcOpName = String.format("%sS_%s", timeUnit, + (op == ArithmeticExpr.Operator.ADD) ? "ADD" : "SUB"); + } fn = getBuiltinFunction(analyzer, funcOpName.toLowerCase(), collectChildReturnTypes(), Function.CompareMode.IS_NONSTRICT_SUPERTYPE_OF); - LOG.info("fn is {} name is {}", fn, funcOpName); + LOG.debug("fn is {} name is {}", fn, funcOpName); } @Override protected void toThrift(TExprNode msg) { msg.node_type = TExprNodeType.COMPUTE_FUNCTION_CALL; - msg.setOpcode(opcode); + msg.setOpcode(opcode); } public ArithmeticExpr.Operator getOp() { @@ -258,6 +291,13 @@ public class TimestampArithmeticExpr extends Expr { public String toSqlImpl() { StringBuilder strBuilder = new StringBuilder(); if (funcName != null) { + if (funcName.equalsIgnoreCase("TIMESTAMPDIFF") || funcName.equalsIgnoreCase("TIMESTAMPADD")) { + strBuilder.append(funcName).append("("); + strBuilder.append(timeUnitIdent).append(", "); + strBuilder.append(getChild(1).toSql()).append(", "); + strBuilder.append(getChild(0).toSql()).append(")"); + return strBuilder.toString(); + } // Function-call like version. strBuilder.append(funcName).append("("); strBuilder.append(getChild(0).toSql()).append(", "); diff --git a/fe/src/main/jflex/sql_scanner.flex b/fe/src/main/jflex/sql_scanner.flex index 53322e7236..7988180e79 100644 --- a/fe/src/main/jflex/sql_scanner.flex +++ b/fe/src/main/jflex/sql_scanner.flex @@ -107,7 +107,7 @@ import org.apache.doris.qe.SqlModeHelper; keywordMap.put("bigint", new Integer(SqlParserSymbols.KW_BIGINT)); keywordMap.put("bitmap", new Integer(SqlParserSymbols.KW_BITMAP)); keywordMap.put("boolean", new Integer(SqlParserSymbols.KW_BOOLEAN)); - keywordMap.put("hll", new Integer(SqlParserSymbols.KW_HLL)); + keywordMap.put("day", new Integer(SqlParserSymbols.KW_DAY)); keywordMap.put("both", new Integer(SqlParserSymbols.KW_BOTH)); keywordMap.put("broker", new Integer(SqlParserSymbols.KW_BROKER)); keywordMap.put("by", new Integer(SqlParserSymbols.KW_BY)); @@ -199,8 +199,10 @@ import org.apache.doris.qe.SqlModeHelper; keywordMap.put("hash", new Integer(SqlParserSymbols.KW_HASH)); keywordMap.put("having", new Integer(SqlParserSymbols.KW_HAVING)); keywordMap.put("help", new Integer(SqlParserSymbols.KW_HELP)); + keywordMap.put("hll", new Integer(SqlParserSymbols.KW_HLL)); keywordMap.put("hll_union", new Integer(SqlParserSymbols.KW_HLL_UNION)); keywordMap.put("bitmap_union", new Integer(SqlParserSymbols.KW_BITMAP_UNION)); + keywordMap.put("hour", new Integer(SqlParserSymbols.KW_HOUR)); keywordMap.put("hub", new Integer(SqlParserSymbols.KW_HUB)); keywordMap.put("identified", new Integer(SqlParserSymbols.KW_IDENTIFIED)); keywordMap.put("if", new Integer(SqlParserSymbols.KW_IF)); @@ -241,7 +243,9 @@ import org.apache.doris.qe.SqlModeHelper; keywordMap.put("maxvalue", new Integer(SqlParserSymbols.KW_MAX_VALUE)); keywordMap.put("merge", new Integer(SqlParserSymbols.KW_MERGE)); keywordMap.put("min", new Integer(SqlParserSymbols.KW_MIN)); + keywordMap.put("minute", new Integer(SqlParserSymbols.KW_MINUTE)); keywordMap.put("modify", new Integer(SqlParserSymbols.KW_MODIFY)); + keywordMap.put("month", new Integer(SqlParserSymbols.KW_MONTH)); keywordMap.put("name", new Integer(SqlParserSymbols.KW_NAME)); keywordMap.put("names", new Integer(SqlParserSymbols.KW_NAMES)); keywordMap.put("negative", new Integer(SqlParserSymbols.KW_NEGATIVE)); @@ -301,6 +305,7 @@ import org.apache.doris.qe.SqlModeHelper; keywordMap.put("row", new Integer(SqlParserSymbols.KW_ROW)); keywordMap.put("rows", new Integer(SqlParserSymbols.KW_ROWS)); keywordMap.put("schemas", new Integer(SqlParserSymbols.KW_SCHEMAS)); + keywordMap.put("second", new Integer(SqlParserSymbols.KW_SECOND)); keywordMap.put("select", new Integer(SqlParserSymbols.KW_SELECT)); keywordMap.put("semi", new Integer(SqlParserSymbols.KW_SEMI)); keywordMap.put("serializable", new Integer(SqlParserSymbols.KW_SERIALIZABLE)); @@ -349,12 +354,14 @@ import org.apache.doris.qe.SqlModeHelper; keywordMap.put("view", new Integer(SqlParserSymbols.KW_VIEW)); keywordMap.put("materialized", new Integer(SqlParserSymbols.KW_MATERIALIZED)); keywordMap.put("warnings", new Integer(SqlParserSymbols.KW_WARNINGS)); + keywordMap.put("week", new Integer(SqlParserSymbols.KW_WEEK)); keywordMap.put("whitelist", new Integer(SqlParserSymbols.KW_WHITELIST)); keywordMap.put("when", new Integer(SqlParserSymbols.KW_WHEN)); keywordMap.put("where", new Integer(SqlParserSymbols.KW_WHERE)); keywordMap.put("with", new Integer(SqlParserSymbols.KW_WITH)); keywordMap.put("work", new Integer(SqlParserSymbols.KW_WORK)); keywordMap.put("write", new Integer(SqlParserSymbols.KW_WRITE)); + keywordMap.put("year", new Integer(SqlParserSymbols.KW_YEAR)); keywordMap.put("||", new Integer(SqlParserSymbols.KW_PIPE)); } diff --git a/gensrc/script/doris_builtins_functions.py b/gensrc/script/doris_builtins_functions.py index 0e9bbf2a96..afa21bfb16 100755 --- a/gensrc/script/doris_builtins_functions.py +++ b/gensrc/script/doris_builtins_functions.py @@ -226,6 +226,21 @@ visible_functions = [ [['convert_tz'], 'DATETIME', ['DATETIME', 'VARCHAR', 'VARCHAR'], '_ZN5doris18TimestampFunctions10convert_tzEPN9doris_udf15FunctionContextERKNS1_11DateTimeValERKNS1_9StringValES9_'], + [['years_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions10years_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + [['months_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions11months_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + [['weeks_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions10weeks_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + [['days_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions9days_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + [['hours_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions10hours_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + [['minutes_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions12minutes_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + [['seconds_diff'], 'BIGINT', ['DATETIME', 'DATETIME'], + '_ZN5doris18TimestampFunctions12seconds_diffEPN9doris_udf15FunctionContextERKNS1_11DateTimeValES6_'], + # Math builtin functions [['pi'], 'DOUBLE', [], '_ZN5doris13MathFunctions2piEPN9doris_udf15FunctionContextE'],