Skip to content

Commit

Permalink
SQL: Implement DATE_PART function (#47206)
Browse files Browse the repository at this point in the history
DATE_PART(<datetime unit>, <date/datetime>) is a function that allows
the user to extract the specified unit from a date/datetime field
similar to the EXTRACT (<datetime unit> FROM <date/datetime>) but
with different names and aliases for the units and it also provides more
options like `DATE_PART('tzoffset', datetimeField)`.

Implemented following the SQL server's spec: https://docs.microsoft.com/en-us/sql/t-sql/functions/datepart-transact-sql?view=sql-server-2017
with the difference that the <datetime unit> argument is either a
literal single quoted string or gets a value from a table field, whereas
in SQL server keywords are used (unquoted identifiers) and it's not
possible to use a value coming for a table column.

Closes: #46372
(cherry picked from commit ead743d)
  • Loading branch information
matriv committed Oct 1, 2019
1 parent 4335e07 commit f792dbf
Show file tree
Hide file tree
Showing 23 changed files with 970 additions and 191 deletions.
91 changes: 91 additions & 0 deletions docs/reference/sql/functions/date-time.asciidoc
Original file line number Diff line number Diff line change
Expand Up @@ -248,6 +248,97 @@ include-tagged::{sql-specs}/docs/docs.csv-spec[filterNow]
Currently, using a _precision_ greater than 3 doesn't make any difference to the output of the
function as the maximum number of second fractional digits returned is 3 (milliseconds).


[[sql-functions-datetime-part]]
==== `DATE_PART/DATEPART`

.Synopsis:
[source, sql]
--------------------------------------------------
DATE_PART(
string_exp, <1>
datetime_exp) <2>
--------------------------------------------------

*Input*:

<1> string expression denoting the unit to extract from the date/datetime
<2> date/datetime expression

*Output*: integer

.Description:

Extract the specified unit from a date/datetime. If any of the two arguments is `null` a `null` is returned.
It's similar to <<sql-functions-datetime-extract>> but with different names and aliases for the units and
provides more options (e.g.: `TZOFFSET`).

[cols="^,^"]
|===
2+h|Datetime units to extract

s|unit
s|abbreviations

| year | years, yy, yyyy
| quarter | quarters, qq, q
| month | months, mm, m
| dayofyear | dy, y
| day | days, dd, d
| week | weeks, wk, ww
| weekday | weekdays, dw
| hour | hours, hh
| minute | minutes, mi, n
| second | seconds, ss, s
| millisecond | milliseconds, ms
| microsecond | microseconds, mcs
| nanosecond | nanoseconds, ns
| tzoffset | tz
|===


[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateTimeYears]
--------------------------------------------------

[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateTimeMinutes]
--------------------------------------------------

[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateQuarter]
--------------------------------------------------

[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateMonth]
--------------------------------------------------

[NOTE]
For `week` and `weekday` the unit is extracted using the non-ISO calculation, which means
that a given week is considered to start from Sunday, not Monday.

[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateTimeWeek]
--------------------------------------------------

[NOTE]
The `tzoffset` returns the total number of minutes (signed) that represent the time zone's offset.

[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateTimeTzOffsetPlus]
--------------------------------------------------

[source, sql]
--------------------------------------------------
include-tagged::{sql-specs}/docs/docs.csv-spec[datePartDateTimeTzOffsetMinus]
--------------------------------------------------

[[sql-functions-datetime-trunc]]
==== `DATE_TRUNC/DATETRUNC`

Expand Down
1 change: 1 addition & 0 deletions docs/reference/sql/functions/index.asciidoc
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,7 @@
** <<sql-functions-current-date>>
** <<sql-functions-current-time>>
** <<sql-functions-current-timestamp>>
** <<sql-functions-datetime-part>>
** <<sql-functions-datetime-trunc>>
** <<sql-functions-datetime-day>>
** <<sql-functions-datetime-dow>>
Expand Down
2 changes: 2 additions & 0 deletions x-pack/plugin/sql/qa/src/main/resources/command.csv-spec
Original file line number Diff line number Diff line change
Expand Up @@ -41,7 +41,9 @@ CURRENT_DATE |SCALAR
CURRENT_TIME |SCALAR
CURRENT_TIMESTAMP|SCALAR
CURTIME |SCALAR
DATEPART |SCALAR
DATETRUNC |SCALAR
DATE_PART |SCALAR
DATE_TRUNC |SCALAR
DAY |SCALAR
DAYNAME |SCALAR
Expand Down
100 changes: 99 additions & 1 deletion x-pack/plugin/sql/qa/src/main/resources/datetime.csv-spec
Original file line number Diff line number Diff line change
Expand Up @@ -260,14 +260,112 @@ SELECT count(*) as count, DATE_TRUNC('decade', hire_date) dt FROM test_emp GROUP

dateTruncHaving
schema::gender:s|dt:ts
SELECT gender, max(hire_date) dt FROM test_emp GROUP BY gender HAVING DATE_TRUNC('year', max(hire_date)) >= '1997-01-01T00:00:00.000Z'::timestamp ORDER BY 1;
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;

gender | dt
--------+-------------------------
null | 1999-04-30 00:00:00.000Z
F | 1997-05-19 00:00:00.000Z
;

selectDatePartWithDate
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,
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,
DATE_PART('weekday', '2019-09-04'::date) as dp_weekday, DATE_PART('hour', '2019-09-04'::date) as dp_hour, DATE_PART('minute', '2019-09-04'::date) as dp_minute,
DATE_PART('second', '2019-09-04'::date) as dp_second, DATE_PART('millisecond', '2019-09-04'::date) as dp_millis, DATE_PART('mcs', '2019-09-04'::date) as dp_micros,
DATE_PART('ns', '2019-09-04'::date) as dp_nanos, DATE_PART('tz', '2019-09-04'::date) as dp_tzoffset;

dp_years | dp_quarter | dp_month | dp_doy | dp_day | dp_week | dp_weekday | dp_hour | dp_minute | dp_second | dp_millis | dp_micros | dp_nanos | dp_tzoffset
---------+------------+----------+--------+--------+---------+------------+---------+-----------+-----------+-----------+-----------+-----------+------------
2019 | 3 | 9 |247 | 4 | 36 | 4 | 0 | 0 | 0 | 0 | 0 | 0 | 0
;

selectDatePartWithDateTime
SELECT DATE_PART('year', '2019-09-04T11:22:33.123Z'::datetime) as dp_years, DATE_PART('quarter', '2019-09-04T11:22:33.123Z'::datetime) as dp_quarter, DATE_PART('month', '2019-09-04T11:22:33.123Z'::datetime) as dp_month,
DATE_PART('dayofyear', '2019-09-04T11:22:33.123Z'::datetime) as dp_doy, DATE_PART('day', '2019-09-04T11:22:33.123Z'::datetime) as dp_day, DATE_PART('week', '2019-09-04T11:22:33.123Z'::datetime) as dp_week,
DATE_PART('weekday', '2019-09-04T11:22:33.123Z'::datetime) as dp_weekday, DATE_PART('hour', '2019-09-04T11:22:33.123Z'::datetime) as dp_hour, DATE_PART('minute', '2019-09-04T11:22:33.123Z'::datetime) as dp_minute,
DATE_PART('second', '2019-09-04T11:22:33.123Z'::datetime) as dp_second, DATE_PART('millisecond', '2019-09-04T11:22:33.123Z'::datetime) as dp_millis, DATE_PART('mcs', '2019-09-04T11:22:33.123Z'::datetime) as dp_micros,
DATE_PART('ns', '2019-09-04T11:22:33.123Z'::datetime) as dp_nanos, DATE_PART('tz', '2019-09-04T11:22:33.123Z'::datetime) as dp_tzoffset;

dp_years | dp_quarter | dp_month | dp_doy | dp_day | dp_week | dp_weekday | dp_hour | dp_minute | dp_second | dp_millis | dp_micros | dp_nanos | dp_tzoffset
---------+------------+----------+--------+--------+---------+------------+---------+-----------+-----------+-----------+-----------+-----------+------------
2019 | 3 | 9 |247 | 4 | 36 | 4 | 11 | 22 | 33 | 123 | 123000 | 123000000 | 0
;

selectDatePartWithNullTruncateField
SELECT DATE_PART(null, birth_date) AS dp FROM test_emp LIMIT 5;

dp:i
------
null
null
null
null
null
;

selectDatePartWithComplexExpressions
SELECT gender, birth_date, DATE_PART(CASE WHEN gender = 'M' THEN CONCAT(gender, 'onths') WHEN gender = 'F' THEN 'year' ELSE 'quarter' END,
birth_date + INTERVAL 10 month) AS dp FROM test_emp WHERE dp > 10 ORDER BY emp_no LIMIT 5;

gender | birth_date | dp
--------+--------------------------+------
F | 1964-06-02 00:00:00.000Z | 1965
M | 1955-01-21 00:00:00.000Z | 11
F | 1953-04-20 00:00:00.000Z | 1954
F | 1957-05-23 00:00:00.000Z | 1958
M | 1958-02-19 00:00:00.000Z | 12
;

datePartOrderBy
schema::emp_no:i|hire_date:ts|dp:i
SELECT emp_no, hire_date, DATE_PART('month', hire_date) as dp FROM test_emp ORDER BY dp DESC NULLS LAST, emp_no LIMIT 5;

emp_no | hire_date | dp
--------+--------------------------+----
10004 | 1986-12-01 00:00:00.000Z | 12
10012 | 1992-12-18 00:00:00.000Z | 12
10023 | 1989-12-17 00:00:00.000Z | 12
10037 | 1990-12-05 00:00:00.000Z | 12
10050 | 1990-12-25 00:00:00.000z | 12
;

datePartFilter
schema::emp_no:i|hire_date:ts|dp:i
SELECT emp_no, hire_date, DATE_PART('day', hire_date) as dp FROM test_emp WHERE DATE_PART('day', hire_date) > 27 order by emp_no;

emp_no | hire_date | dp
--------+--------------------------+----
10003 | 1986-08-28 00:00:00.000Z | 28
10019 | 1999-04-30 00:00:00.000Z | 30
10047 | 1989-03-31 00:00:00.000Z | 31
10062 | 1991-08-30 00:00:00.000Z | 30
10081 | 1986-10-30 00:00:00.000Z | 30
10083 | 1987-03-31 00:00:00.000Z | 31
;

datePartGroupBy
schema::count:l|dp:i
SELECT count(*) as count, DATE_PART('quarter', hire_date) dp FROM test_emp GROUP BY dp ORDER BY 2;

count | dp
-------+----
30 | 1
19 | 2
27 | 3
24 | 4
;

datePartHaving
schema::gender:s|dt:ts
SELECT gender, max(hire_date) AS dt FROM test_emp GROUP BY gender HAVING DATE_PART('year', max(hire_date)) < 1999 ORDER BY 1;

gender | dt
--------+------------------------
F | 1997-05-19 00:00:00.000Z
M | 1996-11-05 00:00:00.000Z
;

//
// Aggregate
//
Expand Down
76 changes: 76 additions & 0 deletions x-pack/plugin/sql/qa/src/main/resources/docs/docs.csv-spec
Original file line number Diff line number Diff line change
Expand Up @@ -237,7 +237,9 @@ CURRENT_DATE |SCALAR
CURRENT_TIME |SCALAR
CURRENT_TIMESTAMP|SCALAR
CURTIME |SCALAR
DATEPART |SCALAR
DATETRUNC |SCALAR
DATE_PART |SCALAR
DATE_TRUNC |SCALAR
DAY |SCALAR
DAYNAME |SCALAR
Expand Down Expand Up @@ -2415,6 +2417,80 @@ SELECT DAY_OF_MONTH(CAST('2018-02-19T10:23:27Z' AS TIMESTAMP)) AS day;
// end::dayOfMonth
;

datePartDateTimeYears
// tag::datePartDateTimeYears
SELECT DATE_PART('year', '2019-09-22T11:22:33.123Z'::datetime) AS "years";

years
----------
2019
// end::datePartDateTimeYears
;

datePartDateTimeWeek
// tag::datePartDateTimeWeek
SELECT DATE_PART('week', '2019-09-22T11:22:33.123Z'::datetime) AS week;

week
----------
39
// end::datePartDateTimeWeek
;

datePartDateTimeMinutes
// tag::datePartDateTimeMinutes
SELECT DATE_PART('mi', '2019-09-04T11:22:33.123Z'::datetime) AS mins;

mins
-----------
22
// end::datePartDateTimeMinutes
;

datePartDateTimeTzOffsetPlus-Ignore
// The timezone is currently ignored when casting a string to datetime
// Awaits fix: https://github.com/elastic/elasticsearch/issues/40692
// tag::datePartDateTimeTzOffsetPlus
SELECT DATE_PART('tzoffset', '2019-09-04T11:22:33.123+05:15'::datetime) AS tz_mins;

tz_mins
--------------
315
// end::datePartDateTimeTzOffsetPlus
;

datePartDateTimeTzOffsetMinus-Ignore
// The timezone is currently ignored when casting a string to datetime
// Awaits fix: https://github.com/elastic/elasticsearch/issues/40692
// tag::datePartDateTimeTzOffsetMinus
SELECT DATE_PART('tzoffset', '2019-09-04T11:22:33.123-03:49'::datetime) AS tz_mins;

tz_mins
--------------
-229
// end::datePartDateTimeTzOffsetMinus
;

datePartDateQuarter
// tag::datePartDateQuarter
SELECT DATE_PART('quarters', CAST('2019-09-24' AS DATE)) AS quarter;

quarter
-------------
3
// end::datePartDateQuarter
;

datePartDateMonth
// tag::datePartDateMonth
SELECT DATE_PART('month', CAST('2019-09-24' AS DATE)) AS month;

month
-------------
9
// end::datePartDateMonth
;

truncateDateTimeMillennium
// tag::truncateDateTimeMillennium
SELECT DATE_TRUNC('millennium', '2019-09-04T11:22:33.123Z'::datetime) AS millennium;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -31,6 +31,7 @@
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.CurrentDate;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.CurrentDateTime;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.CurrentTime;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DatePart;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTrunc;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DayName;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DayOfMonth;
Expand Down Expand Up @@ -194,6 +195,7 @@ private void defineDefaultFunctions() {
def(DayOfMonth.class, DayOfMonth::new, "DAY_OF_MONTH", "DAYOFMONTH", "DAY", "DOM"),
def(DayOfWeek.class, DayOfWeek::new, "DAY_OF_WEEK", "DAYOFWEEK", "DOW"),
def(DayOfYear.class, DayOfYear::new, "DAY_OF_YEAR", "DAYOFYEAR", "DOY"),
def(DatePart.class, DatePart::new, "DATEPART", "DATE_PART"),
def(DateTrunc.class, DateTrunc::new, "DATETRUNC", "DATE_TRUNC"),
def(HourOfDay.class, HourOfDay::new, "HOUR_OF_DAY", "HOUR"),
def(IsoDayOfWeek.class, IsoDayOfWeek::new, "ISO_DAY_OF_WEEK", "ISODAYOFWEEK", "ISODOW", "IDOW"),
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@

import org.elasticsearch.common.io.stream.NamedWriteableRegistry;
import org.elasticsearch.common.io.stream.NamedWriteableRegistry.Entry;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DatePartProcessor;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTimeProcessor;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.DateTruncProcessor;
import org.elasticsearch.xpack.sql.expression.function.scalar.datetime.NamedDateTimeProcessor;
Expand Down Expand Up @@ -89,6 +90,7 @@ public static List<NamedWriteableRegistry.Entry> getNamedWriteables() {
entries.add(new Entry(Processor.class, NamedDateTimeProcessor.NAME, NamedDateTimeProcessor::new));
entries.add(new Entry(Processor.class, NonIsoDateTimeProcessor.NAME, NonIsoDateTimeProcessor::new));
entries.add(new Entry(Processor.class, QuarterProcessor.NAME, QuarterProcessor::new));
entries.add(new Entry(Processor.class, DatePartProcessor.NAME, DatePartProcessor::new));
entries.add(new Entry(Processor.class, DateTruncProcessor.NAME, DateTruncProcessor::new));
// math
entries.add(new Entry(Processor.class, BinaryMathProcessor.NAME, BinaryMathProcessor::new));
Expand Down
Loading

0 comments on commit f792dbf

Please sign in to comment.