Skip to content
New issue

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

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

Already on GitHub? Sign in to your account

[CALCITE-6527] Add DATE_ADD function (enabled in Spark library) #3969

Open
wants to merge 1 commit into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -132,6 +132,16 @@ private SqlLibraryOperators() {
public static final SqlFunction DATEADD =
new SqlTimestampAddFunction("DATEADD");

/** The "DATE_ADD(start_date, num_days)" function
* (Spark) Returns the date that is num_days after start_date. */
@LibraryOperator(libraries = {SPARK})
public static final SqlFunction DATE_ADD_SPARK =
NobiGo marked this conversation as resolved.
Show resolved Hide resolved
SqlBasicFunction.create(SqlKind.DATE_ADD, ReturnTypes.DATE_NULLABLE,
OperandTypes.DATE_ANY)
.withFunctionType(SqlFunctionCategory.TIMEDATE);

/** The "ADD_MONTHS(start_date, num_months)" function
* (SPARK) Returns the date that is num_months after start_date. */
@LibraryOperator(libraries = {ORACLE, SPARK})
public static final SqlFunction ADD_MONTHS =
SqlBasicFunction.create(SqlKind.ADD_MONTHS, ReturnTypes.ARG0_NULLABLE,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -209,6 +209,8 @@ private StandardConvertletTable() {
new TimestampAddConvertlet());
registerOp(SqlLibraryOperators.ADD_MONTHS,
new TimestampAddConvertlet());
registerOp(SqlLibraryOperators.DATE_ADD_SPARK,
new TimestampAddConvertlet());
registerOp(SqlLibraryOperators.DATE_DIFF,
new TimestampDiffConvertlet());
registerOp(SqlLibraryOperators.DATE_SUB,
Expand Down Expand Up @@ -2134,6 +2136,57 @@ private static class SubstrConvertlet implements SqlRexConvertlet {
}
}

/**
* Handles the first parameter of the SQL call.
* Converts the first operand to a RexNode and casts it to DATE type if it is a TIMESTAMP.
*
* @param cx The SQL to Rex conversion context.
* @param rexBuilder The RexBuilder to create RexNode instances.
* @param call The SQL call containing the operands.
* @return The converted RexNode for the first parameter.
*/
private static RexNode handleFirstParameter(SqlRexContext cx, RexBuilder rexBuilder,
SqlCall call) {
RexNode opfirstparameter = cx.convertExpression(call.operand(0));
if (opfirstparameter.getType().getSqlTypeName() == SqlTypeName.TIMESTAMP) {
RelDataType timestampType = cx.getTypeFactory().createSqlType(SqlTypeName.DATE);
return rexBuilder.makeCast(timestampType, opfirstparameter);
} else {
return cx.convertExpression(call.operand(0));
}
}


/**
* Handles the second parameter of the SQL call.
* Converts the second operand to a RexNode and casts it to INTEGER type if it is a CHAR.
*
* @param cx The SQL to Rex conversion context.
* @param rexBuilder The RexBuilder to create RexNode instances.
* @param call The SQL call containing the operands.
* @return The converted RexNode for the second parameter.
*/
private static RexNode handleSecondParameter(SqlRexContext cx, RexBuilder rexBuilder,
SqlCall call) {
RexNode opsecondparameter = cx.convertExpression(call.operand(1));
RelDataTypeFactory typeFactory = cx.getTypeFactory();

// In Calcite, cast('1.2' as integer) is invalid.
// For details, see https://issues.apache.org/jira/browse/CALCITE-1439
// When trying to cast a string value to an integer type, Calcite may
// encounter errors if the string value cannot be successfully converted.
// To handle this, the string needs to be first converted to a double type,
// and then the double value can be converted to an integer type.
// Since the final target type is integer, converting the string to double first
// will not lose precision for the add_months operation.
if (opsecondparameter.getType().getSqlTypeName() == SqlTypeName.CHAR) {
RelDataType doubleType = typeFactory.createSqlType(SqlTypeName.DOUBLE);
opsecondparameter = rexBuilder.makeCast(doubleType, opsecondparameter);
}
RelDataType intType = typeFactory.createSqlType(SqlTypeName.INTEGER);
return rexBuilder.makeCast(intType, opsecondparameter);
}

/** Convertlet that handles the 3-argument {@code TIMESTAMPADD} function
* and the 2-argument BigQuery-style {@code TIMESTAMP_ADD} function. */
private static class TimestampAddConvertlet implements SqlRexConvertlet {
Expand All @@ -2149,34 +2202,16 @@ private static class TimestampAddConvertlet implements SqlRexConvertlet {
final RexNode op2;
switch (call.operandCount()) {
case 2:
// Oracle-style 'ADD_MONTHS(date, integer months)'
if (call.getOperator() == SqlLibraryOperators.ADD_MONTHS) {
// Oracle-style 'ADD_MONTHS(date, integer months)'
qualifier = new SqlIntervalQualifier(TimeUnit.MONTH, null, SqlParserPos.ZERO);
RexNode opfirstparameter = cx.convertExpression(call.operand(0));
if (opfirstparameter.getType().getSqlTypeName() == SqlTypeName.TIMESTAMP) {
RelDataType timestampType = cx.getTypeFactory().createSqlType(SqlTypeName.DATE);
op2 = rexBuilder.makeCast(timestampType, opfirstparameter);
} else {
op2 = cx.convertExpression(call.operand(0));
}

RexNode opsecondparameter = cx.convertExpression(call.operand(1));
RelDataTypeFactory typeFactory = cx.getTypeFactory();

// In Calcite, cast('1.2' as integer) is invalid.
// For details, see https://issues.apache.org/jira/browse/CALCITE-1439
// When trying to cast a string value to an integer type, Calcite may
// encounter errors if the string value cannot be successfully converted.
// To handle this, the string needs to be first converted to a double type,
// and then the double value can be converted to an integer type.
// Since the final target type is integer, converting the string to double first
// will not lose precision for the add_months operation.
if (opsecondparameter.getType().getSqlTypeName() == SqlTypeName.CHAR) {
RelDataType doubleType = typeFactory.createSqlType(SqlTypeName.DOUBLE);
opsecondparameter = rexBuilder.makeCast(doubleType, opsecondparameter);
}
RelDataType intType = typeFactory.createSqlType(SqlTypeName.INTEGER);
op1 = rexBuilder.makeCast(intType, opsecondparameter);
op2 = handleFirstParameter(cx, rexBuilder, call);
op1 = handleSecondParameter(cx, rexBuilder, call);
} else if (call.getOperator() == SqlLibraryOperators.DATE_ADD_SPARK) {
// Spark-style 'DATE_ADD(date, integer days)'
qualifier = new SqlIntervalQualifier(TimeUnit.DAY, null, SqlParserPos.ZERO);
op2 = handleFirstParameter(cx, rexBuilder, call);
op1 = handleSecondParameter(cx, rexBuilder, call);
} else {
// BigQuery-style 'TIMESTAMP_ADD(timestamp, interval)'
final SqlBasicCall operandCall = call.operand(1);
Expand Down
3 changes: 2 additions & 1 deletion site/_docs/reference.md
Original file line number Diff line number Diff line change
Expand Up @@ -2721,7 +2721,7 @@ In the following:
| m | expr1 <=> expr2 | Whether two values are equal, treating null values as the same, and it's similar to `IS NOT DISTINCT FROM`
| p | ACOSD(numeric) | Returns the inverse cosine of *numeric* in degrees as a double. Returns NaN if *numeric* is NaN. Fails if *numeric* is less than -1.0 or greater than 1.0.
| * | ACOSH(numeric) | Returns the inverse hyperbolic cosine of *numeric*
| o s | ADD_MONTHS(start_date, num_months) | Returns the date that is *num_months* after *start_date*
| o s | ADD_MONTHS(date, numMonths) | Returns the date that is *numMonths* after *date*
| s | ARRAY([expr [, expr ]*]) | Construct an array in Apache Spark. The function allows users to use `ARRAY()` to create an empty array
| s | ARRAY_APPEND(array, element) | Appends an *element* to the end of the *array* and returns the result. Type of *element* should be similar to type of the elements of the *array*. If the *array* is null, the function will return null. If an *element* that is null, the null *element* will be added to the end of the *array*
| s | ARRAY_COMPACT(array) | Removes null values from the *array*
Expand Down Expand Up @@ -2804,6 +2804,7 @@ In the following:
| b s | DATE_FROM_UNIX_DATE(integer) | Returns the DATE that is *integer* days after 1970-01-01
| p r | DATE_PART(timeUnit, datetime) | Equivalent to `EXTRACT(timeUnit FROM datetime)`
| b | DATE_ADD(date, interval) | Returns the DATE value that occurs *interval* after *date*
| s | DATE_ADD(date, numDays) | Returns the DATE that is *numDays* after *date*
| b | DATE_DIFF(date, date2, timeUnit) | Returns the whole number of *timeUnit* between *date* and *date2*
| b | DATE_SUB(date, interval) | Returns the DATE value that occurs *interval* before *date*
| b | DATE_TRUNC(date, timeUnit) | Truncates *date* to the granularity of *timeUnit*, rounding to the beginning of the unit
Expand Down
61 changes: 61 additions & 0 deletions testkit/src/main/java/org/apache/calcite/test/SqlOperatorTest.java
Original file line number Diff line number Diff line change
Expand Up @@ -13910,6 +13910,67 @@ void testTimestampDiff(boolean coercionEnabled) {
f.checkNull("date_add(CAST(NULL AS DATE), interval 5 day)");
}

/** Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-6527">[CALCITE-6527]
* Add DATE_ADD function (enabled in Spark library)</a>.
*/
@Test void testDateAddSpark() {
final SqlOperatorFixture f0 = fixture()
.setFor(SqlLibraryOperators.DATE_ADD_SPARK);
f0.checkFails("^date_add(date '2008-12-25', "
+ "5)^",
"No match found for function signature "
+ "DATE_ADD\\(<DATE>, <NUMERIC>\\)", false);

final SqlOperatorFixture f = f0.withLibrary(SqlLibrary.SPARK);
f.checkScalar("date_add(date '2016-02-22', 2)",
"2016-02-24",
"DATE NOT NULL");
f.checkScalar("date_add(date '2016-02-28', 2)",
"2016-03-01",
"DATE NOT NULL");
f.checkScalar("date_add(date '2016-03-01', -2)",
"2016-02-28",
"DATE NOT NULL");
f.checkScalar("date_add(date '2016-03-01', -2)",
"2016-02-28",
"DATE NOT NULL");
f.checkScalar("date_add(date '2016-03-01', -2.0)",
"2016-02-28",
"DATE NOT NULL");
f.checkScalar("date_add(date '2016-02-28', 2.0)",
"2016-03-01",
"DATE NOT NULL");
f.checkScalar("date_add(date '2016-02-28', '2.0')",
"2016-03-01",
"DATE NOT NULL");
f.checkScalar("date_add(timestamp '2016-02-22 13:00:01', '-2.0')",
"2016-02-20",
"DATE NOT NULL");
f.checkScalar("date_add(timestamp '2016-02-22 13:00:01', -2)",
Copy link
Contributor

Choose a reason for hiding this comment

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

Add test like:

spark-sql> select date_add('2016-02-22 13:00:01', -2);
2016-02-20
spark-sql> select date_add('13:00:01', -2);
NULL
Time taken: 0.195 seconds, Fetched 1 row(s)
spark-sql> select date_add('1', -2);
NULL
spark-sql> select date_add(1, -2);
Error in query: cannot resolve 'date_add(1, -2)' due to data type mismatch: argument 1 requires date type, however, '1' is of int type.; line 1 pos 7;
'Project [unresolvedalias(date_add(1, -2), None)]
+- OneRowRelation

Copy link
Member Author

Choose a reason for hiding this comment

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

@NobiGo Calcite has its own date type rules, which are different from Spark. I am wondering whether it is necessary to return null in select date_add('13:00:01', -2)🤔.

The dataricks documentation states that only date expressions are accepted,https://docs.databricks.com/en/sql/language-manual/functions/date_add.html.

I think you can refer to the NVL2 function I adapted before, https://issues.apache.org/jira/browse/CALCITE-6397

"2016-02-20",
"DATE NOT NULL");
f.checkScalar("date_add(timestamp '2016-02-22 13:00:01', -2.0)",
"2016-02-20",
"DATE NOT NULL");
f.checkScalar("date_add(date '0001-01-01', '-2.0')",
"0000-12-30",
"DATE NOT NULL");
f.checkScalar("date_add(date '0001-01-01', '-367')",
"000/-12-31",
"DATE NOT NULL");
f.checkScalar("date_add(date '0001-01-01', '-3')",
"0000-12-29",
"DATE NOT NULL");
f.checkNull("date_add(CAST(NULL AS DATE), 5)");
f.checkNull("date_add(date '2016-02-22', CAST(NULL AS INTEGER))");
f.checkNull("date_add(CAST(NULL AS DATE), CAST(NULL AS INTEGER))");
f.checkFails("^date_add(time '13:00:01', -2)^", INVALID_ARGUMENTS_TYPE_VALIDATION_ERROR,
false);
f.checkFails("^date_add(1, -2)^", INVALID_ARGUMENTS_TYPE_VALIDATION_ERROR,
false);
}

/** Test case for
* <a href="https://issues.apache.org/jira/browse/CALCITE-6396">[CALCITE-6396]
* Add ADD_MONTHS function (enabled in Oracle, Spark library)</a>.
Expand Down
Loading