Skip to content

Commit

Permalink
Merge #42613 #42622
Browse files Browse the repository at this point in the history
42613: sql: add cast support to TimeTZ r=otan a=otan

Refs: #26097

Added the various casts supported by postgres for `timetz`:

```
otan=# select
  castcontext,
  f.typname as "from",
  t.typname as to
from pg_cast
join pg_type as f ON (f.typelem = castsource)
join pg_type as t on (t.typelem=casttarget)
where
  castsource = 'timetz'::regtype or
  casttarget = 'timetz'::regtype;
 castcontext |     from     |   to
-------------+--------------+---------
 i           | _time        | _timetz
 a           | _timestamptz | _timetz
 i           | _timetz      | _timetz
 a           | _timetz      | _time
(4 rows)
```

No release not required as this will be combined with a fully fleshed
note for TimeTZ.

Release note: None

42622: builtins: make date_trunc(week, timestamp[tz]) truncate to Monday r=otan a=otan

Resolves #42612

Release note (sql change): The `date_trunc` function, when used with
`week`, previously truncated to Sunday. This PR will make it follow
postgres more closely by truncating to Monday instead.

Co-authored-by: Oliver Tan <otan@cockroachlabs.com>
  • Loading branch information
craig[bot] and otan committed Nov 20, 2019
3 parents b65495e + bebfb18 + 495ecfb commit 9b625f2
Show file tree
Hide file tree
Showing 5 changed files with 131 additions and 89 deletions.
168 changes: 84 additions & 84 deletions pkg/sql/logictest/testdata/logic_test/datetime
Original file line number Diff line number Diff line change
Expand Up @@ -454,8 +454,8 @@ INSERT INTO ex VALUES
(9, 'month', '2001-04-10 12:04:59', 4, '2001-04-01 00:00:00'),
(10, 'month', '2016-02-10 19:46:33.306157519', 2, '2016-02-01 00:00:00'),
(11, 'months', '2016-02-10 19:46:33.306157519', 2, '2016-02-01 00:00:00'),
(12, 'week', '2001-04-10 12:04:59', 15, '2001-04-08 00:00:00'),
(13, 'weeks', '2001-01-05 12:04:59', 1, '2000-12-31 00:00:00'),
(12, 'week', '2001-04-10 12:04:59', 15, '2001-04-09 00:00:00'),
(13, 'weeks', '2001-01-05 12:04:59', 1, '2001-01-01 00:00:00'),
(14, 'day', '2001-04-10 12:04:59', 10, '2001-04-10 00:00:00'),
(15, 'day', '2016-02-10 19:46:33.306157519', 10, '2016-02-10 00:00:00'),
(16, 'days', '2016-02-10 19:46:33.306157519', 10, '2016-02-10 00:00:00'),
Expand Down Expand Up @@ -630,93 +630,93 @@ SELECT extract(hours from '2016-02-10 19:46:33.306157519-04'::timestamptz)
----
19

