Skip to content
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

implement PostgreSQL-compatible interval type #1444

Merged
merged 4 commits into from
Jan 14, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
1 change: 1 addition & 0 deletions Cargo.lock

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

1 change: 1 addition & 0 deletions doc/user/sql/types/_index.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ Type | Use | Size (bytes) | Syntax
[`decimal`](decimal) | Signed exact number with user-defined precision and scale | 16 | `1.23`
[`float`](float) | Signed variable-precision, inexact number | 8 | `1.23`
[`int`](int) | Signed integer | 8 | `123`
[`interval`](interval) | Duration of time | 32 | `INTERVAL '1-2 3 4:5:6.7'`
[`string`](string) | Unicode string | Variable | `'foo'`
[`timestamp`](timestamp) | Date and time | 8 | `TIMESTAMP '2007-02-01 15:04:05'`
[`timestamptz`](timestamp) | Date and time with timezone | 8 | `TIMESTAMPTZ '2007-02-01 15:04:05+06'`
177 changes: 177 additions & 0 deletions doc/user/sql/types/interval.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,177 @@
---
title: "interval Data Type"
description: "Expresses a duration of time"
menu:
main:
parent: "sql-types"
---

`interval` data expresses a duration of time.

| Detail | Info |
| ---------------- | ---------------------------------------------------------------------------------------------------- |
| **Quick Syntax** | `INTERVAL '1' MINUTE` <br/> `INTERVAL '1-2 3 4:5:6.7'` <br/>`INTERVAL '1 year 2.3 days 4.5 seconds'` |
| **Size** | 32 bytes |
| **Min value** | -9223372036854775807 months, -9223372036854775807 seconds, -999999999 nanoseconds |
| **Max value** | 9223372036854775807 months, 9223372036854775807 seconds, 999999999 nanoseconds |

## Syntax

#### INTERVAL

{{< diagram "type-interval-val.html" >}}

#### `time_expr`

{{< diagram "type-interval-time-expr.html" >}}

#### `time_unit`

{{< diagram "time-units.html" >}}

| Field | Definition |
| ---------------- | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| _head_time_unit_ | Return an interval without `time_unit`s larger than `head_time_unit`. Note that this differs from PostgreSQL's implementation, which ignores this clause. |
| _tail_time_unit_ | 1. Return an interval without `time_unit` smaller than `tail_time_unit`.<br/><br/>2. If the final `time_expr` is only a number, treat the `time_expr` as belonging to `tail_time_unit`. This is the case of the most common `interval` format like `INTERVAL '1' MINUTE`. |

## Details

### `time_expr` Syntax

Materialize strives for full PostgreSQL compatibility with `time_exprs`, which
offers support for two types of `time_expr` syntax:

- SQL Standard, i.e. `'Y-M D H:M:S.NS'`
- PostgreSQL, i.e. repeated `int.frac time_unit`, e.g.:
- `'1 year 2 months 3.4 days 5 hours 6 minutes 7.8 seconds'`
- `'1y 2mon 3.4d 5h 6m 7.8s'`

Like PostgreSQL, Materialize's implementation includes the following
stipulations:

- You can freely mix SQL Standard- and PostgreSQL-style `time_expr`s.
- You can write `time_expr`s in any order, e.g `'H:M:S.NS Y-M'`.
- Each `time_unit` can only be written once.
- SQL Standard `time_expr` uses the following groups of `time_unit`s:

- `Y-M`
- `D`
- `H:M:S.NS`

Using a SQL Standard `time_expr` to write to any of these `time_units`
writes to all other `time_units` in the same group, even if that `time_unit`
is not explicitly referenced.

For example, the `time_expr` `'1:2'` (1 hour, 2 minutes) also writes a value of
0 seconds. You cannot then include another `time_expr` which writes to the
seconds `time_unit`.

- Only PostgreSQL `time_expr`s support non-second fractional `time_units`, e.g.
`1.2 days`. Materialize only supports 9 places of decimal precision.

### Valid casts

`interval` does not support any casts.

## Examples

```sql
SELECT INTERVAL '1' MINUTE AS interval_m;
```

```nofmt
interval_m
------------
00:01:00
```

<hr/>

### SQL Standard syntax

```sql
SELECT INTERVAL '1-2 3 4:5:6.7' AS interval_p;
```

```nofmt
interval_f
-----------------------------------
1 year 2 months 3 days 04:05:06.7
```

<hr/>

### PostgreSQL syntax

```sql
SELECT INTERVAL '1 year 2.3 days 4.5 seconds' AS interval_p;
```

```nofmt
interval_p
--------------------------
1 year 2 days 07:12:04.5
```

<hr/>

### Negative intervals

`interval_n` demonstrates using negative and positive components in an interval.

```sql
SELECT INTERVAL '-1 day 2:3:4.5' AS interval_n;
```

```nofmt
interval_n
-------------
-21:56:55.5
```

<hr/>

### Truncating interval

`interval_r` demonstrates how `head_time_unit` and `tail_time_unit` truncate the
interval.

