Skip to content
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
43 commits
Select commit Hold shift + click to select a range
b75a80f
Add Millennium
MaxGekk Sep 29, 2019
b233c90
Add Century
MaxGekk Sep 29, 2019
6f017a6
Add Decade
MaxGekk Sep 29, 2019
ac1c3a8
Add Year
MaxGekk Sep 29, 2019
7265508
Add Quarter
MaxGekk Sep 29, 2019
554df71
Move MONTHS_PER_QUARTER up
MaxGekk Sep 29, 2019
d0f89f4
Eliminate a warning
MaxGekk Sep 30, 2019
8174fd5
Extend with ExpectsInputTypes
MaxGekk Sep 30, 2019
6378b95
Remove blank lines
MaxGekk Sep 30, 2019
8e4ca7d
Add Month
MaxGekk Sep 30, 2019
8ed01c7
Week is not supported by PostgreSQL
MaxGekk Sep 30, 2019
f1eea12
Remove not-supported fields
MaxGekk Sep 30, 2019
561f789
Week of interval is not supported
MaxGekk Sep 30, 2019
0a671a9
Add Day
MaxGekk Sep 30, 2019
894a6c7
Add Hour
MaxGekk Sep 30, 2019
f86f4f5
Change Month type to ByteType
MaxGekk Sep 30, 2019
283fd99
Change Quarter type to ByteType
MaxGekk Sep 30, 2019
5e189ca
Put common code to IntervalPart
MaxGekk Sep 30, 2019
62c21b9
Run scalafmt
MaxGekk Sep 30, 2019
a4fbb5e
Add Minute
MaxGekk Sep 30, 2019
e1c9415
Add Second
MaxGekk Sep 30, 2019
7f4100f
Run scalafmt
MaxGekk Sep 30, 2019
f3cf7f0
Refactoring
MaxGekk Sep 30, 2019
9262f9d
Add a test for overflow
MaxGekk Sep 30, 2019
b9890ec
Add Milliseconds
MaxGekk Sep 30, 2019
bea3faf
Add Microseconds
MaxGekk Sep 30, 2019
77e0fb3
Add Epoch
MaxGekk Sep 30, 2019
58017a7
Support intervals by date_part
MaxGekk Sep 30, 2019
f5620b3
Update comments for DatePart
MaxGekk Sep 30, 2019
dcaf5b2
Regenerate results of date_part.sql
MaxGekk Sep 30, 2019
f202b15
Add tests for intervals to date_part.sql
MaxGekk Sep 30, 2019
dca29e5
Remove wrong test
MaxGekk Sep 30, 2019
f8a2385
Make Dongjoon and Scala style checker happy
MaxGekk Oct 1, 2019
7b1663e
Merge remote-tracking branch 'remotes/origin/master' into extract-fro…
MaxGekk Oct 8, 2019
8a494a2
Improve an example
MaxGekk Oct 8, 2019
f08531b
Precise epoch calculation from intervals
MaxGekk Oct 8, 2019
e8a61c8
Fix expected results in IntervalExpressionsSuite
MaxGekk Oct 8, 2019
f8a45b3
Revert "Precise epoch calculation from intervals"
MaxGekk Oct 12, 2019
a496d73
Precise calculation micros per month
MaxGekk Oct 12, 2019
47a0290
Revert "Precise calculation micros per month"
MaxGekk Oct 18, 2019
2099a91
Fix expected results in IntervalExpressionsSuite
MaxGekk Oct 18, 2019
d4375b5
Add the Extract prefix to all classes
MaxGekk Oct 18, 2019
5620472
Change indentation for extends to 2 spaces
MaxGekk Oct 18, 2019
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 @@ -18,7 +18,7 @@
package org.apache.spark.sql.catalyst.expressions

import java.sql.Timestamp
import java.time.{DateTimeException, Instant, LocalDate, LocalDateTime, ZoneId}
import java.time.{DateTimeException, LocalDate, LocalDateTime, ZoneId}
import java.time.temporal.IsoFields
import java.util.{Locale, TimeZone}

Expand Down Expand Up @@ -2032,10 +2032,11 @@ object DatePart {
}

