Skip to content

Commit 2dc7950

Browse files
author
musteaf
authored
SQL: Extend DATE_TRUNC to also operate on intervals(elastic - #46632 ) (#47720)
The function is extended to operate on intervals according to the PostgreSQL: https://www.postgresql.org/docs/9.1/functions-datetime.html#FUNCTIONS-DATETIME-TRUNC Closes : #46632
1 parent 1df7382 commit 2dc7950

File tree

14 files changed

+536
-98
lines changed

14 files changed

+536
-98
lines changed

docs/reference/sql/functions/date-time.asciidoc

+21-5
Original file line numberDiff line numberDiff line change
@@ -500,18 +500,19 @@ include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateTimeTzOffsetMinus]
500500
--------------------------------------------------
501501
DATE_TRUNC(
502502
string_exp, <1>
503-
datetime_exp) <2>
503+
datetime_exp/interval_exp) <2>
504504
--------------------------------------------------
505505

506506
*Input*:
507507

508-
<1> string expression denoting the unit to which the date/datetime should be truncated to
509-
<2> date/datetime expression
508+
<1> string expression denoting the unit to which the date/datetime/interval should be truncated to
509+
<2> date/datetime/interval expression
510510

511-
*Output*: datetime
511+
*Output*: datetime/interval
512512

513-
*Description*: Truncate the date/datetime to the specified unit by setting all fields that are less significant than the specified
513+
*Description*: Truncate the date/datetime/interval to the specified unit by setting all fields that are less significant than the specified
514514
one to zero (or one, for day, day of week and month). If any of the two arguments is `null` a `null` is returned.
515+
If the first argument is `week` and the second argument is of `interval` type, an error is thrown since the `interval` data type doesn't support a `week` time unit.
515516

516517
[cols="^,^"]
517518
|===
@@ -563,6 +564,21 @@ include-tagged::{sql-specs}/docs/docs.csv-spec[truncateDateDecades]
563564
include-tagged::{sql-specs}/docs/docs.csv-spec[truncateDateQuarter]
564565
--------------------------------------------------
565566

567+
[source, sql]
568+
--------------------------------------------------
569+
include-tagged::{sql-specs}/docs/docs.csv-spec[truncateIntervalCenturies]
570+
--------------------------------------------------
571+
572+
[source, sql]
573+
--------------------------------------------------
574+
include-tagged::{sql-specs}/docs/docs.csv-spec[truncateIntervalHour]
575+
--------------------------------------------------
576+
577+
[source, sql]
578+
--------------------------------------------------
579+
include-tagged::{sql-specs}/docs/docs.csv-spec[truncateIntervalDay]
580+
--------------------------------------------------
581+
566582
[[sql-functions-datetime-day]]
567583
==== `DAY_OF_MONTH/DOM/DAY`
568584

x-pack/plugin/ql/src/main/java/org/elasticsearch/xpack/ql/util/DateUtils.java