```sql
SELECT INTERVAL '1-2 3 4:5:6.7' DAY TO MINUTE AS interval_r;
```

```nofmt
interval_r
-----------------
3 days 04:05:00
```

<hr/>

### Complex example

`interval_w` demonstrates both mixing SQL Standard and PostgreSQL `time_expr`,
as well as using `tail_time_unit` to control the `time_unit` of the last value
of the `interval` string.

```sql
SELECT INTERVAL '1 day 2-3 4' MINUTE AS interval_w;
```

```nofmt
interval_w
---------------------------------
2 years 3 months 1 day 00:04:00
```

### Interaction with Timestamps

```sql
SELECT TIMESTAMP '2020-01-01 8:00:00' + INTERVAL '1' DAY AS ts_interaction;
```

```nofmt
ts_interaction
-------------------------------
2020-01-02 08:00:00.000000000
```
65 changes: 35 additions & 30 deletions src/expr/scalar/func.rs
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ use serde::{Deserialize, Serialize};
use repr::decimal::MAX_DECIMAL_PRECISION;
use repr::jsonb::Jsonb;
use repr::regex::Regex;
use repr::{strconv, ColumnType, Datum, Interval, RowArena, ScalarType};
use repr::{strconv, ColumnType, Datum, RowArena, ScalarType};

