-
Notifications
You must be signed in to change notification settings - Fork 28.9k
[SPARK-28690][SQL] Add date_part function for timestamps/dates
#25410
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
Changes from all commits
cc81650
0e571be
b856859
d23b8ba
af51e52
e68611a
e1d5a75
ae353b9
f3b2772
b795ebc
efc3ee0
188d7de
9935c01
c918eb0
bcf73d2
7c549c7
1b2c8d4
2fa25b1
494679c
5c8c34d
05b3746
74a7fec
bc707df
d86c092
ade541d
43968c2
b292931
600eee6
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -1409,48 +1409,12 @@ class AstBuilder(conf: SQLConf) extends SqlBaseBaseVisitor[AnyRef] with Logging | |
| * Create a Extract expression. | ||
| */ | ||
| override def visitExtract(ctx: ExtractContext): Expression = withOrigin(ctx) { | ||
| ctx.field.getText.toUpperCase(Locale.ROOT) match { | ||
| case "MILLENNIUM" | "MILLENNIA" | "MIL" | "MILS" => | ||
| Millennium(expression(ctx.source)) | ||
| case "CENTURY" | "CENTURIES" | "C" | "CENT" => | ||
| Century(expression(ctx.source)) | ||
| case "DECADE" | "DECADES" | "DEC" | "DECS" => | ||
| Decade(expression(ctx.source)) | ||
| case "YEAR" | "Y" | "YEARS" | "YR" | "YRS" => | ||
| Year(expression(ctx.source)) | ||
| case "ISOYEAR" => | ||
| IsoYear(expression(ctx.source)) | ||
| case "QUARTER" | "QTR" => | ||
| Quarter(expression(ctx.source)) | ||
| case "MONTH" | "MON" | "MONS" | "MONTHS" => | ||
| Month(expression(ctx.source)) | ||
| case "WEEK" | "W" | "WEEKS" => | ||
| WeekOfYear(expression(ctx.source)) | ||
| case "DAY" | "D" | "DAYS" => | ||
| DayOfMonth(expression(ctx.source)) | ||
| case "DAYOFWEEK" => | ||
| DayOfWeek(expression(ctx.source)) | ||
| case "DOW" => | ||
| Subtract(DayOfWeek(expression(ctx.source)), Literal(1)) | ||
| case "ISODOW" => | ||
| Add(WeekDay(expression(ctx.source)), Literal(1)) | ||
| case "DOY" => | ||
| DayOfYear(expression(ctx.source)) | ||
| case "HOUR" | "H" | "HOURS" | "HR" | "HRS" => | ||
| Hour(expression(ctx.source)) | ||
| case "MINUTE" | "M" | "MIN" | "MINS" | "MINUTES" => | ||
| Minute(expression(ctx.source)) | ||
| case "SECOND" | "S" | "SEC" | "SECONDS" | "SECS" => | ||
| Second(expression(ctx.source)) | ||
| case "MILLISECONDS" | "MSEC" | "MSECS" | "MILLISECON" | "MSECONDS" | "MS" => | ||
| Milliseconds(expression(ctx.source)) | ||
| case "MICROSECONDS" | "USEC" | "USECS" | "USECONDS" | "MICROSECON" | "US" => | ||
| Microseconds(expression(ctx.source)) | ||
| case "EPOCH" => | ||
| Epoch(expression(ctx.source)) | ||
| case other => | ||
| throw new ParseException(s"Literals of type '$other' are currently not supported.", ctx) | ||
|
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. The exception changed from
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more.
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. ... but I can pass
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Instead of passing ctx into DataPart, can't we resolve
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. This will work for
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Ur, I see! sorry, but I need to be away from a keybord, so I'll recheck in hours.
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I've heard that its a little hard to read parser error messages in spark. So, I personally think we should throw ParseException with ctx for the
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I agree it would be nice to point out the exact position of the error but I don't like this ad-hoc solution. There are a few similar places in
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Ur, I don't think the approach is bad and I'm just looking for a better solution to keep the current error handling. If we already have the similar logic, can we follow that?
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. @maropu @dongjoon-hyun If you think the commit d793f49 is necessary for merging the PR, I will apply the patch. |
||
| } | ||
| val fieldStr = ctx.field.getText | ||
| val source = expression(ctx.source) | ||
| val extractField = DatePart.parseExtractField(fieldStr, source, { | ||
| throw new ParseException(s"Literals of type '$fieldStr' are currently not supported.", ctx) | ||
| }) | ||
| new DatePart(Literal(fieldStr), expression(ctx.source), extractField) | ||
| } | ||
|
|
||
| /** | ||
|
|
||
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,68 @@ | ||
| CREATE TEMPORARY VIEW t AS select '2011-05-06 07:08:09.1234567' as c; | ||
|
|
||
| select date_part('millennium', c) from t; | ||
| select date_part('millennia', c) from t; | ||
| select date_part('mil', c) from t; | ||
| select date_part('mils', c) from t; | ||
|
|
||
| select date_part('century', c) from t; | ||
| select date_part('centuries', c) from t; | ||
| select date_part('c', c) from t; | ||
| select date_part('cent', c) from t; | ||
|
|
||
| select date_part('decade', c) from t; | ||
| select date_part('decades', c) from t; | ||
| select date_part('dec', c) from t; | ||
| select date_part('decs', c) from t; | ||
|
|
||
| select date_part('year', c) from t; | ||
| select date_part('y', c) from t; | ||
| select date_part('years', c) from t; | ||
| select date_part('yr', c) from t; | ||
| select date_part('yrs', c) from t; | ||
|
|
||
| select date_part('quarter', c) from t; | ||
| select date_part('qtr', c) from t; | ||
|
|
||
| select date_part('month', c) from t; | ||
| select date_part('mon', c) from t; | ||
| select date_part('mons', c) from t; | ||
| select date_part('months', c) from t; | ||
|
|
||
| select date_part('week', c) from t; | ||
| select date_part('w', c) from t; | ||
| select date_part('weeks', c) from t; | ||
|
|
||
| select date_part('day', c) from t; | ||
| select date_part('d', c) from t; | ||
| select date_part('days', c) from t; | ||
|
|
||
| select date_part('dayofweek', c) from t; | ||
|
|
||
| select date_part('dow', c) from t; | ||
|
|
||
| select date_part('isodow', c) from t; | ||
|
|
||
| select date_part('doy', c) from t; | ||
|
|
||
| select date_part('hour', c) from t; | ||
| select date_part('h', c) from t; | ||
| select date_part('hours', c) from t; | ||
| select date_part('hr', c) from t; | ||
| select date_part('hrs', c) from t; | ||
|
|
||
| select date_part('minute', c) from t; | ||
| select date_part('m', c) from t; | ||
| select date_part('min', c) from t; | ||
| select date_part('mins', c) from t; | ||
| select date_part('minutes', c) from t; | ||
|
|
||
| select date_part('second', c) from t; | ||
| select date_part('s', c) from t; | ||
| select date_part('sec', c) from t; | ||
| select date_part('seconds', c) from t; | ||
| select date_part('secs', c) from t; | ||
|
|
||
| select date_part('not_supported', c) from t; | ||
|
|
||
| select date_part(c, c) from t; |
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -187,22 +187,21 @@ SELECT '' AS date_trunc_week, date_trunc( 'week', timestamp '2004-02-29 15:44:17 | |
| -- WHERE d1 BETWEEN timestamp '1902-01-01' | ||
| -- AND timestamp '2038-01-01'; | ||
|
|
||
| -- [SPARK-28420] Date/Time Functions: date_part | ||
| -- SELECT '' AS "54", d1 as "timestamp", | ||
| -- date_part( 'year', d1) AS year, date_part( 'month', d1) AS month, | ||
| -- date_part( 'day', d1) AS day, date_part( 'hour', d1) AS hour, | ||
| -- date_part( 'minute', d1) AS minute, date_part( 'second', d1) AS second | ||
| -- FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; | ||
|
|
||
| -- SELECT '' AS "54", d1 as "timestamp", | ||
| -- date_part( 'quarter', d1) AS quarter, date_part( 'msec', d1) AS msec, | ||
| -- date_part( 'usec', d1) AS usec | ||
| -- FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; | ||
|
|
||
| -- SELECT '' AS "54", d1 as "timestamp", | ||
| -- date_part( 'isoyear', d1) AS isoyear, date_part( 'week', d1) AS week, | ||
| -- date_part( 'dow', d1) AS dow | ||
| -- FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; | ||
| SELECT '' AS `54`, d1 as `timestamp`, | ||
|
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Oops. What I meant was backquoting for the special value like So,
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Thanks. I will remove the backquoting.
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. @dongjoon-hyun When I removed them, I got the error:
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I would guess,
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. @dongjoon-hyun I removed backquotes only around names that are not functions.
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. ? @MaxGekk . The master branch seems to be same. Could you push your change?
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. @dongjoon-hyun Pushed
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I reverted the backquotes back and opened JIRA for the issue: https://issues.apache.org/jira/browse/SPARK-28767
Member
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. This is because
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Have you checked that? #25114 (comment) |
||
| date_part( 'year', d1) AS `year`, date_part( 'month', d1) AS `month`, | ||
| date_part( 'day', d1) AS `day`, date_part( 'hour', d1) AS `hour`, | ||
| date_part( 'minute', d1) AS `minute`, date_part( 'second', d1) AS `second` | ||
| FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; | ||
|
|
||
| SELECT '' AS `54`, d1 as `timestamp`, | ||
| date_part( 'quarter', d1) AS quarter, date_part( 'msec', d1) AS msec, | ||
| date_part( 'usec', d1) AS usec | ||
| FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; | ||
|
|
||
| SELECT '' AS `54`, d1 as `timestamp`, | ||
| date_part( 'isoyear', d1) AS isoyear, date_part( 'week', d1) AS week, | ||
| date_part( 'dow', d1) AS dow | ||
| FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01'; | ||
|
|
||
| -- [SPARK-28137] Data Type Formatting Functions | ||
| -- TO_CHAR() | ||
|
|
||
Uh oh!
There was an error while loading. Please reload this page.