@ExpressionDescription(
usage = "_FUNC_(field, source) - Extracts a part of the date/timestamp.",
usage = "_FUNC_(field, source) - Extracts a part of the date/timestamp or interval source.",
arguments = """
Arguments:
* field - selects which part of the source should be extracted. Supported string values are:
* field - selects which part of the source should be extracted.
Supported string values of `field` for dates and timestamps are:
["MILLENNIUM", ("MILLENNIA", "MIL", "MILS"),
"CENTURY", ("CENTURIES", "C", "CENT"),
"DECADE", ("DECADES", "DEC", "DECS"),
Expand All @@ -2055,7 +2056,21 @@ object DatePart {
"MILLISECONDS", ("MSEC", "MSECS", "MILLISECON", "MSECONDS", "MS"),
"MICROSECONDS", ("USEC", "USECS", "USECONDS", "MICROSECON", "US"),
"EPOCH"]
* source - a date (or timestamp) column from where `field` should be extracted
Supported string values of `field` for intervals are:
["MILLENNIUM", ("MILLENNIA", "MIL", "MILS"),
"CENTURY", ("CENTURIES", "C", "CENT"),
"DECADE", ("DECADES", "DEC", "DECS"),
"YEAR", ("Y", "YEARS", "YR", "YRS"),
"QUARTER", ("QTR"),
"MONTH", ("MON", "MONS", "MONTHS"),
"DAY", ("D", "DAYS"),
"HOUR", ("H", "HOURS", "HR", "HRS"),
"MINUTE", ("M", "MIN", "MINS", "MINUTES"),
"SECOND", ("S", "SEC", "SECONDS", "SECS"),
"MILLISECONDS", ("MSEC", "MSECS", "MILLISECON", "MSECONDS", "MS"),
"MICROSECONDS", ("USEC", "USECS", "USECONDS", "MICROSECON", "US"),
"EPOCH"]
* source - a date/timestamp or interval column from where `field` should be extracted
""",
examples = """
Examples:
Expand All @@ -2067,6 +2082,10 @@ object DatePart {
224
> SELECT _FUNC_('SECONDS', timestamp'2019-10-01 00:00:01.000001');
1.000001
> SELECT _FUNC_('days', interval 1 year 10 months 5 days);
Copy link
Member

Choose a reason for hiding this comment

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

So, feel free to tell me to go look up a reference, but I am sort of confused about the semantics. The "days" part of "interval 1 year 10 months 5 days" is 5 days, not the interval days (roughly 365 + 10 *31 + 5).

But below, the "seconds" part of "30 seconds 1 ms 1 us" is 30.001001, not 30.

So what's the number of days in "interval 1 year 10 months 5 days 12 hours"? 5 or 5.5?

Copy link
Member

Choose a reason for hiding this comment

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

Sort of answering my own question. From PostgreSQL, at least:
https://www.postgresql.org/docs/9.1/functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT

SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
Result: 16

SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
Result: 4

It seems like the answer to the second example here should be 30?

I'm getting off on a tangent, but, can you specify "interval 5 minutes 90 seconds"? if so, what's the minute part -- 5 or 6? if you can't specify that, can you specify "interval 90 seconds"? if not why not?

Just getting confused about the intended semantics of the date part of an interval!

Copy link
Member Author

Choose a reason for hiding this comment

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

So, feel free to tell me to go look up a reference, but I am sort of confused about the semantics.

Semantic is defined by internal representation of Catalyst's CalendarIntervalType. Purpose of the type is to represent components of an interval not duration of interval (see the discussions in #25022). CalendarIntervalType stores the year, months, weeks, days, hours, minutes, seconds, milliseconds, microseconds components in 2 independent variables - months and microseconds. Due to independence and unlimited (limited by long/int size) of the microseconds field, we can store more than 31 days in microseconds.
Because purpose of CalendarIntervalType is to represent interval as components but not duration, the same duration in microseconds can have multiple representations in Catalyst INTERVAL type. Let's say:
390000000 microseconds = interval 5 minutes 90 seconds = interval 6 minutes 30 seconds = interval 1 minute 330 seconds and so on.

When an user request components of an interval, we need to select one of its representation. We do that by constructing "normalized" representation in where number of years and days is unlimited (limited by int or long) and months should be in [0..12), hours is in [0, 12), minutes is [0, 60) ... microseconds is in [0, 1000000). seconds and milliseconds are special cases because they have the fractional part as well but they limited too. seconds - [0, 59.999999], milliseconds - [0, 59999.999]. This behavior is inherited from PostgreSQL. In this way, there is only one "normalized" representation of any interval from which the date_part() function extracts components.

Copy link
Member

Choose a reason for hiding this comment

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

Yeah I get why we split the months and ms part, and can see what the convenient implementation is w.r.t. the current implementation. Maybe the details of the semantics aren't that important for practical purposes.

But it does seem like this proposal doesn't match PostgreSQL in the SELECT date_part('hour', INTERVAL '4 hours 3 minutes'); case, at least. But it's impractical to follow this behavior given the internal representation.

SELECT date_part('hour', INTERVAL '1 month 1 day'); gives 24, right? because the days are separable from the months.

SELECT date_part('month', INTERVAL '1 year 1 month'); gives 13, not 1, right? because the month part isn't separable.

This feels inconsistent. What if we construed the semantics to always mean 'the given interval in the given units'? that's consistent, but doesn't quite sound like what date_part does, as it's no longer a 'part'.

Am I right about that so far?

Copy link
Member Author

Choose a reason for hiding this comment

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

But it does seem like this proposal doesn't match PostgreSQL in the SELECT date_part('hour', INTERVAL '4 hours 3 minutes');

It does. In PostgreSQL:

maxim=# SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
 date_part 
-----------
         4

In SparkSQL:

spark-sql> SELECT date_part('hour', interval 4 hours 3 minutes);
4

SELECT date_part('hour', INTERVAL '1 month 1 day'); gives 24, right? because the days are separable from the months.

No, it is 0 because the range of hours is [0, 23]:
In PostgreSQL:

maxim=# SELECT date_part('hour', INTERVAL '1 month 1 day');
 date_part 
-----------
         0

In SparkSQL:

spark-sql> SELECT date_part('hour', INTERVAL 1 month 1 day);
0

SELECT date_part('month', INTERVAL '1 year 1 month'); gives 13, not 1, right? because the month part isn't separable.

No, it gives 1.
In PostgreSQL:

maxim=# SELECT date_part('month', INTERVAL '1 year 1 month');
 date_part 
-----------
         1

In SparkSQL:

spark-sql> SELECT date_part('month', INTERVAL 1 year 1 month);
1

This feels inconsistent.

I cannot agree with you so far.

Copy link
Member

Choose a reason for hiding this comment

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

I see, that's good. So as far as you know it's consistent with PostgreSQL? and correctly returns the time-unit part of an interval, not the interval in the time-unit? in that case I'm not sure why this is correct:

date_part('seconds', interval 30 seconds 1 milliseconds 1 microseconds);
       30.001001

Shouldn't it be 30?

Copy link
Member Author

Choose a reason for hiding this comment

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

Shouldn't it be 30?

I agree with you that seconds should be 30, milliseconds should be 1, and microseconds is 1 but PostgreSQL developers decided to implement this in different way. Maybe this is because seconds, milliseconds are always have the fractional part in other PostgreSQL functions.

For seconds, it looks reasonable but I don't know what PostgreSQL developers thought of when they defined milliseconds as milliseconds in a minute:

maxim=# select date_part('milliseconds', interval '30 seconds 1 milliseconds 1 microseconds');
 date_part 
-----------
 30001.001
maxim=# select date_part('microseconds', interval '30 seconds 1 milliseconds 1 microseconds');
 date_part 
-----------
  30001001

I interpret this as the second, millisecond, microsecond form one interval component with values in the range [0, 6000000) where 0-1 digits belongs to seconds, 2-4 digits to milliseconds, and 5-7 digits to microseconds.

Precisely follow PostgreSQL implementation is still open question for me. I believe PostgreSQL has badly designed date-time API. As you can see similar date_part('HOUR', <interval>) and date_part('MILLISECONDS', <interval>) must have similar semantic but they don't.

Copy link
Member

Choose a reason for hiding this comment

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

Yeah, it seems inconsistent. Sometimes the entire interval's length is return in the given unit, sometimes just a portion of the interval matching that unit is returned. I wonder if there is any other standard to look at.

Doesn't this current PR have the same consistency question, given the current test output?

I'm mostly concerned with having consistent semantics, whatever they are. If it can't be done reasonably, hm, should we implement this?

I'm trying to figure out the use case for "a date part of an interval". I can only think of cases where the interval should be converted entirely into some unit.

Copy link
Member Author

@MaxGekk MaxGekk Oct 8, 2019

Choose a reason for hiding this comment

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

Sometimes the entire interval's length is return in the given unit ...

The entire interval's length is returned for EPOCH only, and components for other field values.

I wonder if there is any other standard to look at.

I like java 8 approach where there are 2 types java.time.Duration and java.time.Period. The first one is to store interval duration in nanosecond precision, the second one is to store components year, months, days. I would reuse this model and extend the types slightly:

  • DURATION type is to store interval duration in microseconds. long should be enough to store difference between any supported timestamps.
  • PERIOD type should store years, months, days, hours, minutes, seconds, milliseconds and microseconds. For example, (-10 years, 5 months, -3 hours, 100 microseconds).

I'm mostly concerned with having consistent semantics, whatever they are. If it can't be done reasonably, hm, should we implement this?

I don't know. From my point of semantic of each extraction field is well defined. There is a difference in implementation of this PR and PostgreSQL. As I wrote above Spark store interval in 2 variables - months and microseconds, but PostgreSQL uses 3 vars - month, day and time (in microseconds). In this way, days are independent from other components. And as consequence, hours are not limited by [0, 24):

maxim=# SELECT interval '-100 years 100 days -100 hours'; 
            interval             
---------------------------------
 -100 years +100 days -100:00:00
(1 row)

I'm trying to figure out the use case for "a date part of an interval". I can only think of cases where the interval should be converted entirely into some unit.

I can image at least 2 use cases:

  • Adjusting some of timestamp/date components. For example, we have timestamp '2019-10-08 10:11:12.123456', and we want to adjust it by -1 year 10 hours. As result, we will have timestamp '2018-10-08 20:11:12.123456'. The PERIOD type could be useful here.
  • When we need Ordered (and comparable) intervals. We can calculate absolute interval duration in some units. For example, in the query:
SELECT name, place
FROM t1, t2
WHERE t1.sellTimestamp - t2.deliveredTimestamp < interval 1 month 15 days;

Here, the DURATION should be used. We cannot use PERIOD because its values cannot be ordered. Spark's CalendarIntervalType cannot be used here too.

Copy link
Member

Choose a reason for hiding this comment

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

The entire interval's length is returned for EPOCH only, and components for other field values.

Hm, but then back to the original question; why is the answer not 30 below?

SELECT _FUNC_('seconds', interval 30 seconds 1 milliseconds 1 microseconds);
       30.001001

I'm not concerned necessarily about matching PostgreSQL, but am concerned about internal consistency. Unless I'm really missing something, these two examples here seem to have different semantics. I understand if you mean it's the natural way to implement this given the representation, but, I'm not sure that makes it right?

I think the discussion of PERIOD is separate. Here the question is the use case for date_part on an interval. I'm sort of struggling to think of when that's useful, though I accept it exists in other DBs. Your example doesn't show using date_part. I can imagine wanting to render an interval in given units -- what is the length of this whole interval in seconds? -- but that's not what this does, nor what the function name seems to imply.

That's why I'm questioning supporting this at all.

5
> SELECT _FUNC_('seconds', interval 5 hours 30 seconds 1 milliseconds 1 microseconds);
30.001001
""",
since = "3.0.0")
case class DatePart(field: Expression, source: Expression, child: Expression)
Expand All @@ -2082,9 +2101,16 @@ case class DatePart(field: Expression, source: Expression, child: Expression)
Literal(null, DoubleType)
} else {
val fieldStr = fieldEval.asInstanceOf[UTF8String].toString
DatePart.parseExtractField(fieldStr, source, {
throw new AnalysisException(s"Literals of type '$fieldStr' are currently not supported.")
})
val errMsg = s"Literals of type '$fieldStr' are currently not supported " +
s"for the ${source.dataType.catalogString} type."
if (source.dataType == CalendarIntervalType) {
ExtractIntervalPart.parseExtractField(
fieldStr,
source,
throw new AnalysisException(errMsg))
} else {
DatePart.parseExtractField(fieldStr, source, throw new AnalysisException(errMsg))
}
}
})
}
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,111 @@
/*
* Licensed to the Apache Software Foundation (ASF) under one or more
* contributor license agreements. See the NOTICE file distributed with
* this work for additional information regarding copyright ownership.
* The ASF licenses this file to You under the Apache License, Version 2.0
* (the "License"); you may not use this file except in compliance with
* the License. You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/

package org.apache.spark.sql.catalyst.expressions

import java.util.Locale

import org.apache.spark.sql.catalyst.expressions.codegen.{CodegenContext, ExprCode}
import org.apache.spark.sql.catalyst.util.IntervalUtils
import org.apache.spark.sql.catalyst.util.IntervalUtils._
import org.apache.spark.sql.types._
import org.apache.spark.unsafe.types.CalendarInterval

abstract class ExtractIntervalPart(
child: Expression,
val dataType: DataType,
func: CalendarInterval => Any,
funcName: String)
extends UnaryExpression with ExpectsInputTypes with Serializable {

override def inputTypes: Seq[AbstractDataType] = Seq(CalendarIntervalType)

override protected def nullSafeEval(interval: Any): Any = {
func(interval.asInstanceOf[CalendarInterval])
}

override protected def doGenCode(ctx: CodegenContext, ev: ExprCode): ExprCode = {
val iu = IntervalUtils.getClass.getName.stripSuffix("$")
defineCodeGen(ctx, ev, c => s"$iu.$funcName($c)")
}
}

case class ExtractIntervalMillenniums(child: Expression)
extends ExtractIntervalPart(child, IntegerType, getMillenniums, "getMillenniums")

case class ExtractIntervalCenturies(child: Expression)
extends ExtractIntervalPart(child, IntegerType, getCenturies, "getCenturies")

case class ExtractIntervalDecades(child: Expression)
extends ExtractIntervalPart(child, IntegerType, getDecades, "getDecades")

case class ExtractIntervalYears(child: Expression)
extends ExtractIntervalPart(child, IntegerType, getYears, "getYears")

case class ExtractIntervalQuarters(child: Expression)
extends ExtractIntervalPart(child, ByteType, getQuarters, "getQuarters")

case class ExtractIntervalMonths(child: Expression)
extends ExtractIntervalPart(child, ByteType, getMonths, "getMonths")

case class ExtractIntervalDays(child: Expression)
extends ExtractIntervalPart(child, LongType, getDays, "getDays")

case class ExtractIntervalHours(child: Expression)
extends ExtractIntervalPart(child, ByteType, getHours, "getHours")

case class ExtractIntervalMinutes(child: Expression)
extends ExtractIntervalPart(child, ByteType, getMinutes, "getMinutes")

case class ExtractIntervalSeconds(child: Expression)
extends ExtractIntervalPart(child, DecimalType(8, 6), getSeconds, "getSeconds")

case class ExtractIntervalMilliseconds(child: Expression)
extends ExtractIntervalPart(child, DecimalType(8, 3), getMilliseconds, "getMilliseconds")

case class ExtractIntervalMicroseconds(child: Expression)
Copy link
Contributor

Choose a reason for hiding this comment

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

not related to this PR, but we can apply the same naming policy to the related date/timestamp functions.

extends ExtractIntervalPart(child, LongType, getMicroseconds, "getMicroseconds")

// Number of seconds in 10000 years is 315576000001 (30 days per one month)
// which is 12 digits + 6 digits for the fractional part of seconds.
case class ExtractIntervalEpoch(child: Expression)
extends ExtractIntervalPart(child, DecimalType(18, 6), getEpoch, "getEpoch")

object ExtractIntervalPart {

def parseExtractField(
extractField: String,
source: Expression,
errorHandleFunc: => Nothing): Expression = extractField.toUpperCase(Locale.ROOT) match {
case "MILLENNIUM" | "MILLENNIA" | "MIL" | "MILS" => ExtractIntervalMillenniums(source)
case "CENTURY" | "CENTURIES" | "C" | "CENT" => ExtractIntervalCenturies(source)
case "DECADE" | "DECADES" | "DEC" | "DECS" => ExtractIntervalDecades(source)
case "YEAR" | "Y" | "YEARS" | "YR" | "YRS" => ExtractIntervalYears(source)
case "QUARTER" | "QTR" => ExtractIntervalQuarters(source)
case "MONTH" | "MON" | "MONS" | "MONTHS" => ExtractIntervalMonths(source)
case "DAY" | "D" | "DAYS" => ExtractIntervalDays(source)
case "HOUR" | "H" | "HOURS" | "HR" | "HRS" => ExtractIntervalHours(source)
case "MINUTE" | "M" | "MIN" | "MINS" | "MINUTES" => ExtractIntervalMinutes(source)
case "SECOND" | "S" | "SEC" | "SECONDS" | "SECS" => ExtractIntervalSeconds(source)
case "MILLISECONDS" | "MSEC" | "MSECS" | "MILLISECON" | "MSECONDS" | "MS" =>
ExtractIntervalMilliseconds(source)
case "MICROSECONDS" | "USEC" | "USECS" | "USECONDS" | "MICROSECON" | "US" =>
ExtractIntervalMicroseconds(source)
case "EPOCH" => ExtractIntervalEpoch(source)
case _ => errorHandleFunc
}
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
/*
* Licensed to the Apache Software Foundation (ASF) under one or more
* contributor license agreements. See the NOTICE file distributed with
* this work for additional information regarding copyright ownership.
* The ASF licenses this file to You under the Apache License, Version 2.0
* (the "License"); you may not use this file except in compliance with
* the License. You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/

package org.apache.spark.sql.catalyst.util

import org.apache.spark.sql.types.Decimal
import org.apache.spark.unsafe.types.CalendarInterval

object IntervalUtils {
val MONTHS_PER_YEAR: Int = 12
val MONTHS_PER_QUARTER: Byte = 3
val YEARS_PER_MILLENNIUM: Int = 1000
val YEARS_PER_CENTURY: Int = 100
val YEARS_PER_DECADE: Int = 10
val MICROS_PER_HOUR: Long = DateTimeUtils.MILLIS_PER_HOUR * DateTimeUtils.MICROS_PER_MILLIS
val MICROS_PER_MINUTE: Long = DateTimeUtils.MILLIS_PER_MINUTE * DateTimeUtils.MICROS_PER_MILLIS
val DAYS_PER_MONTH: Byte = 30
val MICROS_PER_MONTH: Long = DAYS_PER_MONTH * DateTimeUtils.SECONDS_PER_DAY
/* 365.25 days per year assumes leap year every four years */
val MICROS_PER_YEAR: Long = (36525L * DateTimeUtils.MICROS_PER_DAY) / 100