query IBT
SELECT k, date_trunc(element, input::timestamp) = date_trunc_result, date_trunc(element, input::timestamp)::string
query ITTBT
SELECT k, element, input, date_trunc(element, input::timestamp) = date_trunc_result, date_trunc(element, input::timestamp)::string
FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
----
1 true 2001-01-01 00:00:00+00:00
2 true 2016-01-01 00:00:00+00:00
3 true 2016-01-01 00:00:00+00:00
4 true 2001-04-01 00:00:00+00:00
5 true 2016-01-01 00:00:00+00:00
6 true 2016-04-01 00:00:00+00:00
7 true 2016-07-01 00:00:00+00:00
8 true 2016-10-01 00:00:00+00:00
9 true 2001-04-01 00:00:00+00:00
10 true 2016-02-01 00:00:00+00:00
11 true 2016-02-01 00:00:00+00:00
12 true 2001-04-08 00:00:00+00:00
13 true 2000-12-31 00:00:00+00:00
14 true 2001-04-10 00:00:00+00:00
15 true 2016-02-10 00:00:00+00:00
16 true 2016-02-10 00:00:00+00:00
24 true 2001-04-10 12:00:00+00:00
25 true 2016-02-10 19:00:00+00:00
26 true 2016-02-10 23:00:00+00:00
27 true 2016-02-10 19:00:00+00:00
28 true 2016-02-10 23:00:00+00:00
29 true 2001-04-10 12:04:00+00:00
30 true 2016-02-10 19:46:00+00:00
31 true 2016-02-10 19:46:00+00:00
32 true 2001-04-10 12:04:59+00:00
33 true 2016-02-10 19:46:33+00:00
34 true 2016-02-10 19:46:33+00:00
35 true 2001-04-10 12:04:59.234+00:00
36 true 2016-02-10 19:46:33.306+00:00
37 true 2016-02-10 19:46:33.306+00:00
38 true 2001-04-10 12:04:59.345654+00:00
39 true 2016-02-10 19:46:33.306158+00:00
40 true 2016-02-10 19:46:33.306158+00:00
45 true 2000-01-01 00:00:00+00:00
46 true -2020-01-01 00:00:00+00:00
47 true 2001-01-01 00:00:00+00:00
48 true -0099-01-01 00:00:00+00:00
49 true 2001-01-01 00:00:00+00:00
50 true -1999-01-01 00:00:00+00:00
1 year 2001-04-10 12:04:59 +0000 UTC true 2001-01-01 00:00:00+00:00
2 year 2016-02-10 19:46:33.306158 +0000 UTC true 2016-01-01 00:00:00+00:00
3 years 2016-02-10 19:46:33.306158 +0000 UTC true 2016-01-01 00:00:00+00:00
4 quarter 2001-04-10 12:04:59 +0000 UTC true 2001-04-01 00:00:00+00:00
5 quarter 2016-02-10 19:46:33.306158 +0000 UTC true 2016-01-01 00:00:00+00:00
6 quarter 2016-05-10 19:46:33.306158 +0000 UTC true 2016-04-01 00:00:00+00:00
7 quarter 2016-09-09 19:46:33.306158 +0000 UTC true 2016-07-01 00:00:00+00:00
8 quarter 2016-10-10 19:46:33.306158 +0000 UTC true 2016-10-01 00:00:00+00:00
9 month 2001-04-10 12:04:59 +0000 UTC true 2001-04-01 00:00:00+00:00
10 month 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-01 00:00:00+00:00
11 months 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-01 00:00:00+00:00
12 week 2001-04-10 12:04:59 +0000 UTC true 2001-04-09 00:00:00+00:00
13 weeks 2001-01-05 12:04:59 +0000 UTC true 2001-01-01 00:00:00+00:00
14 day 2001-04-10 12:04:59 +0000 UTC true 2001-04-10 00:00:00+00:00
15 day 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 00:00:00+00:00
16 days 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 00:00:00+00:00
24 hour 2001-04-10 12:04:59 +0000 UTC true 2001-04-10 12:00:00+00:00
25 hour 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:00:00+00:00
26 hour 2016-02-10 23:46:33.306158 +0000 UTC true 2016-02-10 23:00:00+00:00
27 hours 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:00:00+00:00
28 hours 2016-02-10 23:46:33.306158 +0000 UTC true 2016-02-10 23:00:00+00:00
29 minute 2001-04-10 12:04:59 +0000 UTC true 2001-04-10 12:04:00+00:00
30 minute 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:00+00:00
31 minutes 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:00+00:00
32 second 2001-04-10 12:04:59.234 +0000 UTC true 2001-04-10 12:04:59+00:00
33 second 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33+00:00
34 seconds 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33+00:00
35 millisecond 2001-04-10 12:04:59.234567 +0000 UTC true 2001-04-10 12:04:59.234+00:00
36 millisecond 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33.306+00:00
37 milliseconds 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33.306+00:00
38 microsecond 2001-04-10 12:04:59.345654 +0000 UTC true 2001-04-10 12:04:59.345654+00:00
39 microsecond 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33.306158+00:00
40 microseconds 2016-02-10 19:46:33.306158 +0000 UTC true 2016-02-10 19:46:33.306158+00:00
45 decade 2001-04-10 12:04:59 +0000 UTC true 2000-01-01 00:00:00+00:00
46 decade -2015-02-10 19:46:33.306158 +0000 UTC true -2020-01-01 00:00:00+00:00
47 century 2016-02-10 19:46:33.306158 +0000 UTC true 2001-01-01 00:00:00+00:00
48 century -0003-02-10 19:46:33.306158 +0000 UTC true -0099-01-01 00:00:00+00:00
49 millennium 2016-02-10 19:46:33.306158 +0000 UTC true 2001-01-01 00:00:00+00:00
50 millennium -1003-02-10 19:46:33.306158 +0000 UTC true -1999-01-01 00:00:00+00:00