+5-5
Original file line numberDiff line numberDiff line change
@@ -34,7 +34,7 @@ public class DateUtils {
3434
public static final ZoneId UTC = ZoneId.of("Z");
3535

3636
public static final String EMPTY = "";
37-
37+
3838
public static final DateTimeFormatter ISO_DATE_WITH_MILLIS = new DateTimeFormatterBuilder()
3939
.parseCaseInsensitive()
4040
.append(ISO_LOCAL_DATE)
@@ -72,17 +72,17 @@ public class DateUtils {
7272
.appendOffsetId()
7373
.toFormatter(Locale.ROOT);
7474

75-
private static final int SECONDS_PER_MINUTE = 60;
76-
private static final int SECONDS_PER_HOUR = SECONDS_PER_MINUTE * 60;
77-
private static final int SECONDS_PER_DAY = SECONDS_PER_HOUR * 24;
75+
public static final int SECONDS_PER_MINUTE = 60;
76+
public static final int SECONDS_PER_HOUR = SECONDS_PER_MINUTE * 60;
77+
public static final int SECONDS_PER_DAY = SECONDS_PER_HOUR * 24;
7878

7979
private DateUtils() {}
8080

8181
public static String toString(Object value) {
8282
if (value == null) {
8383
return "null";
8484
}
85-
85+
8686
if (value instanceof ZonedDateTime) {
8787
return ((ZonedDateTime) value).format(ISO_DATE_WITH_MILLIS);
8888
}

x-pack/plugin/sql/qa/src/main/resources/datetime.csv-spec

+71
Original file line numberDiff line numberDiff line change
@@ -499,6 +499,16 @@ DATE_TRUNC('week', '2019-09-04'::date) as dt_week, DATE_TRUNC('day', '2019-09-0
499499
2000-01-01T00:00:00.000Z | 2000-01-01T00:00:00.000Z | 2010-01-01T00:00:00.000Z | 2019-01-01T00:00:00.000Z | 2019-07-01T00:00:00.000Z | 2019-09-01T00:00:00.000Z | 2019-09-02T00:00:00.000Z | 2019-09-04T00:00:00.000Z
500500
;
501501

502+
selectDateTruncWithInterval
503+
SELECT DATE_TRUNC('hour', INTERVAL '1 12:43:21' DAY TO SECONDS) as dt_hour, DATE_TRUNC('minute', INTERVAL '1 12:43:21' DAY TO SECONDS) as dt_min,
504+
DATE_TRUNC('seconds', INTERVAL '1 12:43:21' DAY TO SECONDS) as dt_sec, DATE_TRUNC('ms', INTERVAL '1 12:43:21' DAY TO SECONDS)::string as dt_millis,
505+
DATE_TRUNC('mcs', INTERVAL '1 12:43:21' DAY TO SECONDS)::string as dt_micro, DATE_TRUNC('nanoseconds', INTERVAL '1 12:43:21' DAY TO SECONDS)::string as dt_nano;
506+
507+
dt_hour | dt_min | dt_sec | dt_millis | dt_micro | dt_nano
508+
---------------+---------------+---------------+---------------+---------------+---------------
509+
+1 12:00:00 |+1 12:43:00 |+1 12:43:21 |+1 12:43:21 |+1 12:43:21 |+1 12:43:21
510+
;
511+
502512
selectDateTruncWithField
503513
schema::emp_no:i|birth_date:ts|dt_mil:ts|dt_cent:ts|dt_dec:ts|dt_year:ts|dt_quarter:ts|dt_month:ts|dt_week:ts|dt_day:ts
504514
SELECT emp_no, birth_date, DATE_TRUNC('millennium', birth_date) as dt_mil, DATE_TRUNC('centuries', birth_date) as dt_cent,
@@ -585,6 +595,21 @@ SELECT emp_no, hire_date, DATE_TRUNC('quarter', hire_date) as dt FROM test_emp O
585595
10076 | 1985-07-09 00:00:00.000Z | 1985-07-01 00:00:00.000Z
586596
;
587597

598+
dateTruncOrderByWithInterval
599+
schema::first_name:s|dt:ts|hire_date:ts|languages:byte
600+
SELECT first_name, hire_date + DATE_TRUNC('centuries', CASE WHEN languages = 5 THEN INTERVAL '18-3' YEAR TO MONTH
601+
WHEN languages = 4 THEN INTERVAL '108-4' YEAR TO MONTH WHEN languages = 3 THEN INTERVAL '212-3' YEAR TO MONTH
602+
ELSE INTERVAL '318-6' YEAR TO MONTH END) as dt, hire_date, languages FROM test_emp WHERE emp_no <= 10006 ORDER BY dt NULLS LAST LIMIT 5;
603+
604+
first_name | dt | hire_date | languages
605+
--------------+--------------------------+--------------------------+-----------
606+
Bezalel | 1985-11-21 00:00:00.000Z | 1985-11-21T00:00:00.000Z | 5
607+
Chirstian | 1986-12-01 00:00:00.000Z | 1986-12-01T00:00:00.000Z | 5
608+
Parto | 2086-08-28 00:00:00.000Z | 1986-08-28T00:00:00.000Z | 4
609+
Anneke | 2189-06-02 00:00:00.000Z | 1989-06-02T00:00:00.000Z | 3
610+
Georgi | 2286-06-26 00:00:00.000Z | 1986-06-26T00:00:00.000Z | 2
611+
;
612+
588613
dateTruncFilter
589614
schema::emp_no:i|hire_date:ts|dt:ts
590615
SELECT emp_no, hire_date, DATE_TRUNC('quarter', hire_date) as dt FROM test_emp WHERE DATE_TRUNC('quarter', hire_date) > '1994-07-01T00:00:00.000Z'::timestamp ORDER BY emp_no;
@@ -601,6 +626,24 @@ SELECT emp_no, hire_date, DATE_TRUNC('quarter', hire_date) as dt FROM test_emp W
601626
10093 | 1996-11-05 00:00:00.000Z | 1996-10-01 00:00:00.000Z
602627
;
603628

629+
dateTruncFilterWithInterval
630+
schema::first_name:s|hire_date:ts
631+
SELECT first_name, hire_date FROM test_emp WHERE hire_date > '2090-03-05T10:11:22.123Z'::datetime - DATE_TRUNC('centuries', INTERVAL 190 YEARS) ORDER BY first_name DESC, hire_date ASC LIMIT 10;
632+
633+
first_name | hire_date
634+
---------------+-------------------------
635+
null | 1990-06-20 00:00:00.000Z
636+
null | 1990-12-05 00:00:00.000Z
637+
null | 1991-09-01 00:00:00.000Z
638+
null | 1992-01-03 00:00:00.000Z
639+
null | 1994-02-17 00:00:00.000Z
640+
Yongqiao | 1995-03-20 00:00:00.000Z
641+
Yishay | 1990-10-20 00:00:00.000Z
642+
Yinghua | 1990-12-25 00:00:00.000Z
643+
Weiyi | 1993-02-14 00:00:00.000Z
644+
Tuval | 1995-12-15 00:00:00.000Z
645+
;
646+
604647
dateTruncGroupBy
605648
schema::count:l|dt:ts
606649
SELECT count(*) as count, DATE_TRUNC('decade', hire_date) dt FROM test_emp GROUP BY dt ORDER BY 2;
@@ -611,6 +654,24 @@ SELECT count(*) as count, DATE_TRUNC('decade', hire_date) dt FROM test_emp GROUP
611654
41 | 1990-01-01 00:00:00.000Z
612655
;
613656

657+
dateTruncGroupByWithInterval
658+
schema::count:l|dt:ts
659+
SELECT count(*) as count, birth_date + DATE_TRUNC('hour', INTERVAL '1 12:43:21' DAY TO SECONDS) dt FROM test_emp GROUP BY dt ORDER BY 2 LIMIT 10;
660+
661+
count | dt
662+
--------+-------------------------
663+
10 | null
664+
1 | 1952-02-28 12:00:00.000Z
665+
1 | 1952-04-20 12:00:00.000Z
666+
1 | 1952-05-16 12:00:00.000Z
667+
1 | 1952-06-14 12:00:00.000Z
668+
1 | 1952-07-09 12:00:00.000Z
669+
1 | 1952-08-07 12:00:00.000Z
670+
1 | 1952-11-14 12:00:00.000Z
671+
1 | 1952-12-25 12:00:00.000Z
672+
1 | 1953-01-08 12:00:00.000Z
673+
;
674+
614675
dateTruncHaving
615676
schema::gender:s|dt:ts
616677
SELECT gender, max(hire_date) AS dt FROM test_emp GROUP BY gender HAVING DATE_TRUNC('year', max(hire_date)) >= '1997-01-01T00:00:00.000Z'::timestamp ORDER BY 1;
@@ -621,6 +682,16 @@ null | 1999-04-30 00:00:00.000Z
621682
F | 1997-05-19 00:00:00.000Z
622683
;
623684

685+
// Awaits fix: https://github.com/elastic/elasticsearch/issues/53565
686+
dateTruncHavingWithInterval-Ignore
687+
schema::gender:s|dt:ts
688+
SELECT gender, max(hire_date) AS dt FROM test_emp GROUP BY gender HAVING max(hire_date) - DATE_TRUNC('hour', INTERVAL 1 YEARS) >= '1997-01-01T00:00:00.000Z'::timestamp ORDER BY 1;
689+
690+
gender | dt
691+
--------+-------------------------
692+
null | 1999-04-30 00:00:00.000Z
693+
;
694+
624695
selectDatePartWithDate
625696
SELECT DATE_PART('year', '2019-09-04'::date) as dp_years, DATE_PART('quarter', '2019-09-04'::date) as dp_quarter, DATE_PART('month', '2019-09-04'::date) as dp_month,
626697
DATE_PART('dayofyear', '2019-09-04'::date) as dp_doy, DATE_PART('day', '2019-09-04'::date) as dp_day, DATE_PART('week', '2019-09-04'::date) as dp_week,

x-pack/plugin/sql/qa/src/main/resources/docs/docs.csv-spec

+30
Original file line numberDiff line numberDiff line change
@@ -2675,6 +2675,36 @@ SELECT DATETRUNC('quarters', CAST('2019-09-04' AS DATE)) AS quarter;
26752675
// end::truncateDateQuarter
26762676
;
26772677

2678+
truncateIntervalCenturies
2679+
// tag::truncateIntervalCenturies
2680+
SELECT DATE_TRUNC('centuries', INTERVAL '199-5' YEAR TO MONTH) AS centuries;
2681+
2682+
centuries
2683+
------------------
2684+
+100-0
2685+
// end::truncateIntervalCenturies
2686+
;
2687+
2688+
truncateIntervalHour
2689+
// tag::truncateIntervalHour
2690+
SELECT DATE_TRUNC('hours', INTERVAL '17 22:13:12' DAY TO SECONDS) AS hour;
2691+
2692+
hour
2693+
------------------
2694+
+17 22:00:00
2695+
// end::truncateIntervalHour
2696+
;
2697+
2698+
truncateIntervalDay
2699+
// tag::truncateIntervalDay
2700+
SELECT DATE_TRUNC('days', INTERVAL '19 15:24:19' DAY TO SECONDS) AS day;
2701+
2702+
day
2703+
------------------
2704+
+19 00:00:00
2705+
// end::truncateIntervalDay
2706+
;
2707+
26782708
constantDayOfWeek
26792709
// tag::dayOfWeek
26802710
SELECT DAY_OF_WEEK(CAST('2018-02-19T10:23:27Z' AS TIMESTAMP)) AS day;

x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/SqlTypeResolutions.java

+5-1
Original file line numberDiff line numberDiff line change
@@ -16,7 +16,7 @@
1616
public final class SqlTypeResolutions {
1717

1818
private SqlTypeResolutions() {}
19-
19+
2020
public static TypeResolution isDate(Expression e, String operationName, ParamOrdinal paramOrd) {
2121
return isType(e, SqlDataTypes::isDateBased, operationName, paramOrd, "date", "datetime");
2222
}
@@ -25,6 +25,10 @@ public static TypeResolution isDateOrTime(Expression e, String operationName, Pa
2525
return isType(e, SqlDataTypes::isDateOrTimeBased, operationName, paramOrd, "date", "time", "datetime");
2626
}
2727

28+
public static TypeResolution isDateOrInterval(Expression e, String operationName, ParamOrdinal paramOrd) {
29+
return isType(e, SqlDataTypes::isDateOrIntervalBased, operationName, paramOrd, "date", "datetime", "an interval data type");
30+
}
31+
2832
public static TypeResolution isNumericOrDate(Expression e, String operationName, ParamOrdinal paramOrd) {
2933
return isType(e, dt -> dt.isNumeric() || SqlDataTypes.isDateBased(dt), operationName, paramOrd,
3034
"date", "datetime", "numeric");

x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/BinaryDateTimeFunction.java

+1-5
Original file line numberDiff line numberDiff line change
@@ -19,7 +19,6 @@
1919
import static org.elasticsearch.common.logging.LoggerMessageFormat.format;
2020
import static org.elasticsearch.xpack.ql.expression.TypeResolutions.isString;
2121
import static org.elasticsearch.xpack.ql.expression.gen.script.ParamsBuilder.paramsBuilder;
22-
import static org.elasticsearch.xpack.sql.expression.SqlTypeResolutions.isDate;
2322

2423
public abstract class BinaryDateTimeFunction extends BinaryScalarFunction {
2524

@@ -54,10 +53,7 @@ protected TypeResolution resolveType() {
5453
}
5554
}
5655
}
57-
resolution = isDate(right(), sourceText(), Expressions.ParamOrdinal.SECOND);
58-
if (resolution.unresolved()) {
59-
return resolution;
60-
}
56+
6157
return TypeResolution.TYPE_RESOLVED;
6258
}
6359

x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/scalar/datetime/DatePart.java

+16
Original file line numberDiff line numberDiff line change
@@ -6,6 +6,7 @@
66
package org.elasticsearch.xpack.sql.expression.function.scalar.datetime;
77

88
import org.elasticsearch.xpack.ql.expression.Expression;
9+
import org.elasticsearch.xpack.ql.expression.Expressions;
910
import org.elasticsearch.xpack.ql.expression.function.scalar.BinaryScalarFunction;
1011
import org.elasticsearch.xpack.ql.expression.gen.pipeline.Pipe;
1112
import org.elasticsearch.xpack.ql.tree.NodeInfo;
@@ -23,6 +24,8 @@
2324
import java.util.Set;
2425
import java.util.function.ToIntFunction;
2526

27+
import static org.elasticsearch.xpack.sql.expression.SqlTypeResolutions.isDate;
28+
2629
public class DatePart extends BinaryDateTimeFunction {
2730

2831
public enum Part implements DateTimeField {
@@ -84,6 +87,19 @@ public DataType dataType() {
8487
return DataTypes.INTEGER;
8588
}
8689

90+
@Override
91+
protected TypeResolution resolveType() {
92+
TypeResolution resolution = super.resolveType();
93+
if (resolution.unresolved()) {
94+
return resolution;
95+
}
96+
resolution = isDate(right(), sourceText(), Expressions.ParamOrdinal.SECOND);
97+
if (resolution.unresolved()) {
98+
return resolution;
99+
}
100+
return TypeResolution.TYPE_RESOLVED;
101+
}
102+
87103
@Override
88104
protected BinaryScalarFunction replaceChildren(Expression newDateTimePart, Expression newTimestamp) {
89105
return new DatePart(source(), newDateTimePart, newTimestamp, zoneId());

0 commit comments

Comments
 (0)