From ee705e30835a4dec2d753a5d705a30a481fc2f21 Mon Sep 17 00:00:00 2001 From: Alexander Behm Date: Tue, 7 Aug 2012 22:52:08 -0700 Subject: [PATCH] Added timestamp arithmetic expressions. --- be/src/exprs/expr-test.cc | 101 +++++++ be/src/exprs/timestamp-functions.cc | 102 ++++++- be/src/exprs/timestamp-functions.h | 33 +- common/function-registry/impala_functions.py | 44 ++- fe/src/main/cup/sql-parser.y | 56 +++- .../analysis/TimestampArithmeticExpr.java | 264 ++++++++++++++++ fe/src/main/jflex/sql-scanner.flex | 1 + .../impala/analysis/AnalyzerTest.java | 117 ++++++++ .../cloudera/impala/analysis/ParserTest.java | 57 +++- .../queries/QueryTest/exprs.test | 281 ++++++++++++++++++ 10 files changed, 1030 insertions(+), 26 deletions(-) create mode 100644 fe/src/main/java/com/cloudera/impala/analysis/TimestampArithmeticExpr.java diff --git a/be/src/exprs/expr-test.cc b/be/src/exprs/expr-test.cc index 7247c3a10..8533f0161 100644 --- a/be/src/exprs/expr-test.cc +++ b/be/src/exprs/expr-test.cc @@ -1645,6 +1645,53 @@ TEST_F(ExprTest, MathRoundingFunctions) { TEST_F(ExprTest, TimestampFunctions) { TestStringValue("cast(cast('2012-01-01 09:10:11.123456789' as timestamp) as string)", "2012-01-01 09:10:11.123456789"); + // Add/sub years. + TestStringValue("cast(date_add(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 10 years) as string)", + "2022-01-01 09:10:11.123456789"); + TestStringValue("cast(date_sub(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 10 years) as string)", + "2002-01-01 09:10:11.123456789"); + // Add/sub months. + TestStringValue("cast(date_add(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 13 months) as string)", + "2013-02-01 09:10:11.123456789"); + TestStringValue("cast(date_sub(cast('2013-02-01 09:10:11.123456789' " + "as timestamp), interval 13 months) as string)", + "2012-01-01 09:10:11.123456789"); + TestStringValue("cast(date_add(cast('2012-01-31 09:10:11.123456789' " + "as timestamp), interval 1 month) as string)", + "2012-02-29 09:10:11.123456789"); + TestStringValue("cast(date_sub(cast('2012-02-29 09:10:11.123456789' " + "as timestamp), interval 1 month) as string)", + "2012-01-31 09:10:11.123456789"); + // Add/sub weeks. + TestStringValue("cast(date_add(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 2 weeks) as string)", + "2012-01-15 09:10:11.123456789"); + TestStringValue("cast(date_sub(cast('2012-01-15 09:10:11.123456789' " + "as timestamp), interval 2 weeks) as string)", + "2012-01-01 09:10:11.123456789"); + TestStringValue("cast(date_add(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 53 weeks) as string)", + "2013-01-06 09:10:11.123456789"); + TestStringValue("cast(date_sub(cast('2013-01-06 09:10:11.123456789' " + "as timestamp), interval 53 weeks) as string)", + "2012-01-01 09:10:11.123456789"); + // Add/sub days. + TestStringValue("cast(date_add(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 10 days) as string)", + "2012-01-11 09:10:11.123456789"); + TestStringValue("cast(date_sub(cast('2012-01-01 09:10:11.123456789' " + "as timestamp), interval 10 days) as string)", + "2011-12-22 09:10:11.123456789"); + TestStringValue("cast(date_add(cast('2011-12-22 09:10:11.12345678' " + "as timestamp), interval 10 days) as string)", + "2012-01-01 09:10:11.123456780"); + TestStringValue("cast(date_sub(cast('2011-12-22 09:10:11.12345678' " + "as timestamp), interval 365 days) as string)", + "2010-12-22 09:10:11.123456780"); + // Add/sub days (HIVE's date_add/sub variant). TestStringValue("cast(date_add(cast('2012-01-01 09:10:11.123456789' " "as timestamp), 10) as string)", "2012-01-11 09:10:11.123456789"); @@ -1657,6 +1704,60 @@ TEST_F(ExprTest, TimestampFunctions) { TestStringValue( "cast(date_sub(cast('2011-12-22 09:10:11.12345678' as timestamp), 365) as string)", "2010-12-22 09:10:11.123456780"); + // Add/sub hours. + TestStringValue("cast(date_add(cast('2012-01-01 00:00:00.123456789' " + "as timestamp), interval 25 hours) as string)", + "2012-01-02 01:00:00.123456789"); + TestStringValue("cast(date_sub(cast('2012-01-02 01:00:00.123456789' " + "as timestamp), interval 25 hours) as string)", + "2012-01-01 00:00:00.123456789"); + // Add/sub minutes. + TestStringValue("cast(date_add(cast('2012-01-01 00:00:00.123456789' " + "as timestamp), interval 1533 minutes) as string)", + "2012-01-02 01:33:00.123456789"); + TestStringValue("cast(date_sub(cast('2012-01-02 01:33:00.123456789' " + "as timestamp), interval 1533 minutes) as string)", + "2012-01-01 00:00:00.123456789"); + // Add/sub seconds. + TestStringValue("cast(date_add(cast('2012-01-01 00:00:00.123456789' " + "as timestamp), interval 90033 seconds) as string)", + "2012-01-02 01:00:33.123456789"); + TestStringValue("cast(date_sub(cast('2012-01-02 01:00:33.123456789' " + "as timestamp), interval 90033 seconds) as string)", + "2012-01-01 00:00:00.123456789"); + // Add/sub milliseconds. + TestStringValue("cast(date_add(cast('2012-01-01 00:00:00.000000001' " + "as timestamp), interval 90000033 milliseconds) as string)", + "2012-01-02 01:00:00.033000001"); + TestStringValue("cast(date_sub(cast('2012-01-02 01:00:00.033000001' " + "as timestamp), interval 90000033 milliseconds) as string)", + "2012-01-01 00:00:00.000000001"); + // Add/sub microseconds. + TestStringValue("cast(date_add(cast('2012-01-01 00:00:00.000000001' " + "as timestamp), interval 1033 microseconds) as string)", + "2012-01-01 00:00:00.001033001"); + TestStringValue("cast(date_sub(cast('2012-01-01 00:00:00.001033001' " + "as timestamp), interval 1033 microseconds) as string)", + "2012-01-01 00:00:00.000000001"); + // Add/sub nanoseconds. + TestStringValue("cast(date_add(cast('2012-01-01 00:00:00.000000001' " + "as timestamp), interval 1033 nanoseconds) as string)", + "2012-01-01 00:00:00.000001034"); + TestStringValue("cast(date_sub(cast('2012-01-01 00:00:00.000001034' " + "as timestamp), interval 1033 nanoseconds) as string)", + "2012-01-01 00:00:00.000000001"); + + // Test add/sub behavior with very large time values. + string max_int = lexical_cast(numeric_limits::max()); + TestStringValue( + "cast(years_add(cast('2000-01-01 00:00:00' " + "as timestamp), " + max_int + ") as string)", + "1999-01-01 00:00:00"); + TestStringValue( + "cast(years_sub(cast('2000-01-01 00:00:00' " + "as timestamp), " + max_int + ") as string)", + "2001-01-01 00:00:00"); + TestValue("unix_timestamp(cast('1970-01-01 00:00:00' as timestamp))", TYPE_INT, 0); TestStringValue("cast(cast(0 as timestamp) as string)", "1970-01-01 00:00:00"); TestValue("cast('2011-12-22 09:10:11.123456789' as timestamp) > \ diff --git a/be/src/exprs/timestamp-functions.cc b/be/src/exprs/timestamp-functions.cc index c77806ed8..4e801be36 100644 --- a/be/src/exprs/timestamp-functions.cc +++ b/be/src/exprs/timestamp-functions.cc @@ -150,35 +150,119 @@ void* TimestampFunctions::ToDate(Expr* e, TupleRow* row) { return &e->result_.string_val; } -void* TimestampFunctions::DateAdd(Expr* e, TupleRow* row) { +void* TimestampFunctions::YearsAdd(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, true); +} + +void* TimestampFunctions::YearsSub(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, false); +} + +void* TimestampFunctions::MonthsAdd(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, true); +} + +void* TimestampFunctions::MonthsSub(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, false); +} + +void* TimestampFunctions::WeeksAdd(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, true); +} + +void* TimestampFunctions::WeeksSub(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, false); +} + +void* TimestampFunctions::DaysAdd(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, true); +} + +void* TimestampFunctions::DaysSub(Expr* e, TupleRow* row) { + return TimestampDateOp(e, row, false); +} + +void* TimestampFunctions::HoursAdd(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, true); +} + +void* TimestampFunctions::HoursSub(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, false); +} + +void* TimestampFunctions::MinutesAdd(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, true); +} + +void* TimestampFunctions::MinutesSub(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, false); +} + +void* TimestampFunctions::SecondsAdd(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, true); +} + +void* TimestampFunctions::SecondsSub(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, false); +} + +void* TimestampFunctions::MillisAdd(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, true); +} + +void* TimestampFunctions::MillisSub(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, false); +} + +void* TimestampFunctions::MicrosAdd(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, true); +} + +void* TimestampFunctions::MicrosSub(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, false); +} + +void* TimestampFunctions::NanosAdd(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, true); +} + +void* TimestampFunctions::NanosSub(Expr* e, TupleRow* row) { + return TimestampTimeOp(e, row, false); +} + +template +void* TimestampFunctions::TimestampDateOp(Expr* e, TupleRow* row, bool is_add) { DCHECK_EQ(e->GetNumChildren(), 2); Expr* op1 = e->children()[0]; Expr* op2 = e->children()[1]; TimestampValue* tv = reinterpret_cast(op1->GetValue(row)); - int* count = reinterpret_cast(op2->GetValue(row)); + int32_t* count = reinterpret_cast(op2->GetValue(row)); if (tv == NULL || count == NULL) return NULL; if (tv->date().is_special()) return NULL; - date_duration d(*count); - TimestampValue value(tv->date() + d, tv->time_of_day()); + UNIT unit(*count); + TimestampValue + value((is_add ? tv->date() + unit : tv->date() - unit), tv->time_of_day()); e->result_.timestamp_val = value; return &e->result_.timestamp_val; } -void* TimestampFunctions::DateSub(Expr* e, TupleRow* row) { +template +void* TimestampFunctions::TimestampTimeOp(Expr* e, TupleRow* row, bool is_add) { DCHECK_EQ(e->GetNumChildren(), 2); Expr* op1 = e->children()[0]; Expr* op2 = e->children()[1]; TimestampValue* tv = reinterpret_cast(op1->GetValue(row)); - int* count = reinterpret_cast(op2->GetValue(row)); + int32_t* count = reinterpret_cast(op2->GetValue(row)); if (tv == NULL || count == NULL) return NULL; - if (tv->time_of_day().is_special()) return NULL; + if (tv->date().is_special()) return NULL; - date_duration d(*count); - TimestampValue value(tv->date() - d, tv->time_of_day()); + UNIT unit(*count); + ptime p(tv->date(), tv->time_of_day()); + TimestampValue value(is_add ? p + unit : p - unit); e->result_.timestamp_val = value; return &e->result_.timestamp_val; diff --git a/be/src/exprs/timestamp-functions.h b/be/src/exprs/timestamp-functions.h index 21d18e03a..cf3f57f46 100644 --- a/be/src/exprs/timestamp-functions.h +++ b/be/src/exprs/timestamp-functions.h @@ -30,12 +30,38 @@ class TimestampFunctions { static void* Minute(Expr* e, TupleRow* row); static void* Second(Expr* e, TupleRow* row); - // Date functions. + // Date/time functions. static void* Now(Expr* e, TupleRow* row); static void* ToDate(Expr* e, TupleRow* row); - static void* DateAdd(Expr* e, TupleRow* row); - static void* DateSub(Expr* e, TupleRow* row); static void* DateDiff(Expr* e, TupleRow* row); + static void* YearsAdd(Expr* e, TupleRow* row); + static void* YearsSub(Expr* e, TupleRow* row); + static void* MonthsAdd(Expr* e, TupleRow* row); + static void* MonthsSub(Expr* e, TupleRow* row); + static void* WeeksAdd(Expr* e, TupleRow* row); + static void* WeeksSub(Expr* e, TupleRow* row); + static void* DaysAdd(Expr* e, TupleRow* row); + static void* DaysSub(Expr* e, TupleRow* row); + static void* HoursAdd(Expr* e, TupleRow* row); + static void* HoursSub(Expr* e, TupleRow* row); + static void* MinutesAdd(Expr* e, TupleRow* row); + static void* MinutesSub(Expr* e, TupleRow* row); + static void* SecondsAdd(Expr* e, TupleRow* row); + static void* SecondsSub(Expr* e, TupleRow* row); + static void* MillisAdd(Expr* e, TupleRow* row); + static void* MillisSub(Expr* e, TupleRow* row); + static void* MicrosAdd(Expr* e, TupleRow* row); + static void* MicrosSub(Expr* e, TupleRow* row); + static void* NanosAdd(Expr* e, TupleRow* row); + static void* NanosSub(Expr* e, TupleRow* row); + + // Helper for add/sub functions on the date portion. + template + static void* TimestampDateOp(Expr* e, TupleRow* row, bool is_add); + + // Helper for add/sub functions on the time portion. + template + static void* TimestampTimeOp(Expr* e, TupleRow* row, bool is_add); // Convert a timestamp to or from a particular timezone based time. static void* FromUtc(Expr* e, TupleRow* row); @@ -56,6 +82,7 @@ class TimezoneDatabase { static boost::local_time::tz_database tz_database_; static std::vector tz_region_list_; }; + } #endif diff --git a/common/function-registry/impala_functions.py b/common/function-registry/impala_functions.py index 2d6e883af..08d5944d7 100755 --- a/common/function-registry/impala_functions.py +++ b/common/function-registry/impala_functions.py @@ -123,10 +123,46 @@ functions = [ ['Timestamp_now', 'TIMESTAMP', [], 'TimestampFunctions::Now', ['now']], ['Timestamp_to_date', 'STRING', ['TIMESTAMP'], \ 'TimestampFunctions::ToDate', ['to_date']], - ['Timestamp_date_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ - 'TimestampFunctions::DateAdd', ['date_add']], - ['Timestamp_date_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ - 'TimestampFunctions::DateSub', ['date_sub']], + ['Timestamp_years_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::YearsAdd', ['years_add']], + ['Timestamp_years_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::YearsSub', ['years_sub']], + ['Timestamp_months_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MonthsAdd', ['months_add']], + ['Timestamp_months_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MonthsSub', ['months_sub']], + ['Timestamp_weeks_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::WeeksAdd', ['weeks_add']], + ['Timestamp_weeks_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::WeeksSub', ['weeks_sub']], + ['Timestamp_days_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::DaysAdd', ['days_add', 'date_add', 'adddate']], + ['Timestamp_days_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::DaysSub', ['days_sub', 'date_sub', 'subdate']], + ['Timestamp_hours_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::HoursAdd', ['hours_add']], + ['Timestamp_hours_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::HoursSub', ['hours_sub']], + ['Timestamp_minutes_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MinutesAdd', ['minutes_add']], + ['Timestamp_minutes_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MinutesSub', ['minutes_sub']], + ['Timestamp_seconds_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::SecondsAdd', ['seconds_add']], + ['Timestamp_seconds_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::SecondsSub', ['seconds_sub']], + ['Timestamp_milliseconds_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MillisAdd', ['milliseconds_add']], + ['Timestamp_milliseconds_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MillisSub', ['milliseconds_sub']], + ['Timestamp_microseconds_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MicrosAdd', ['microseconds_add']], + ['Timestamp_microseconds_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::MicrosSub', ['microseconds_sub']], + ['Timestamp_nanoseconds_add', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::NanosAdd', ['nanoseconds_add']], + ['Timestamp_nanoseconds_sub', 'TIMESTAMP', ['TIMESTAMP', 'INT'], \ + 'TimestampFunctions::NanosSub', ['nanoseconds_sub']], ['Timestamp_diff', 'INT', ['TIMESTAMP', 'TIMESTAMP'], \ 'TimestampFunctions::DateDiff', ['datediff']], ['From_utc_timestamp', 'TIMESTAMP', ['TIMESTAMP', 'STRING'], \ diff --git a/fe/src/main/cup/sql-parser.y b/fe/src/main/cup/sql-parser.y index c3e51b3dc..38d9632c9 100644 --- a/fe/src/main/cup/sql-parser.y +++ b/fe/src/main/cup/sql-parser.y @@ -140,7 +140,7 @@ terminal KW_AND, KW_ALL, KW_AS, KW_ASC, KW_AVG, KW_BETWEEN, KW_BIGINT, KW_BOOLEA KW_MAX, KW_NOT, KW_NULL, KW_ON, KW_OR, KW_ORDER, KW_OUTER, KW_REGEXP, KW_RLIKE, KW_RIGHT, KW_SELECT, KW_SEMI, KW_SMALLINT, KW_STRING, KW_SUM, KW_TINYINT, KW_TRUE, KW_UNION, KW_USING, KW_WHEN, KW_WHERE, KW_THEN, KW_TIMESTAMP, - KW_INSERT, KW_INTO, KW_OVERWRITE, KW_TABLE, KW_PARTITION; + KW_INSERT, KW_INTO, KW_OVERWRITE, KW_TABLE, KW_PARTITION, KW_INTERVAL; terminal COMMA, DOT, STAR, LPAREN, RPAREN, DIVIDE, MOD, ADD, SUBTRACT; terminal BITAND, BITOR, BITXOR, BITNOT; terminal EQUAL, NOT, LESSTHAN, GREATERTHAN; @@ -165,7 +165,7 @@ nonterminal SelectList select_clause; nonterminal SelectList select_list; nonterminal SelectListItem select_list_item; nonterminal SelectListItem star_expr ; -nonterminal Expr expr, arithmetic_expr; +nonterminal Expr expr, arithmetic_expr, timestamp_arithmetic_expr; nonterminal ArrayList expr_list; nonterminal ArrayList func_arg_list; nonterminal String alias_clause; @@ -213,6 +213,8 @@ precedence left BITAND, BITOR, BITXOR, BITNOT; precedence left KW_ORDER, KW_BY, KW_LIMIT; precedence left RPAREN; precedence left KW_IN; +// Support chaining of timestamp arithmetic exprs. +precedence left KW_INTERVAL; start with insert_or_query_stmt; @@ -413,7 +415,7 @@ select_list_item ::= | predicate:p alias_clause:alias {: RESULT = new SelectListItem(p, alias); :} | predicate:p - {: RESULT = new SelectListItem(p, null); :} + {: RESULT = new SelectListItem(p, null); :} | star_expr:expr {: RESULT = expr; :} ; @@ -678,7 +680,7 @@ expr ::= subtract_chain_expr:e {: RESULT = e; :} | literal:l - {: RESULT = l; :} + {: RESULT = l; :} | IDENT:functionName LPAREN RPAREN {: RESULT = new FunctionCallExpr(functionName, new ArrayList()); :} | IDENT:functionName LPAREN func_arg_list:exprs RPAREN @@ -691,10 +693,12 @@ expr ::= {: RESULT = a; :} | column_ref:c {: RESULT = c; :} - | arithmetic_expr:e + | timestamp_arithmetic_expr:e + {: RESULT = e; :} + | arithmetic_expr:e {: RESULT = e; :} | LPAREN expr:e RPAREN - {: RESULT = e; :} + {: RESULT = e; :} ; func_arg_list ::= @@ -735,6 +739,46 @@ arithmetic_expr ::= {: RESULT = new ArithmeticExpr(ArithmeticExpr.Operator.BITNOT, e, null); :} ; +// We use IDENT for the temporal unit to avoid making DAY, YEAR, etc. keywords. +// This way we do not need to change existing uses of IDENT. +// We chose not to make DATE_ADD and DATE_SUB keywords for the same reason. +timestamp_arithmetic_expr ::= + KW_INTERVAL expr:v IDENT:u ADD expr:t + {: RESULT = new TimestampArithmeticExpr(ArithmeticExpr.Operator.ADD, t, v, u, true); :} + | expr:t ADD KW_INTERVAL expr:v IDENT:u + {: + RESULT = new TimestampArithmeticExpr(ArithmeticExpr.Operator.ADD, t, v, u, false); + :} + // Set precedence to KW_INTERVAL (which is higher than ADD) for chaining. + %prec KW_INTERVAL + | expr:t SUBTRACT KW_INTERVAL expr:v IDENT:u + {: + RESULT = + new TimestampArithmeticExpr(ArithmeticExpr.Operator.SUBTRACT, t, v, u, false); + :} + // Set precedence to KW_INTERVAL (which is higher than ADD) for chaining. + %prec KW_INTERVAL + // Timestamp arithmetic expr that looks like a function call. + // We use func_arg_list instead of expr to avoid a shift/reduce conflict with + // func_arg_list on COMMA, and report an error if the list contains more than one expr. + | IDENT:functionName LPAREN func_arg_list:l COMMA KW_INTERVAL expr:v IDENT:u RPAREN + {: + if (l.size() > 1) { + // Report parsing failure on keyword interval. + Symbol errorToken = parser.getSymbolFactory().newSymbol("interval", + SqlParserSymbols.KW_INTERVAL, + ((Symbol) CUP$SqlParser$stack.peek()), + ((Symbol) CUP$SqlParser$stack.peek()), RESULT); + // Call syntax error to gather information about expected tokens, etc. + // syntax_error does not throw an exception + parser.syntax_error(errorToken); + // Unrecovered_syntax_error throws an exception and will terminate parsing + parser.unrecovered_syntax_error(errorToken); + } + RESULT = new TimestampArithmeticExpr(functionName, l.get(0), v, u); + :} + ; + literal ::= INTEGER_LITERAL:l {: RESULT = new IntLiteral(l); :} diff --git a/fe/src/main/java/com/cloudera/impala/analysis/TimestampArithmeticExpr.java b/fe/src/main/java/com/cloudera/impala/analysis/TimestampArithmeticExpr.java new file mode 100644 index 000000000..283c3f364 --- /dev/null +++ b/fe/src/main/java/com/cloudera/impala/analysis/TimestampArithmeticExpr.java @@ -0,0 +1,264 @@ +// Copyright (c) 2011 Cloudera, Inc. All rights reserved. + +package com.cloudera.impala.analysis; + +import java.util.HashMap; +import java.util.Map; + +import com.cloudera.impala.analysis.ArithmeticExpr.Operator; +import com.cloudera.impala.catalog.PrimitiveType; +import com.cloudera.impala.common.AnalysisException; +import com.cloudera.impala.thrift.TExprNode; +import com.cloudera.impala.thrift.TExprNodeType; +import com.cloudera.impala.thrift.TExprOpcode; +import com.google.common.base.Preconditions; + +/** + * Describes the addition and subtraction of time units from timestamps. + * Arithmetic expressions on timestamps are syntactic sugar. + * They are executed as function call exprs in the BE. + */ +public class TimestampArithmeticExpr extends Expr { + + // Time units supported in timestamp arithmetic. + public static enum TimeUnit { + YEAR("YEAR"), + MONTH("MONTH"), + WEEK("WEEK"), + DAY("DAY"), + HOUR("HOUR"), + MINUTE("MINUTE"), + SECOND("SECOND"), + MILLISECOND("MILLISECOND"), + MICROSECOND("MICROSECOND"), + NANOSECOND("NANOSECOND"); + + private final String description; + + private TimeUnit(String description) { + this.description = description; + } + + @Override + public String toString() { + return description; + } + } + + private static Map TIME_UNITS_MAP = new HashMap(); + static { + for (TimeUnit timeUnit : TimeUnit.values()) { + TIME_UNITS_MAP.put(timeUnit.toString(), timeUnit); + TIME_UNITS_MAP.put(timeUnit.toString() + "S", timeUnit); + } + } + + // Set for function call-like arithmetic. + private final String funcName; + private ArithmeticExpr.Operator op; + + // Keep the original string passed in the c'tor to resolve + // ambiguities with other uses of IDENT during query parsing. + private final String timeUnitIdent; + private TimeUnit timeUnit; + + // Indicates an expr where the interval comes first, e.g., 'interval b year + a'. + private final boolean intervalFirst; + + // C'tor for function-call like arithmetic, e.g., 'date_add(a, interval b year)'. + public TimestampArithmeticExpr(String funcName, Expr e1, Expr e2, + String timeUnitIdent) { + this.funcName = funcName; + this.timeUnitIdent = timeUnitIdent; + this.intervalFirst = false; + children.add(e1); + children.add(e2); + } + + // C'tor for non-function-call like arithmetic, e.g., 'a + interval b year'. + // e1 always refers to the timestamp to be added/subtracted from, and e2 + // to the time value (even in the interval-first case). + public TimestampArithmeticExpr(ArithmeticExpr.Operator op, Expr e1, Expr e2, + String timeUnitIdent, boolean intervalFirst) { + Preconditions.checkState(op == Operator.ADD || op == Operator.SUBTRACT); + this.funcName = null; + this.op = op; + this.timeUnitIdent = timeUnitIdent; + this.intervalFirst = intervalFirst; + children.add(e1); + children.add(e2); + } + + @Override + public void analyze(Analyzer analyzer) throws AnalysisException { + super.analyze(analyzer); + + // Check if name of function call is date_sub or date_add. + if (funcName != null) { + if (funcName.toUpperCase().equals("DATE_ADD")) { + op = ArithmeticExpr.Operator.ADD; + } else if (funcName.toUpperCase().equals("DATE_SUB")) { + op = ArithmeticExpr.Operator.SUBTRACT; + } else { + throw new AnalysisException("Encountered function name '" + funcName + + "' in timestamp arithmetic expression '" + toSql() + "'. " + + "Expected function name 'DATE_ADD' or 'DATE_SUB'."); + } + } + timeUnit = TIME_UNITS_MAP.get(timeUnitIdent.toUpperCase()); + if (timeUnit == null) { + throw new AnalysisException("Invalid time unit '" + timeUnitIdent + + "' in timestamp arithmetic expression '" + toSql() + "'."); + } + + // The first child must return a timestamp. + if (getChild(0).getType() != PrimitiveType.TIMESTAMP) { + throw new AnalysisException("Operand '" + getChild(0).toSql() + + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" + + getChild(0).getType() + "'. Expected type 'TIMESTAMP'."); + } + + // The second child must be of type 'INT' or castable to it. + if (getChild(1).getType() != PrimitiveType.INT) { + if (PrimitiveType.isImplicitlyCastable(getChild(1).getType(), PrimitiveType.INT)) { + castChild(PrimitiveType.INT, 1); + } else { + throw new AnalysisException("Operand '" + getChild(1).toSql() + + "' of timestamp arithmetic expression '" + toSql() + "' returns type '" + + getChild(1).getType() + "' which is incompatible with expected type 'INT'."); + } + } + + type = PrimitiveType.TIMESTAMP; + opcode = getOpCode(); + } + + @Override + protected void toThrift(TExprNode msg) { + msg.node_type = TExprNodeType.FUNCTION_CALL; + msg.setOpcode(opcode); + } + + public String getTimeUnitIdent() { + return timeUnitIdent; + } + + public TimeUnit getTimeUnit() { + return timeUnit; + } + + public ArithmeticExpr.Operator getOp() { + return op; + } + + private TExprOpcode getOpCode() { + // Select appropriate opcode based on op and timeUnit. + switch (timeUnit) { + case YEAR: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_YEARS_ADD; + } else { + return TExprOpcode.TIMESTAMP_YEARS_SUB; + } + } + case MONTH: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_MONTHS_ADD; + } else { + return TExprOpcode.TIMESTAMP_MONTHS_SUB; + } + } + case WEEK: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_WEEKS_ADD; + } else { + return TExprOpcode.TIMESTAMP_WEEKS_SUB; + } + } + case DAY: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_DAYS_ADD; + } else { + return TExprOpcode.TIMESTAMP_DAYS_SUB; + } + } + case HOUR: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_HOURS_ADD; + } else { + return TExprOpcode.TIMESTAMP_HOURS_SUB; + } + } + case MINUTE: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_MINUTES_ADD; + } else { + return TExprOpcode.TIMESTAMP_MINUTES_SUB; + } + } + case SECOND: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_SECONDS_ADD; + } else { + return TExprOpcode.TIMESTAMP_SECONDS_SUB; + } + } + case MILLISECOND: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_MILLISECONDS_ADD; + } else { + return TExprOpcode.TIMESTAMP_MILLISECONDS_SUB; + } + } + case MICROSECOND: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_MICROSECONDS_ADD; + } else { + return TExprOpcode.TIMESTAMP_MICROSECONDS_SUB; + } + } + case NANOSECOND: { + if (op == Operator.ADD) { + return TExprOpcode.TIMESTAMP_NANOSECONDS_ADD; + } else { + return TExprOpcode.TIMESTAMP_NANOSECONDS_SUB; + } + } + default: { + Preconditions.checkState(false, "Unexpected time unit '" + timeUnit + "'."); + } + } + return null; + } + + @Override + public String toSql() { + StringBuilder strBuilder = new StringBuilder(); + if (funcName != null) { + // Function-call like version. + strBuilder.append(funcName + "("); + strBuilder.append(getChild(0).toSql() + ", "); + strBuilder.append("INTERVAL "); + strBuilder.append(getChild(1).toSql()); + strBuilder.append(" " + timeUnitIdent); + strBuilder.append(")"); + return strBuilder.toString(); + } + if (intervalFirst) { + // Non-function-call like version with interval as first operand. + strBuilder.append("INTERVAL "); + strBuilder.append(getChild(1).toSql() + " "); + strBuilder.append(timeUnitIdent); + strBuilder.append(" " + op.toString() + " "); + strBuilder.append(getChild(0).toSql()); + } else { + // Non-function-call like version with interval as second operand. + strBuilder.append(getChild(0).toSql()); + strBuilder.append(" " + op.toString() + " "); + strBuilder.append("INTERVAL "); + strBuilder.append(getChild(1).toSql() + " "); + strBuilder.append(timeUnitIdent); + } + return strBuilder.toString(); + } +} diff --git a/fe/src/main/jflex/sql-scanner.flex b/fe/src/main/jflex/sql-scanner.flex index 29fcfea3d..fde012b5b 100644 --- a/fe/src/main/jflex/sql-scanner.flex +++ b/fe/src/main/jflex/sql-scanner.flex @@ -68,6 +68,7 @@ import com.cloudera.impala.analysis.SqlParserSymbols; keywordMap.put("in", new Integer(SqlParserSymbols.KW_IN)); keywordMap.put("inner", new Integer(SqlParserSymbols.KW_INNER)); keywordMap.put("insert", new Integer(SqlParserSymbols.KW_INSERT)); + keywordMap.put("interval", new Integer(SqlParserSymbols.KW_INTERVAL)); keywordMap.put("into", new Integer(SqlParserSymbols.KW_INTO)); keywordMap.put("join", new Integer(SqlParserSymbols.KW_JOIN)); keywordMap.put("int", new Integer(SqlParserSymbols.KW_INT)); diff --git a/fe/src/test/java/com/cloudera/impala/analysis/AnalyzerTest.java b/fe/src/test/java/com/cloudera/impala/analysis/AnalyzerTest.java index b70ccecac..fc069a05a 100644 --- a/fe/src/test/java/com/cloudera/impala/analysis/AnalyzerTest.java +++ b/fe/src/test/java/com/cloudera/impala/analysis/AnalyzerTest.java @@ -20,6 +20,7 @@ import org.junit.Test; import org.slf4j.Logger; import org.slf4j.LoggerFactory; +import com.cloudera.impala.analysis.TimestampArithmeticExpr.TimeUnit; import com.cloudera.impala.catalog.Catalog; import com.cloudera.impala.catalog.PrimitiveType; import com.cloudera.impala.catalog.TestSchemaUtils; @@ -1192,6 +1193,122 @@ public class AnalyzerTest { "Arithmetic operation requires numeric or string operands"); } + /** + * We have three variants of timestamp arithmetic exprs, as in MySQL: + * http://dev.mysql.com/doc/refman/5.5/en/date-and-time-functions.html + * (section #function_date-add) + * 1. Non-function-call like version, e.g., 'a + interval b timeunit' + * 2. Beginning with an interval (only for '+'), e.g., 'interval b timeunit + a' + * 3. Function-call like version, e.g., date_add(a, interval b timeunit) + */ + @Test + public void TestTimestampArithmeticExpressions() { + String[] valueTypeCols = + new String[] { "tinyint_col", "smallint_col", "int_col" }; + + // Tests all time units. + for (TimeUnit timeUnit : TimeUnit.values()) { + // Tests on all valid time value types (fixed points). + for (String col : valueTypeCols) { + // Non-function call like version. + AnalyzesOk("select timestamp_col + interval " + col + " " + timeUnit.toString() + + " from alltypes"); + AnalyzesOk("select timestamp_col - interval " + col + " " + timeUnit.toString() + + " from alltypes"); + // Reversed interval and timestamp using addition. + AnalyzesOk("select interval " + col + " " + timeUnit.toString() + + " + timestamp_col from alltypes"); + // Function-call like version. + AnalyzesOk("select date_add(timestamp_col, interval " + col + " " + + timeUnit.toString() + ") from alltypes"); + AnalyzesOk("select date_sub(timestamp_col, interval " + col + " " + + timeUnit.toString() + ") from alltypes"); + } + } + + // First operand does not return a timestamp. Non-function-call like version. + AnalysisError("select float_col + interval 10 years from alltypes", + "Operand 'float_col' of timestamp arithmetic expression " + + "'float_col + INTERVAL 10 years' returns type 'FLOAT'. " + + "Expected type 'TIMESTAMP'."); + AnalysisError("select string_col + interval 10 years from alltypes", + "Operand 'string_col' of timestamp arithmetic expression " + + "'string_col + INTERVAL 10 years' returns type 'STRING'. " + + "Expected type 'TIMESTAMP'."); + // Reversed interval and timestamp using addition. + AnalysisError("select interval 10 years + float_col from alltypes", + "Operand 'float_col' of timestamp arithmetic expression " + + "'INTERVAL 10 years + float_col' returns type 'FLOAT'. " + + "Expected type 'TIMESTAMP'"); + AnalysisError("select interval 10 years + string_col from alltypes", + "Operand 'string_col' of timestamp arithmetic expression " + + "'INTERVAL 10 years + string_col' returns type 'STRING'. " + + "Expected type 'TIMESTAMP'"); + // First operand does not return a timestamp. Function-call like version. + AnalysisError("select date_add(float_col, interval 10 years) from alltypes", + "Operand 'float_col' of timestamp arithmetic expression " + + "'date_add(float_col, INTERVAL 10 years)' returns type 'FLOAT'. " + + "Expected type 'TIMESTAMP'."); + AnalysisError("select date_add(string_col, interval 10 years) from alltypes", + "Operand 'string_col' of timestamp arithmetic expression " + + "'date_add(string_col, INTERVAL 10 years)' returns type 'STRING'. " + + "Expected type 'TIMESTAMP'."); + + // Second operand is not compatible with type INT. Non-function-call like version. + AnalysisError("select timestamp_col + interval 5.2 years from alltypes", + "Operand '5.2' of timestamp arithmetic expression " + + "'timestamp_col + INTERVAL 5.2 years' returns type 'DOUBLE' " + + "which is incompatible with expected type 'INT'."); + AnalysisError("select timestamp_col + interval bigint_col years from alltypes", + "Operand 'bigint_col' of timestamp arithmetic expression " + + "'timestamp_col + INTERVAL bigint_col years' returns type 'BIGINT' " + + "which is incompatible with expected type 'INT'."); + // Implicit cast from STRING to INT. + AnalyzesOk("select timestamp_col + interval '10' years from alltypes"); + // Reversed interval and timestamp using addition. + AnalysisError("select interval 5.2 years + timestamp_col from alltypes", + "Operand '5.2' of timestamp arithmetic expression " + + "'INTERVAL 5.2 years + timestamp_col' returns type 'DOUBLE' " + + "which is incompatible with expected type 'INT'."); + AnalysisError("select interval bigint_col years + timestamp_col from alltypes", + "Operand 'bigint_col' of timestamp arithmetic expression " + + "'INTERVAL bigint_col years + timestamp_col' returns type 'BIGINT' " + + "which is incompatible with expected type 'INT'."); + // Implicit cast from STRING to INT. + AnalyzesOk("select interval '10' years + timestamp_col from alltypes"); + // Second operand is not compatible with type INT. Function-call like version. + AnalysisError("select date_add(timestamp_col, interval 5.2 years) from alltypes", + "Operand '5.2' of timestamp arithmetic expression " + + "'date_add(timestamp_col, INTERVAL 5.2 years)' returns type 'DOUBLE' " + + "which is incompatible with expected type 'INT'."); + AnalysisError("select date_add(timestamp_col, interval bigint_col years) " + + "from alltypes", + "Operand 'bigint_col' of timestamp arithmetic expression " + + "'date_add(timestamp_col, INTERVAL bigint_col years)' returns type 'BIGINT' " + + "which is incompatible with expected type 'INT'."); + // Implicit cast from STRING to INT. + AnalyzesOk("select date_add(timestamp_col, interval '10' years) from alltypes"); + + // Invalid time unit. Non-function-call like version. + AnalysisError("select timestamp_col + interval 10 error from alltypes", + "Invalid time unit 'error' in timestamp arithmetic expression " + + "'timestamp_col + INTERVAL 10 error'."); + AnalysisError("select timestamp_col - interval 10 error from alltypes", + "Invalid time unit 'error' in timestamp arithmetic expression " + + "'timestamp_col - INTERVAL 10 error'."); + // Reversed interval and timestamp using addition. + AnalysisError("select interval 10 error + timestamp_col from alltypes", + "Invalid time unit 'error' in timestamp arithmetic expression " + + "'INTERVAL 10 error + timestamp_col'."); + // Invalid time unit. Function-call like version. + AnalysisError("select date_add(timestamp_col, interval 10 error) from alltypes", + "Invalid time unit 'error' in timestamp arithmetic expression " + + "'date_add(timestamp_col, INTERVAL 10 error)'."); + AnalysisError("select date_sub(timestamp_col, interval 10 error) from alltypes", + "Invalid time unit 'error' in timestamp arithmetic expression " + + "'date_sub(timestamp_col, INTERVAL 10 error)'."); + } + @Test public void TestNestedFunctions() throws AnalysisException { AnalyzesOk("select sin(pi())"); diff --git a/fe/src/test/java/com/cloudera/impala/analysis/ParserTest.java b/fe/src/test/java/com/cloudera/impala/analysis/ParserTest.java index 652d4618c..09a9e57da 100644 --- a/fe/src/test/java/com/cloudera/impala/analysis/ParserTest.java +++ b/fe/src/test/java/com/cloudera/impala/analysis/ParserTest.java @@ -10,12 +10,15 @@ import java.io.StringReader; import org.junit.Test; +import com.cloudera.impala.analysis.TimestampArithmeticExpr.TimeUnit; + public class ParserTest { /** * Asserts in case of parser error. * @param stmt + * @return parse result */ - public void ParsesOk(String stmt) { + public Object ParsesOk(String stmt) { SqlScanner input = new SqlScanner(new StringReader(stmt)); SqlParser parser = new SqlParser(input); Object result = null; @@ -26,6 +29,7 @@ public class ParserTest { fail("\n" + parser.getErrorMsg(stmt)); } assertNotNull(result); + return result; } /** @@ -353,6 +357,51 @@ public class ParserTest { ParserError("select a ~ a from t"); } + /** + * We have three variants of timestamp arithmetic exprs, as in MySQL: + * http://dev.mysql.com/doc/refman/5.5/en/date-and-time-functions.html + * (section #function_date-add) + * 1. Non-function-call like version, e.g., 'a + interval b timeunit' + * 2. Beginning with an interval (only for '+'), e.g., 'interval b timeunit + a' + * 3. Function-call like version, e.g., date_add(a, interval b timeunit) + */ + @Test public void TestTimestampArithmeticExprs() { + // Tests all valid time units. + for (TimeUnit timeUnit : TimeUnit.values()) { + // Non-function call like versions. + ParsesOk("select a + interval b " + timeUnit.toString()); + ParsesOk("select a - interval b " + timeUnit.toString()); + // Reversed interval and timestamp is ok for addition. + ParsesOk("select interval b " + timeUnit.toString() + " + a"); + // Reversed interval and timestamp is an error for subtraction. + ParserError("select interval b " + timeUnit.toString() + " - a"); + // Function-call like versions. + ParsesOk("select date_add(a, interval b " + timeUnit.toString() + ")"); + ParsesOk("select date_sub(a, interval b " + timeUnit.toString() + ")"); + // Invalid function name for timestamp arithmetic expr should parse ok. + ParsesOk("select error(a, interval b " + timeUnit.toString() + ")"); + // Invalid time unit parses ok. + ParsesOk("select error(a, interval b error)"); + // Missing 'interval' keyword. Note that the non-function-call like version will + // pass without 'interval' because the time unit is recognized as an alias. + ParserError("select date_add(a, b " + timeUnit.toString() + ")"); + ParserError("select date_sub(a, b " + timeUnit.toString() + ")"); + } + + // Test chained timestamp arithmetic exprs. + ParsesOk("select a + interval b years + interval c months + interval d days"); + ParsesOk("select a - interval b years - interval c months - interval d days"); + ParsesOk("select a + interval b years - interval c months + interval d days"); + // Starting with interval. + ParsesOk("select interval b years + a + interval c months + interval d days"); + ParsesOk("select interval b years + a - interval c months - interval d days"); + ParsesOk("select interval b years + a - interval c months + interval d days"); + + // To many arguments. + ParserError("select date_sub(a, c, interval b year)"); + ParserError("select date_sub(a, interval b year, c)"); + } + @Test public void TestCaseExprs() { // Test regular exps. ParsesOk("select case a when '5' then x when '6' then y else z end from t"); @@ -575,7 +624,7 @@ public class ParserTest { " ^\n" + "Encountered: FROM\n" + "Expected: AVG, CASE, CAST, COUNT, DISTINCT, DISTINCTPC, " + - "DISTINCTPCSA, FALSE, MIN, MAX, NOT, NULL, SUM, TRUE, IDENTIFIER\n"); + "DISTINCTPCSA, FALSE, MIN, MAX, NOT, NULL, SUM, TRUE, INTERVAL, IDENTIFIER\n"); // missing from ParserError("select c, b, c where a = 5", @@ -601,7 +650,7 @@ public class ParserTest { " ^\n" + "Encountered: EOF\n" + "Expected: AVG, CASE, CAST, COUNT, DISTINCTPC, DISTINCTPCSA, " + - "FALSE, MIN, MAX, NOT, NULL, SUM, TRUE, IDENTIFIER\n"); + "FALSE, MIN, MAX, NOT, NULL, SUM, TRUE, INTERVAL, IDENTIFIER\n"); // missing predicate in where clause (group by) ParserError("select c, b, c from t where group by a, b", @@ -610,7 +659,7 @@ public class ParserTest { " ^\n" + "Encountered: GROUP\n" + "Expected: AVG, CASE, CAST, COUNT, DISTINCTPC, DISTINCTPCSA, " + - "FALSE, MIN, MAX, NOT, NULL, SUM, TRUE, IDENTIFIER\n"); + "FALSE, MIN, MAX, NOT, NULL, SUM, TRUE, INTERVAL, IDENTIFIER\n"); // unmatched string literal starting with " ParserError("select c, \"b, c from t", diff --git a/testdata/workloads/functional-query/queries/QueryTest/exprs.test b/testdata/workloads/functional-query/queries/QueryTest/exprs.test index 01534d498..42b05ac29 100644 --- a/testdata/workloads/functional-query/queries/QueryTest/exprs.test +++ b/testdata/workloads/functional-query/queries/QueryTest/exprs.test @@ -819,4 +819,285 @@ timestamp, timestamp ---- RESULTS // Matches two identical timestamps separated by commas. regex: (\d{4}-\d{2}-\d{2}\s\d{2}:\d{2}:\d{2}(\.\d{9})?),\1 +==== +# Timestamp arithmetic tests (lowest timestamp_col has value 2009-01-01 00:00:00). +# Add/sub years, non-function-call like version. +select timestamp_col + interval 10 years, + interval 10 years + timestamp_col, + timestamp_col - interval 10 years +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2019-01-01 00:00:00,2019-01-01 00:00:00,1999-01-01 00:00:00 +==== +# Add/sub years, function-call like version. +select date_add(timestamp_col, interval 10 years), + date_sub(timestamp_col, interval 10 years) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2019-01-01 00:00:00,1999-01-01 00:00:00 +==== +# Add/sub months, non-function-call like version. +select timestamp_col + interval 13 months, + timestamp_col + interval 1 month, + interval 13 months + timestamp_col, + interval 1 month + timestamp_col, + timestamp_col - interval 13 months, + timestamp_col - interval 1 month +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp,timestamp,timestamp +---- RESULTS +2010-02-01 00:00:00,2009-02-01 00:00:00,2010-02-01 00:00:00,2009-02-01 00:00:00,2007-12-01 00:00:00,2008-12-01 00:00:00 +==== +# Add/sub months, function-call like version. +select date_add(timestamp_col, interval 13 months), + date_add(timestamp_col, interval 1 month), + date_sub(timestamp_col, interval 13 months), + date_sub(timestamp_col, interval 1 month) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp +---- RESULTS +2010-02-01 00:00:00,2009-02-01 00:00:00,2007-12-01 00:00:00,2008-12-01 00:00:00 +==== +# Add/sub weeks, non-function-call like version. +select timestamp_col + interval 2 weeks, + timestamp_col + interval 53 weeks, + interval 2 weeks + timestamp_col, + interval 53 weeks + timestamp_col, + timestamp_col - interval 2 weeks, + timestamp_col - interval 53 weeks +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp,timestamp,timestamp +---- RESULTS +2009-01-15 00:00:00,2010-01-07 00:00:00,2009-01-15 00:00:00,2010-01-07 00:00:00,2008-12-18 00:00:00,2007-12-27 00:00:00 +==== +# Add/sub weeks, function-call like version. +select date_add(timestamp_col, interval 2 weeks), + date_add(timestamp_col, interval 53 weeks), + date_sub(timestamp_col, interval 2 weeks), + date_sub(timestamp_col, interval 53 weeks) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp +---- RESULTS +2009-01-15 00:00:00,2010-01-07 00:00:00,2008-12-18 00:00:00,2007-12-27 00:00:00 +==== +# Add/sub days, non-function-call like version. +select timestamp_col + interval 10 days, + timestamp_col + interval 10 days, + interval 10 days + timestamp_col, + interval 10 days + timestamp_col, + timestamp_col - interval 10 days, + timestamp_col - interval 365 days +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp,timestamp,timestamp +---- RESULTS +2009-01-11 00:00:00,2009-01-11 00:00:00,2009-01-11 00:00:00,2009-01-11 00:00:00,2008-12-22 00:00:00,2008-01-02 00:00:00 +==== +# Add/sub days, function-call like version. +select date_add(timestamp_col, interval 10 days), + date_add(timestamp_col, interval 10 days), + date_sub(timestamp_col, interval 10 days), + date_sub(timestamp_col, interval 365 days) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp +---- RESULTS +2009-01-11 00:00:00,2009-01-11 00:00:00,2008-12-22 00:00:00,2008-01-02 00:00:00 +==== +# Add/sub hours, non-function-call like version. +select timestamp_col + interval 25 hours, + interval 25 hours + timestamp_col, + timestamp_col - interval 25 hours +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2009-01-02 01:00:00,2009-01-02 01:00:00,2008-12-30 23:00:00 +==== +# Add/sub hours, function-call like version. +select date_add(timestamp_col, interval 25 hours), + date_sub(timestamp_col, interval 25 hours) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2009-01-02 01:00:00,2008-12-30 23:00:00 +==== +# Add/sub minutes (1533 minutes are 25h33m), non-function-call like version. +select timestamp_col + interval 1533 minutes, + interval 1533 minutes + timestamp_col, + timestamp_col - interval 1533 minutes +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2009-01-02 01:33:00,2009-01-02 01:33:00,2008-12-30 22:27:00 +==== +# Add/sub minutes (1533 minutes are 25h33m), function-call like version. +select date_add(timestamp_col, interval 1533 minutes), + date_sub(timestamp_col, interval 1533 minutes) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2009-01-02 01:33:00,2008-12-30 22:27:00 +==== +# Add/sub seconds (90033 seconds are 25h33s), non-function-call like version. +select timestamp_col + interval 90033 seconds, + interval 90033 seconds + timestamp_col, + timestamp_col - interval 90033 seconds +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2009-01-02 01:00:33,2009-01-02 01:00:33,2008-12-30 22:59:27 +==== +# Add/sub seconds (90033 seconds are 25h33s), function-call like version. +select date_add(timestamp_col, interval 90033 seconds), + date_sub(timestamp_col, interval 90033 seconds) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2009-01-02 01:00:33,2008-12-30 22:59:27 +==== +# Add/sub milliseconds (90000033 seconds are 25h33ms), non-function-call like version. +select timestamp_col + interval 90000033 milliseconds, + interval 90000033 milliseconds + timestamp_col, + timestamp_col - interval 90000033 milliseconds +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2009-01-02 01:00:00.033000000,2009-01-02 01:00:00.033000000,2008-12-30 22:59:59.967000000 +==== +# Add/sub milliseconds (90000033 seconds are 25h33ms), function-call like version. +select date_add(timestamp_col, interval 90000033 milliseconds), + date_sub(timestamp_col, interval 90000033 milliseconds) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2009-01-02 01:00:00.033000000,2008-12-30 22:59:59.967000000 +==== +# Add/sub microseconds, non-function-call like version. +select timestamp_col + interval 1033 microseconds, + interval 1033 microseconds + timestamp_col, + timestamp_col - interval 1033 microseconds +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2009-01-01 00:00:00.001033000,2009-01-01 00:00:00.001033000,2008-12-31 23:59:59.998967000 +==== +# Add/sub microseconds, function-call like version. +select date_add(timestamp_col, interval 1033 microseconds), + date_sub(timestamp_col, interval 1033 microseconds) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2009-01-01 00:00:00.001033000,2008-12-31 23:59:59.998967000 +==== +# Add/sub nanoseconds, non-function-call like version. +select timestamp_col + interval 1033 nanoseconds, + interval 1033 nanoseconds + timestamp_col, + timestamp_col - interval 1033 nanoseconds +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp +---- RESULTS +2009-01-01 00:00:00.000001033,2009-01-01 00:00:00.000001033,2008-12-31 23:59:59.999998967 +==== +# Add/sub nanoseconds, function-call like version. +select date_add(timestamp_col, interval 1033 nanoseconds), + date_sub(timestamp_col, interval 1033 nanoseconds) +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp +---- RESULTS +2009-01-01 00:00:00.000001033,2008-12-31 23:59:59.999998967 +==== +# Chaining of arithmetic operations (only non-function-call like version). +select timestamp_col + interval 10 years + interval 2 months + interval 5 days, + interval 10 years + timestamp_col + interval 2 months + interval 5 days, + timestamp_col + interval 10 years - interval 2 months + interval 5 days, + interval 10 years + timestamp_col - interval 2 months + interval 5 days, + timestamp_col - interval 10 years - interval 2 months - interval 5 days +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp,timestamp +---- RESULTS +2019-03-06 00:00:00,2019-03-06 00:00:00,2018-11-06 00:00:00,2018-11-06 00:00:00,1998-10-27 00:00:00 +==== +select timestamp_col + interval 10 hours + interval 2 minutes + interval 5 seconds + + interval 3 milliseconds + interval 3 microseconds + interval 3 nanoseconds, + interval 10 hours + timestamp_col + interval 2 minutes + interval 5 seconds + + interval 3 milliseconds + interval 3 microseconds + interval 3 nanoseconds, + timestamp_col + interval 10 hours - interval 2 minutes + interval 5 seconds + - interval 3 milliseconds + interval 3 microseconds - interval 3 nanoseconds, + interval 10 hours + timestamp_col + interval 2 minutes + interval 5 seconds + - interval 3 milliseconds + interval 3 microseconds - interval 3 nanoseconds, + timestamp_col - interval 10 hours - interval 2 minutes - interval 5 seconds + - interval 3 milliseconds - interval 3 microseconds - interval 3 nanoseconds +from alltypes$TABLE order by id limit 1 +---- TYPES +timestamp,timestamp,timestamp,timestamp,timestamp +---- RESULTS +2009-01-01 10:02:05.003003003,2009-01-01 10:02:05.003003003,2009-01-01 09:58:04.997002997,2009-01-01 10:02:04.997002997,2008-12-31 13:57:54.996996997 +==== +# Test corner cases and also timestamp arithmetic without from clause. +select cast("2012-02-29 00:00:00" as timestamp) + interval 1 year, + cast("2013-02-28 00:00:00" as timestamp) - interval 1 year, + cast("2012-01-01 00:00:00" as timestamp) + interval 365 days, + cast("2013-01-01 00:00:00" as timestamp) - interval 366 days +---- TYPES +timestamp,timestamp,timestamp,timestamp +---- RESULTS +2013-02-28 00:00:00,2012-02-29 00:00:00,2012-12-31 00:00:00,2012-01-01 00:00:00 +==== +# Test overflow (2147483647 is MAX_INT). +select cast("2012-01-01 00:00:00" as timestamp) + interval 2147483647 years, + cast("2012-01-01 00:00:00" as timestamp) - interval 2147483647 years +---- TYPES +timestamp,timestamp +---- RESULTS +2011-01-01 00:00:00,2013-01-01 00:00:00 +==== +# Timestamp arithmetic inside a predicate. +select year, month from alltypes$TABLE +where year = year((cast('2012-01-01 09:10:11' as timestamp) - interval 3 years)) +and month = month((cast('2012-01-01 09:10:11' as timestamp) + interval 3 months)) +limit 3 +---- TYPES +int,int +---- RESULTS +2009,4 +2009,4 +2009,4 +==== +# Test NULLs in second operand +select count(*) from alltypesagg$TABLE +where (cast('2012-01-01 09:10:11' as timestamp) + interval tinyint_col seconds) IS NULL +---- TYPES +bigint +---- RESULTS +1000 +==== +# Test NULLs in first operand +select count(*) from alltypesagg$TABLE +where (cast('2012-01-01 09:10:11' as timestamp) + interval tinyint_col seconds) + + interval 10 years IS NULL +---- TYPES +bigint +---- RESULTS +1000 ==== \ No newline at end of file