use self::format::DateTimeFormat;
pub use crate::like::build_like_regex_from_string;
Expand Down Expand Up @@ -485,11 +485,10 @@ fn add_float64<'a>(a: Datum<'a>, b: Datum<'a>) -> Datum<'a> {
fn add_timestamp_interval<'a>(a: Datum<'a>, b: Datum<'a>) -> Datum<'a> {
let dt = a.unwrap_timestamp();
Datum::Timestamp(match b {
Datum::Interval(Interval::Months(months)) => add_timestamp_months(dt, months),
Datum::Interval(Interval::Duration {
is_positive,
duration,
}) => add_timestamp_duration(dt, is_positive, duration),
Datum::Interval(i) => {
let dt = add_timestamp_months(dt, i.months);
add_timestamp_duration(dt, i.is_positive_dur, i.duration)
}
_ => panic!("Tried to do timestamp addition with non-interval: {:?}", b),
})
}
Expand All @@ -498,11 +497,10 @@ fn add_timestamptz_interval<'a>(a: Datum<'a>, b: Datum<'a>) -> Datum<'a> {
let dt = a.unwrap_timestamptz().naive_utc();

let new_ndt = match b {
Datum::Interval(Interval::Months(months)) => add_timestamp_months(dt, months),
Datum::Interval(Interval::Duration {
is_positive,
duration,
}) => add_timestamp_duration(dt, is_positive, duration),
Datum::Interval(i) => {
let dt = add_timestamp_months(dt, i.months);
add_timestamp_duration(dt, i.is_positive_dur, i.duration)
}
_ => panic!("Tried to do timestamp addition with non-interval: {:?}", b),
};

Expand Down Expand Up @@ -537,14 +535,12 @@ fn floor_decimal<'a>(a: Datum<'a>, scale: u8) -> Datum<'a> {

fn sub_timestamp_interval<'a>(a: Datum<'a>, b: Datum<'a>) -> Datum<'a> {
let inverse = match b {
Datum::Interval(Interval::Months(months)) => Datum::Interval(Interval::Months(-months)),
Datum::Interval(Interval::Duration {
is_positive,
duration,
}) => Datum::Interval(Interval::Duration {
is_positive: !is_positive,
duration,
}),
Datum::Interval(i) => {
let mut res = i;
res.months = -res.months;
res.is_positive_dur = !res.is_positive_dur;
Datum::Interval(res)
}
_ => panic!(
"Tried to do timestamptz subtraction with non-interval: {:?}",
b
Expand All @@ -555,14 +551,12 @@ fn sub_timestamp_interval<'a>(a: Datum<'a>, b: Datum<'a>) -> Datum<'a> {

fn sub_timestamptz_interval<'a>(a: Datum<'a>, b: Datum<'a>) -> Datum<'a> {
let inverse = match b {
Datum::Interval(Interval::Months(months)) => Datum::Interval(Interval::Months(-months)),
Datum::Interval(Interval::Duration {
is_positive,
duration,
}) => Datum::Interval(Interval::Duration {
is_positive: !is_positive,
duration,
}),
Datum::Interval(i) => {
let mut res = i;
res.months = -res.months;
res.is_positive_dur = !res.is_positive_dur;
Datum::Interval(res)
}
_ => panic!(
"Tried to do timestamptz subtraction with non-interval: {:?}",
b
Expand Down Expand Up @@ -784,6 +778,13 @@ fn neg_decimal<'a>(a: Datum<'a>) -> Datum<'a> {
Datum::from(-a.unwrap_decimal())
}

pub fn neg_interval<'a>(a: Datum<'a>) -> Datum<'a> {
let mut i = a.unwrap_interval();
i.is_positive_dur = !i.is_positive_dur;
i.months = -i.months;
Datum::from(i)
}

fn sqrt_float32<'a>(a: Datum<'a>) -> Datum<'a> {
let x = a.unwrap_float32();
if x < 0.0 {
Expand Down Expand Up @@ -1705,6 +1706,7 @@ pub enum UnaryFunc {
NegFloat32,
NegFloat64,
NegDecimal,
NegInterval,
SqrtFloat32,
SqrtFloat64,
AbsInt32,
Expand Down Expand Up @@ -1823,6 +1825,7 @@ impl UnaryFunc {
UnaryFunc::NegFloat32 => neg_float32(a),
UnaryFunc::NegFloat64 => neg_float64(a),
UnaryFunc::NegDecimal => neg_decimal(a),
UnaryFunc::NegInterval => neg_interval(a),
UnaryFunc::AbsInt32 => abs_int32(a),
UnaryFunc::AbsInt64 => abs_int64(a),
UnaryFunc::AbsFloat32 => abs_float32(a),
Expand Down Expand Up @@ -1953,7 +1956,8 @@ impl UnaryFunc {
| UnaryFunc::NegInt64
| UnaryFunc::NegFloat32
| UnaryFunc::NegFloat64
| UnaryFunc::NegDecimal => true,
| UnaryFunc::NegDecimal
| UnaryFunc::NegInterval => true,
_ => false,
};
// This debug assertion is an attempt to ensure that this function
Expand Down Expand Up @@ -2065,8 +2069,8 @@ impl UnaryFunc {
SqrtFloat32 => ColumnType::new(ScalarType::Float32).nullable(true),
SqrtFloat64 => ColumnType::new(ScalarType::Float64).nullable(true),

Not | NegInt32 | NegInt64 | NegFloat32 | NegFloat64 | NegDecimal | AbsInt32
| AbsInt64 | AbsFloat32 | AbsFloat64 => input_type,
Not | NegInt32 | NegInt64 | NegFloat32 | NegFloat64 | NegDecimal | NegInterval
| AbsInt32 | AbsInt64 | AbsFloat32 | AbsFloat64 => input_type,

ExtractIntervalYear
| ExtractIntervalMonth
Expand Down Expand Up @@ -2156,6 +2160,7 @@ impl fmt::Display for UnaryFunc {
UnaryFunc::NegFloat32 => f.write_str("-"),
UnaryFunc::NegFloat64 => f.write_str("-"),
UnaryFunc::NegDecimal => f.write_str("-"),
UnaryFunc::NegInterval => f.write_str("-"),
UnaryFunc::AbsInt32 => f.write_str("abs"),
UnaryFunc::AbsInt64 => f.write_str("abs"),
UnaryFunc::AbsFloat32 => f.write_str("abs"),
Expand Down
41 changes: 12 additions & 29 deletions src/pgrepr/src/value/interval.rs
Original file line number Diff line number Diff line change
Expand Up @@ -34,21 +34,11 @@ impl ToSql for Interval {
//
// Postgres implementation: https://github.com/postgres/postgres/blob/517bf2d91/src/backend/utils/adt/timestamp.c#L1008
// Diesel implementation: https://github.com/diesel-rs/diesel/blob/a8b52bd05/diesel/src/pg/types/date_and_time/mod.rs#L39
match self.0 {
repr::Interval::Months(months) => {
out.put_i64(0);
out.put_i32(0);
out.put_i32(months as i32);
}
repr::Interval::Duration {
duration,
is_positive,
} => {
out.put_i64((duration.as_micros() as i64) * if is_positive { 1 } else { -1 });
out.put_i32(0);
out.put_i32(0);
}
}
out.put_i64(
(self.0.duration.as_micros() as i64) * if self.0.is_positive_dur { 1 } else { -1 },
);
out.put_i32(0);
out.put_i32(self.0.months as i32);
Ok(IsNull::No)
}

Expand All @@ -64,22 +54,15 @@ impl ToSql for Interval {

impl<'a> FromSql<'a> for Interval {
fn from_sql(_: &Type, mut raw: &'a [u8]) -> Result<Interval, Box<dyn Error + Sync + Send>> {
let micros = raw.read_i64::<NetworkEndian>()?;
let mut micros = raw.read_i64::<NetworkEndian>()?;
let days = raw.read_i32::<NetworkEndian>()?;
let months = raw.read_i32::<NetworkEndian>()?;
if micros == 0 && days == 0 && months != 0 {
Ok(Interval(repr::Interval::Months(months.into())))
} else if (micros != 0 || days != 0) && months == 0 {
let micros = micros + ((days as i64) * 1000 * 1000 * 60 * 60 * 24);
let is_positive = micros > 0;
let micros = micros.abs() as u64;
Ok(Interval(repr::Interval::Duration {
is_positive,
duration: Duration::from_micros(micros),
}))
} else {
Err("mixed intervals are not supported".into())
}
micros += (days as i64) * 1000 * 1000 * 60 * 60 * 24;
Ok(Interval(repr::Interval {
months: months.into(),
is_positive_dur: micros > 0,
duration: Duration::from_micros(micros.abs() as u64),
}))
}

fn accepts(ty: &Type) -> bool {
Expand Down