Skip to content

Commit

Permalink
[CALCITE-5449] Allow EXTRACT() to accept DAYOFWEEK, DAYOFYEAR, ISOWEE…
Browse files Browse the repository at this point in the history
…K, WEEK(WEEKDAY) (#32)

* [CALCITE-5449] Allow EXTRACT() to accept time frames

* Fix getMonotonicity() override

* Lint

* Refactor DAYOFWEEK, DAYOFYEAR

---------

Co-authored-by: tanclary <116591231+tanclary@users.noreply.github.com>
Co-authored-by: Tanner Clary <tannerclary@google.com>
  • Loading branch information
3 people authored and wnob committed May 2, 2023
1 parent cabe489 commit 60452bf
Show file tree
Hide file tree
Showing 8 changed files with 124 additions and 43 deletions.
82 changes: 47 additions & 35 deletions babel/src/test/resources/sql/big-query.iq
Original file line number Diff line number Diff line change
Expand Up @@ -398,14 +398,12 @@ SELECT
# In the following example, EXTRACT returns values corresponding to
# different date parts from a column of dates near the end of the
# year.

!if (false) {
SELECT
d,
EXTRACT(ISOYEAR FROM d) AS isoyear,
EXTRACT(ISOWEEK FROM d) AS isoweek,
EXTRACT(YEAR FROM d) AS year,
EXTRACT(WEEK FROM d) AS week
EXTRACT(ISOWEEK FROM d) as isoweek,
EXTRACT(WEEK(TUESDAY) FROM d) AS week_tues,
EXTRACT(YEAR FROM d) AS year
FROM UNNEST(
ARRAY [DATE '2015-12-23',
DATE '2015-12-24',
Expand All @@ -426,48 +424,62 @@ FROM UNNEST(
DATE '2016-01-08',
DATE '2016-01-09']) AS d
ORDER BY d;
+------------+---------+---------+------+------+
| date | isoyear | isoweek | year | week |
+------------+---------+---------+------+------+
| 2015-12-23 | 2015 | 52 | 2015 | 51 |
| 2015-12-24 | 2015 | 52 | 2015 | 51 |
| 2015-12-25 | 2015 | 52 | 2015 | 51 |
| 2015-12-26 | 2015 | 52 | 2015 | 51 |
| 2015-12-27 | 2015 | 52 | 2015 | 52 |
| 2015-12-28 | 2015 | 53 | 2015 | 52 |
| 2015-12-29 | 2015 | 53 | 2015 | 52 |
| 2015-12-30 | 2015 | 53 | 2015 | 52 |
| 2015-12-31 | 2015 | 53 | 2015 | 52 |
| 2016-01-01 | 2015 | 53 | 2016 | 0 |
| 2016-01-02 | 2015 | 53 | 2016 | 0 |
| 2016-01-03 | 2015 | 53 | 2016 | 1 |
| 2016-01-04 | 2016 | 1 | 2016 | 1 |
| 2016-01-05 | 2016 | 1 | 2016 | 1 |
| 2016-01-06 | 2016 | 1 | 2016 | 1 |
| 2016-01-07 | 2016 | 1 | 2016 | 1 |
| 2016-01-08 | 2016 | 1 | 2016 | 1 |
| 2016-01-09 | 2016 | 1 | 2016 | 1 |
+------------+---------+---------+------+------+
+------------+---------+---------+-----------+------+
| d | isoyear | isoweek | week_tues | year |
+------------+---------+---------+-----------+------+
| 2015-12-23 | 2015 | 52 | 51 | 2015 |
| 2015-12-24 | 2015 | 52 | 51 | 2015 |
| 2015-12-25 | 2015 | 52 | 51 | 2015 |
| 2015-12-26 | 2015 | 52 | 51 | 2015 |
| 2015-12-27 | 2015 | 52 | 51 | 2015 |
| 2015-12-28 | 2015 | 53 | 51 | 2015 |
| 2015-12-29 | 2015 | 53 | 52 | 2015 |
| 2015-12-30 | 2015 | 53 | 52 | 2015 |
| 2015-12-31 | 2015 | 53 | 52 | 2015 |
| 2016-01-01 | 2015 | 53 | 0 | 2016 |
| 2016-01-02 | 2015 | 53 | 0 | 2016 |
| 2016-01-03 | 2015 | 53 | 0 | 2016 |
| 2016-01-04 | 2016 | 1 | 0 | 2016 |
| 2016-01-05 | 2016 | 1 | 1 | 2016 |
| 2016-01-06 | 2016 | 1 | 1 | 2016 |
| 2016-01-07 | 2016 | 1 | 1 | 2016 |
| 2016-01-08 | 2016 | 1 | 1 | 2016 |
| 2016-01-09 | 2016 | 1 | 1 | 2016 |
+------------+---------+---------+-----------+------+
(18 rows)

!ok
!}


# In the following example, date_expression falls on a Sunday. EXTRACT
# calculates the first column using weeks that begin on Sunday, and it
# calculates the second column using weeks that begin on Monday.

!if (false) {
WITH t AS (SELECT DATE('2017-11-05') AS d)
SELECT
d,
EXTRACT(ISOWEEK FROM d) AS isoweek,
EXTRACT(WEEK(SUNDAY) FROM d) AS week_sunday,
EXTRACT(WEEK(MONDAY) FROM d) AS week_monday FROM t;
+------------+-------------+-------------+
| date | week_sunday | week_monday |
+------------+-------------+-------------+
| 2017-11-05 | 45 | 44 |
+------------+-------------+-------------+
+------------+---------+-------------+-------------+
| d | isoweek | week_sunday | week_monday |
+------------+---------+-------------+-------------+
| 2017-11-05 | 44 | 45 | 44 |
+------------+---------+-------------+-------------+
(1 row)

!ok

SELECT EXTRACT(DAYOFWEEK FROM DATE '2008-12-25') as dow,
EXTRACT(DAYOFYEAR FROM DATE '2008-12-25') as doy;
+-----+-----+
| dow | doy |
+-----+-----+
| 5 | 360 |
+-----+-----+
(1 row)

!ok
!}

# In the following example, EXTRACT returns a value corresponding to
# the HOUR time part.
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -2740,6 +2740,10 @@ private static class ExtractImplementor extends AbstractRexCallImplementor {

@Override Expression implementSafe(final RexToLixTranslator translator,
final RexCall call, final List<Expression> argValueList) {
if (argValueList.get(0).getType() == String.class) {
return Expressions.call(BuiltInMethod.CUSTOM_DATE_EXTRACT.method,
translator.getRoot(), argValueList.get(0), argValueList.get(1));
}
final TimeUnitRange timeUnitRange =
(TimeUnitRange) translator.getLiteralValue(argValueList.get(0));
final TimeUnit unit = requireNonNull(timeUnitRange, "timeUnitRange").startUnit;
Expand Down
35 changes: 35 additions & 0 deletions core/src/main/java/org/apache/calcite/rel/type/TimeFrameSet.java
Original file line number Diff line number Diff line change
Expand Up @@ -287,6 +287,41 @@ public long diffTimestamp(long timestamp, long timestamp2, TimeFrame frame) {
return timestamp;
}

/** For ISOWEEK and WEEK(WEEKDAY), EXTRACT can be rewritten
* as the composition of DATE_DIFF and DATE_TRUNC. DAYOFWEEK and DAYOFYEAR
* are just translated to DOW and DOY respectively. */
public long extractDate(int date, TimeFrame timeFrame) {
TimeUnitRange timeUnitRange;
int offset = 0;
// Date will be truncated to either ISOYEAR or YEAR depending on time frame.
switch (timeFrame.name()) {
case "DAYOFWEEK":
return DateTimeUtils.unixDateExtract(TimeUnitRange.DOW, date);
case "DAYOFYEAR":
return DateTimeUtils.unixDateExtract(TimeUnitRange.DOY, date);
case "ISOWEEK":
timeUnitRange = TimeUnitRange.ISOYEAR;
offset += 1;
break;
default:
if (TimeFrames.WEEK_FRAME_NAMES.contains(timeFrame.name())) {
timeUnitRange = TimeUnitRange.YEAR;
} else {
throw new IllegalArgumentException("Unsupported frame for EXTRACT: " + timeFrame.name());
}
break;
}
// Date is truncated first to year/isoyear and then to the provided time frame.
int y0 = (int) DateTimeUtils.unixDateFloor(timeUnitRange, date);
int date2 = floorDate(y0, timeFrame);

// For WEEK(WEEKDAY), if year starts on WEEKDAY then offset of +1 is required.
if (date2 == y0 && timeUnitRange != TimeUnitRange.ISOYEAR) {
offset += 1;
}
return (long) diffDate(date2, date, timeFrame) + offset;
}

/** Builds a collection of time frames. */
public interface Builder {
/** Creates a {@code TimeFrameSet}. */
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -117,6 +117,8 @@ private static BuilderImpl addCore(BuilderImpl b) {

b.addQuotient(TimeUnit.DOY, TimeUnit.DAY, TimeUnit.YEAR);
b.addQuotient(TimeUnit.DOW, TimeUnit.DAY, TimeUnit.WEEK);
b.addQuotient("DAYOFYEAR", TimeUnit.DAY.name(), TimeUnit.YEAR.name());
b.addQuotient("DAYOFWEEK", TimeUnit.DAY.name(), TimeUnit.WEEK.name());
b.addQuotient(TimeUnit.ISODOW.name(), TimeUnit.DAY.name(), "ISOWEEK");

b.addRollup(TimeUnit.DAY, TimeUnit.MONTH);
Expand Down
11 changes: 11 additions & 0 deletions core/src/main/java/org/apache/calcite/runtime/SqlFunctions.java
Original file line number Diff line number Diff line change
Expand Up @@ -3403,6 +3403,17 @@ public static int customDateDiff(DataContext root,
return timeFrameSet.diffDate(date, date2, timeFrame);
}

/** SQL {@code EXTRACT} function applied to a custom time frame.
*
* <p>Unlike other DATE/TIME functions that accept custom time frames,
* EXTRACT currently only accepts ISOWEEK and WEEK(WEEKDAY). */
public static long customDateExtract(DataContext root, String timeFrameName, long date) {
final TimeFrameSet timeFrameSet =
requireNonNull(DataContext.Variable.TIME_FRAME_SET.get(root));
final TimeFrame timeFrame = timeFrameSet.get(timeFrameName);
return timeFrameSet.extractDate((int) date, timeFrame);
}

/** SQL {@code TIMESTAMPDIFF} function applied to a custom time frame.
*
* <p>Custom time frames are created and accessed as described in
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,6 @@
*/
package org.apache.calcite.sql.fun;

import org.apache.calcite.avatica.util.TimeUnitRange;
import org.apache.calcite.sql.SqlCall;
import org.apache.calcite.sql.SqlFunction;
import org.apache.calcite.sql.SqlFunctionCategory;
Expand All @@ -31,8 +30,6 @@
import org.apache.calcite.sql.validate.SqlValidatorScope;
import org.apache.calcite.util.Util;

import static org.apache.calcite.sql.validate.SqlNonNullableAccessors.getOperandLiteralValueOrThrow;

/**
* The SQL <code>EXTRACT</code> operator. Extracts a specified field value from
* a DATETIME or an INTERVAL. E.g.<br>
Expand Down Expand Up @@ -88,11 +85,12 @@ public SqlExtractFunction(String name) {
}

@Override public SqlMonotonicity getMonotonicity(SqlOperatorBinding call) {
TimeUnitRange value = getOperandLiteralValueOrThrow(call, 0, TimeUnitRange.class);
switch (value) {
case YEAR:
// If string value of first operand is anything except YEAR,
// return NOT_MONOTONIC.
Object value = call.getOperandLiteralValue(0, Object.class);
if (value != null && value.toString().equals("YEAR")) {
return call.getOperandMonotonicity(1).unstrict();
default:
} else {
return SqlMonotonicity.NOT_MONOTONIC;
}
}
Expand Down
2 changes: 2 additions & 0 deletions core/src/main/java/org/apache/calcite/util/BuiltInMethod.java
Original file line number Diff line number Diff line change
Expand Up @@ -540,6 +540,8 @@ public enum BuiltInMethod {
DataContext.class, String.class, int.class, int.class),
CUSTOM_DATE_DIFF(SqlFunctions.class, "customDateDiff",
DataContext.class, String.class, int.class, int.class),
CUSTOM_DATE_EXTRACT(SqlFunctions.class, "customDateExtract",
DataContext.class, String.class, long.class),
CUSTOM_DATE_FLOOR(SqlFunctions.class, "customDateFloor",
DataContext.class, String.class, int.class),
CUSTOM_DATE_CEIL(SqlFunctions.class, "customDateCeil",
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7546,13 +7546,30 @@ private static void checkArrayConcatAggFuncFails(SqlOperatorFixture t) {
"2008", "BIGINT NOT NULL");
f.checkScalar("extract(isoyear from date '2008-2-23')",
"2008", "BIGINT NOT NULL");

f.checkScalar("extract(isoweek from date '2008-02-23')",
"8", "BIGINT NOT NULL");
f.checkScalar("extract(week(sunday) from date '2017-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(week(monday) from date '2018-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(week(tuesday) from date '2019-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(week(wednesday) from date '2014-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(week(thursday) from date '2015-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(week(friday) from date '2021-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(week(saturday) from date '2022-03-19')",
"12", "BIGINT NOT NULL");
f.checkScalar("extract(doy from date '2008-2-23')",
"54", "BIGINT NOT NULL");
f.checkScalar("extract(dayofyear from date '2008-2-23')",
"54", "BIGINT NOT NULL");
f.checkScalar("extract(dow from date '2008-2-23')",
"7", "BIGINT NOT NULL");
f.checkScalar("extract(dayofweek from date '2008-2-23')",
"7", "BIGINT NOT NULL");
f.checkScalar("extract(dow from date '2008-2-24')",
"1", "BIGINT NOT NULL");
f.checkScalar("extract(dayofweek from date '2008-2-23')",
Expand Down

0 comments on commit 60452bf

Please sign in to comment.