query IBT
SELECT k, date_trunc(element, input::timestamptz) = date_trunc_result, date_trunc(element, input::timestamptz)::string
FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
----
1 true 2001-01-01 00:00:00+00:00
2 true 2016-01-01 00:00:00+00:00
3 true 2016-01-01 00:00:00+00:00
4 true 2001-04-01 00:00:00+00:00
5 true 2016-01-01 00:00:00+00:00
6 true 2016-04-01 00:00:00+00:00
7 true 2016-07-01 00:00:00+00:00
8 true 2016-10-01 00:00:00+00:00
9 true 2001-04-01 00:00:00+00:00
10 true 2016-02-01 00:00:00+00:00
11 true 2016-02-01 00:00:00+00:00
12 true 2001-04-08 00:00:00+00:00
13 true 2000-12-31 00:00:00+00:00
14 true 2001-04-10 00:00:00+00:00
15 true 2016-02-10 00:00:00+00:00
16 true 2016-02-10 00:00:00+00:00
24 true 2001-04-10 12:00:00+00:00
25 true 2016-02-10 19:00:00+00:00
26 true 2016-02-10 23:00:00+00:00
27 true 2016-02-10 19:00:00+00:00
28 true 2016-02-10 23:00:00+00:00
29 true 2001-04-10 12:04:00+00:00
30 true 2016-02-10 19:46:00+00:00
31 true 2016-02-10 19:46:00+00:00
32 true 2001-04-10 12:04:59+00:00
33 true 2016-02-10 19:46:33+00:00
34 true 2016-02-10 19:46:33+00:00
35 true 2001-04-10 12:04:59.234+00:00
36 true 2016-02-10 19:46:33.306+00:00
37 true 2016-02-10 19:46:33.306+00:00
38 true 2001-04-10 12:04:59.345654+00:00
39 true 2016-02-10 19:46:33.306158+00:00
40 true 2016-02-10 19:46:33.306158+00:00
45 true 2000-01-01 00:00:00+00:00
46 true -2020-01-01 00:00:00+00:00
47 true 2001-01-01 00:00:00+00:00
48 true -0099-01-01 00:00:00+00:00
49 true 2001-01-01 00:00:00+00:00
50 true -1999-01-01 00:00:00+00:00
1 true 2001-01-01 00:00:00+00:00
2 true 2016-01-01 00:00:00+00:00
3 true 2016-01-01 00:00:00+00:00
4 true 2001-04-01 00:00:00+00:00
5 true 2016-01-01 00:00:00+00:00
6 true 2016-04-01 00:00:00+00:00
7 true 2016-07-01 00:00:00+00:00
8 true 2016-10-01 00:00:00+00:00
9 true 2001-04-01 00:00:00+00:00
10 true 2016-02-01 00:00:00+00:00
11 true 2016-02-01 00:00:00+00:00
12 true 2001-04-09 00:00:00+00:00
13 true 2001-01-01 00:00:00+00:00
14 true 2001-04-10 00:00:00+00:00
15 true 2016-02-10 00:00:00+00:00
16 true 2016-02-10 00:00:00+00:00
24 true 2001-04-10 12:00:00+00:00
25 true 2016-02-10 19:00:00+00:00
26 true 2016-02-10 23:00:00+00:00
27 true 2016-02-10 19:00:00+00:00
28 true 2016-02-10 23:00:00+00:00
29 true 2001-04-10 12:04:00+00:00
30 true 2016-02-10 19:46:00+00:00
31 true 2016-02-10 19:46:00+00:00
32 true 2001-04-10 12:04:59+00:00
33 true 2016-02-10 19:46:33+00:00
34 true 2016-02-10 19:46:33+00:00
35 true 2001-04-10 12:04:59.234+00:00
36 true 2016-02-10 19:46:33.306+00:00
37 true 2016-02-10 19:46:33.306+00:00
38 true 2001-04-10 12:04:59.345654+00:00
39 true 2016-02-10 19:46:33.306158+00:00
40 true 2016-02-10 19:46:33.306158+00:00
45 true 2000-01-01 00:00:00+00:00
46 true -2020-01-01 00:00:00+00:00
47 true 2001-01-01 00:00:00+00:00
48 true -0099-01-01 00:00:00+00:00
49 true 2001-01-01 00:00:00+00:00
50 true -1999-01-01 00:00:00+00:00

query T
SELECT date_trunc('millennia', '2000-02-10 19:46:33.306157519-04'::timestamptz)::string
Expand Down Expand Up @@ -758,8 +758,8 @@ FROM ex WHERE date_trunc_result IS NOT NULL ORDER BY k
9 true 2001-04-01 00:00:00+00:00
10 true 2016-02-01 00:00:00+00:00
11 true 2016-02-01 00:00:00+00:00
12 true 2001-04-08 00:00:00+00:00
13 true 2000-12-31 00:00:00+00:00
12 true 2001-04-09 00:00:00+00:00
13 true 2001-01-01 00:00:00+00:00
14 true 2001-04-10 00:00:00+00:00
15 true 2016-02-10 00:00:00+00:00
16 true 2016-02-10 00:00:00+00:00
Expand Down
26 changes: 26 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/timetz
Original file line number Diff line number Diff line change
Expand Up @@ -46,3 +46,29 @@ query TTI
SELECT a::string, b::string, c FROM timetz_test WHERE a = b ORDER BY c
----
15:00:00+03:00:00 15:00:00+03:00:00 5

# Test various casts involving different timezones.
subtest cast_tests

statement ok
SET TIME ZONE -5

query T
SELECT '11:00+03:00'::timetz::time
----
0000-01-01 11:00:00 +0000 UTC