def getYears(interval: CalendarInterval): Int = {
interval.months / MONTHS_PER_YEAR
}

def getMillenniums(interval: CalendarInterval): Int = {
getYears(interval) / YEARS_PER_MILLENNIUM
}

def getCenturies(interval: CalendarInterval): Int = {
getYears(interval) / YEARS_PER_CENTURY
}

def getDecades(interval: CalendarInterval): Int = {
getYears(interval) / YEARS_PER_DECADE
}

def getMonths(interval: CalendarInterval): Byte = {
(interval.months % MONTHS_PER_YEAR).toByte
}

def getQuarters(interval: CalendarInterval): Byte = {
(getMonths(interval) / MONTHS_PER_QUARTER + 1).toByte
}

def getDays(interval: CalendarInterval): Long = {
interval.microseconds / DateTimeUtils.MICROS_PER_DAY
}

def getHours(interval: CalendarInterval): Byte = {
((interval.microseconds % DateTimeUtils.MICROS_PER_DAY) / MICROS_PER_HOUR).toByte
}

def getMinutes(interval: CalendarInterval): Byte = {
((interval.microseconds % MICROS_PER_HOUR) / MICROS_PER_MINUTE).toByte
}

def getMicroseconds(interval: CalendarInterval): Long = {
interval.microseconds % MICROS_PER_MINUTE
}

def getSeconds(interval: CalendarInterval): Decimal = {
Decimal(getMicroseconds(interval), 8, 6)
}

def getMilliseconds(interval: CalendarInterval): Decimal = {
Decimal(getMicroseconds(interval), 8, 3)
}

// Returns total number of seconds with microseconds fractional part in the given interval.
def getEpoch(interval: CalendarInterval): Decimal = {
Copy link
Member Author

Choose a reason for hiding this comment

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

var result = interval.microseconds
result += MICROS_PER_YEAR * (interval.months / MONTHS_PER_YEAR)
result += MICROS_PER_MONTH * (interval.months % MONTHS_PER_YEAR)
Decimal(result, 18, 6)
}
}
Loading