Skip to content

Commit 9e8a594

Browse files
authored
Bring EXTRACT into alignment with PostgreSQL v14 (#10027)
Bring EXTRACT into alignment with PostgreSQL v14 Before this commit, EXTRACT was treated as an alias to date_part with slightly different syntax. Both of these functions returned a float data type. PostgreSQL v14 updated EXTRACT to return a numeric data type, which makes it compliant with the SQL standard. This commit updates the EXTRACT function so that it return a numeric data type so that it matches PostgreSQL. date_part still returns a float. Additionally PostgreSQL v14 implemented EXTRACT explicitly for the DATE data type. Previously DATEs were casted to TIMESTAMPs before extracting fields from them. This commit also explicitly implements EXTRACT for DATE types, so they aren't cast to a TIMESTAMP first. A consequence of this is that time related fields (e.g. SECOND) are now rejected when trying to EXTRACT a DATE type. However, The implementation for date_part still casts DATE types to TIMESTAMP types. This means that date_part does not reject time related fields for DATE types. This implementation matches PostgreSQL. The postgres commit that implements these changes can be found here: postgres/postgres@a2da77c This commit also implements extracting EPOCHs from TIME types, which wasn't previously implemented. Fixes #9853, #9870, #10027
1 parent 1168190 commit 9e8a594

File tree

22 files changed

+1018
-276
lines changed

22 files changed

+1018
-276
lines changed

doc/user/content/release-notes.md

Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -114,6 +114,20 @@ changes that have not yet been documented.
114114
- Support the inverse [trigonometric functions](/sql/functions/#trigonometric-func)
115115
`asin`, `asinh`, `acos`, `acosh`, `atan`, `atanh`.
116116

117+
- **Breaking change.** Return an error when [`extract`](/sql/functions/extract/)
118+
is called with a [`date`] value but a time-related field (e.g., `SECOND`).
119+
120+
Previous versions of Materialize would incorrectly return `0` in these cases.
121+
The new behavior matches PostgreSQL.
122+
123+
[`date_part`](/sql/functions/date-part/) still returns a `0` in these cases,
124+
which matches the PostgreSQL behavior.
125+
126+
- **Breaking change.** Change the return type of [`extract`](/sql/functions/extract/)
127+
from [`float`](/sql/types/float/) to [`numeric`](/sql/types/numeric/).
128+
129+
This new behavior matches PostgreSQL v14.
130+
117131
{{< comment >}}
118132
Only add new release notes above this line.
119133

Lines changed: 72 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,72 @@
1+
---
2+
title: "date_part Function"
3+
description: "Returns a specified time component from a time-based value"
4+
menu:
5+
main:
6+
parent: 'sql-functions'
7+
---
8+
9+
`date_part` returns some time component from a time-based value, such as the year from a Timestamp.
10+
It is mostly functionally equivalent to the function [`EXTRACT`](../extract), except to maintain
11+
PostgreSQL compatibility, `date_part` returns values of type [`float`](../../types/float). This can
12+
result in a loss of precision in certain uses. Using [`EXTRACT`](../extract) is recommended instead.
13+
14+
## Signatures
15+
16+
{{< diagram "func-date-part.svg" >}}
17+
18+
Parameter | Type | Description
19+
----------|---------------------------------------------------------------------------------------------------------------------------------------------------------------|------------
20+
_val_ | [`time`](../../types/time), [`timestamp`](../../types/timestamp), [`timestamp with time zone`](../../types/timestamptz), [`interval`](../../types/interval), [`date`](../../types/date) | The value from which you want to extract a component. vals of type [`date`](../../types/date) are first cast to type [`timestamp`](../../types/timestamp).
21+
22+
### Arguments
23+
24+
`date_part` supports multiple synonyms for most time periods.
25+
26+
Time period | Synonyms
27+
------------|---------
28+
epoch | `EPOCH`
29+
millennium | `MIL`, `MILLENNIUM`, `MILLENNIA`
30+
century | `C`, `CENT`, `CENTURY`, `CENTURIES`
31+
decade | `DEC`, `DECS`, `DECADE`, `DECADES`
32+
year | `Y`, `YEAR`, `YEARS`, `YR`, `YRS`
33+
quarter | `QTR`, `QUARTER`
34+
month | `MON`, `MONS`, `MONTH`, `MONTHS`
35+
week | `W`, `WEEK`, `WEEKS`
36+
day | `D`, `DAY`, `DAYS`
37+
hour |`H`, `HR`, `HRS`, `HOUR`, `HOURS`
38+
minute | `M`, `MIN`, `MINS`, `MINUTE`, `MINUTES`
39+
second | `S`, `SEC`, `SECS`, `SECOND`, `SECONDS`
40+
microsecond | `US`, `USEC`, `USECS`, `USECONDS`, `MICROSECOND`, `MICROSECONDS`
41+
millisecond | `MS`, `MSEC`, `MSECS`, `MSECONDS`, `MILLISECOND`, `MILLISECONDS`
42+
day of week |`DOW`
43+
ISO day of week | `ISODOW`
44+
day of year | `DOY`
45+
46+
### Return value
47+
48+
`date_part` returns a [`float`](../../types/float) value.
49+
50+
## Examples
51+
52+
### Extract second from timestamptz
53+
54+
```sql
55+
SELECT date_part('S', TIMESTAMP '2006-01-02 15:04:05.06');
56+
```
57+
```nofmt
58+
date_part
59+
-----------
60+
5.06
61+
```
62+
63+
### Extract century from date
64+
65+
```sql
66+
SELECT date_part('CENTURIES', DATE '2006-01-02');
67+
```
68+
```nofmt
69+
date_part
70+
-----------
71+
21
72+
```

doc/user/content/sql/functions/extract.md

Lines changed: 11 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -12,9 +12,9 @@ menu:
1212

1313
{{< diagram "func-extract.svg" >}}
1414

15-
Parameter | Type | Description
16-
----------|-----------------------------------------------------------------------------------------------------------------------------------------------------|------------
17-
_val_ | [`date`](../../types/date), [`time`](../../types/time), [`timestamp`](../../types/timestamp), [`timestamp with time zone`](../../types/timestamptz) | The value from which you want to extract a component.
15+
Parameter | Type | Description
16+
----------|-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|------------
17+
_val_ | [`date`](../../types/date), [`time`](../../types/time), [`timestamp`](../../types/timestamp), [`timestamp with time zone`](../../types/timestamptz), [`interval`](../../types/interval) | The value from which you want to extract a component.
1818

1919
### Arguments
2020

@@ -42,30 +42,28 @@ decade | `DEC`, `DECS`, `DECADE`, `DECADES`
4242

4343
### Return value
4444

45-
`EXTRACT` returns a [`float`](../../types/float) value.
45+
`EXTRACT` returns a [`numeric`](../../types/numeric) value.
4646

4747
## Examples
4848

4949
### Extract second from timestamptz
5050

5151
```sql
52-
SELECT EXTRACT(S FROM TIMESTAMP '2006-01-02 15:04:05.06')
53-
AS sec_extr;
52+
SELECT EXTRACT(S FROM TIMESTAMP '2006-01-02 15:04:05.06');
5453
```
5554
```nofmt
56-
sec_extr
57-
----------
58-
5.06
55+
extract
56+
---------
57+
5.06
5958
```
6059

6160
### Extract century from date
6261

6362
```sql
64-
SELECT EXTRACT(CENTURIES FROM DATE '2006-01-02')
65-
AS sec_extr;
63+
SELECT EXTRACT(CENTURIES FROM DATE '2006-01-02');
6664
```
6765
```nofmt
68-
sec_extr
69-
----------
66+
extract
67+
---------
7068
21
7169
```

doc/user/data/sql_funcs.yml

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -421,10 +421,14 @@
421421
description: Largest `time_component` <= `val`
422422
url: date-trunc
423423

424-
- signature: EXTRACT(extract_expr) -> float
424+
- signature: EXTRACT(extract_expr) -> numeric
425425
description: Specified time component from value
426426
url: extract
427427

428+
- signature: 'date_part(time_component: str, val: timestamp) -> float'
429+
description: Specified time component from value
430+
url: date-part
431+
428432
- signature: mz_logical_timestamp() -> numeric
429433
description: 'The logical time at which a query executes. Used for temporal filters and internal debugging.'
430434
url: now_and_mz_logical_timestamp

doc/user/layouts/partials/sql-grammar/func-date-part.svg

Lines changed: 195 additions & 0 deletions
Loading

doc/user/sql-grammar/sql-grammar.bnf

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -346,6 +346,8 @@ func_date_trunc ::=
346346
'date_trunc' '(' "'" ( 'microseconds' | 'milliseconds' | 'second' | 'minute' | 'hour' | 'day' | 'week' | 'month' | 'quarter' | 'year' | 'decade' | 'century' | 'millenium' ) "'" ',' ts_val ')'
347347
func_extract ::=
348348
'EXTRACT' '(' ( 'EPOCH' | 'MILLENNIUM' | 'CENTURY' | 'DECADE' | 'YEAR' | 'QUARTER' | 'MONTH' | 'WEEK' | 'DAY' | 'HOUR' | 'MINUTE' | 'SECOND' | 'MICROSECOND' | 'MILLISECOND' | 'DOW' | 'ISODOW' | 'DOY' ) 'FROM' val ')'
349+
func_date_part ::=
350+
'date_part' '(' "'" ( 'epoch' | 'millennium' | 'century' | 'decade' | 'year' | 'quarter' | 'month' | 'week' | 'dat' | 'hour' | 'minute' | 'second' | 'microsecond' | 'millisecond' | 'dow' | 'isodow' | 'doy' ) "'" ',' val ')'
349351
func_length ::=
350352
'length' '(' str (',' encoding_name)? ')'
351353
func_substring ::=

0 commit comments

Comments
 (0)