# This should take the timezone in the background.
query T
SELECT '11:00'::time::timetz
----
0000-01-01 11:00:00 -0500 -0500

# This should observe the time and zone from the timestamp.
query T
SELECT '2001-01-01 11:00+04:00'::timestamptz::timetz
----
0000-01-01 11:00:00 +0400 +0400

statement ok
SET TIME ZONE UTC
11 changes: 8 additions & 3 deletions pkg/sql/sem/builtins/builtins.go
Original file line number Diff line number Diff line change
Expand Up @@ -4819,9 +4819,14 @@ func truncateTimestamp(
day, hour, min, sec, nsec = dayTrunc, hourTrunc, minTrunc, secTrunc, nsecTrunc

case "week", "weeks":
// Subtract (day of week * nanoseconds per day) to get date as of previous Sunday.
previousSunday := fromTime.Add(time.Duration(-1 * int64(fromTime.Weekday()) * int64(time.Hour) * 24))
year, month, day = previousSunday.Year(), previousSunday.Month(), previousSunday.Day()
// Subtract (day of week * nanoseconds per day) to get Sunday, then add a day to get Monday.
previousMonday := fromTime.Add(-1 * time.Hour * 24 * time.Duration(fromTime.Weekday()-1))
if fromTime.Weekday() == time.Sunday {
// The math above does not work for Sunday, as it roll forward to the next Monday.
// As such, subtract six days instead.
previousMonday = fromTime.Add(-6 * time.Hour * 24)
}
year, month, day = previousMonday.Year(), previousMonday.Month(), previousMonday.Day()
hour, min, sec, nsec = hourTrunc, minTrunc, secTrunc, nsecTrunc

case "day", "days":
Expand Down
6 changes: 5 additions & 1 deletion pkg/sql/sem/builtins/builtins_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -264,11 +264,15 @@ func TestTruncateTimestamp(t *testing.T) {
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "quarter", tree.MakeDTimestampTZ(time.Date(2118, time.January, 1, 0, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "month", tree.MakeDTimestampTZ(time.Date(2118, time.March, 1, 0, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "day", tree.MakeDTimestampTZ(time.Date(2118, time.March, 11, 0, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "week", tree.MakeDTimestampTZ(time.Date(2118, time.March, 6, 0, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "week", tree.MakeDTimestampTZ(time.Date(2118, time.March, 7, 0, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "hour", tree.MakeDTimestampTZ(time.Date(2118, time.March, 11, 5, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "second", tree.MakeDTimestampTZ(time.Date(2118, time.March, 11, 5, 6, 7, 0, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "millisecond", tree.MakeDTimestampTZ(time.Date(2118, time.March, 11, 5, 6, 7, 80000000, loc), time.Microsecond)},
{time.Date(2118, time.March, 11, 5, 6, 7, 80009001, loc), "microsecond", tree.MakeDTimestampTZ(time.Date(2118, time.March, 11, 5, 6, 7, 80009000, loc), time.Microsecond)},

// Test Monday and Sunday boundaries.
{time.Date(2019, time.November, 11, 5, 6, 7, 80009001, loc), "week", tree.MakeDTimestampTZ(time.Date(2019, time.November, 11, 0, 0, 0, 0, loc), time.Microsecond)},
{time.Date(2019, time.November, 10, 5, 6, 7, 80009001, loc), "week", tree.MakeDTimestampTZ(time.Date(2019, time.November, 4, 0, 0, 0, 0, loc), time.Microsecond)},
}

for _, tc := range testCases {
Expand Down
9 changes: 8 additions & 1 deletion pkg/sql/sem/tree/eval.go
Original file line number Diff line number Diff line change
Expand Up @@ -3442,6 +3442,8 @@ func PerformCast(ctx *EvalContext, d Datum, t *types.T) (Datum, error) {
return ParseDTime(ctx, d.Contents)
case *DTime:
return d, nil
case *DTimeTZ:
return MakeDTime(d.TimeOfDay), nil
case *DTimestamp:
return MakeDTime(timeofday.FromTime(d.Time)), nil
case *DTimestampTZ:
Expand All @@ -3457,7 +3459,12 @@ func PerformCast(ctx *EvalContext, d Datum, t *types.T) (Datum, error) {
return ParseDTimeTZ(ctx, string(*d))
case *DCollatedString:
return ParseDTimeTZ(ctx, d.Contents)
// TODO(otan#26097): expand for other valid types.
case *DTime:
return NewDTimeTZFromLocation(timeofday.TimeOfDay(*d), ctx.GetLocation()), nil
case *DTimeTZ:
return d, nil
case *DTimestampTZ:
return NewDTimeTZFromTime(d.Time), nil
}

case types.TimestampFamily:
Expand Down

0 comments on commit 9b625f2

Please sign in to comment.