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

sql: normalize age and timestamptz intervals like postgres #56667

Merged
merged 2 commits into from
Nov 16, 2020

Conversation

otan
Copy link
Contributor

@otan otan commented Nov 13, 2020

sql: normalize age and timestamptz intervals like postgres

Release note (sql change, bug fix): Previously, timestamp/timestamptz - timestamp/timestamptz operators would normalize the interval into
months, days, H:M:S (in older versions, this may be just H:M:S).

This could result in an incorrect result:

> select '2020-01-01'::timestamptz - '2018-01-01';
     ?column?
-------------------
  2 years 10 days

This has now been fixed such that it is only normalized into
days/H:M:S. This is now more postgres compatible.

Release note (sql change, bug fix): Previously, the age builtin would
incorrectly normalize months and days based on 30 days a month (in older
versions this may be just H:M:S).

This can give an incorrect result, e.g.

> select age('2020-01-01'::timestamptz, '2018-01-01');
     ?column?
-------------------
  2 years 10 days

This is not the most accurate it could be as age can use the given
timestamptz arguments to be more accurate.
This is now more postgres compatible.

Revert "sql: age returns normalized intervals"

This reverts commit 88a5d94.

Release note: None

@otan otan requested review from solongordon and a team November 13, 2020 20:27
@cockroach-teamcity
Copy link
Member

This change is Reviewable

@otan otan force-pushed the fix_normalize_bug branch from 8f7f165 to 2f08992 Compare November 13, 2020 20:30
Copy link
Contributor

@solongordon solongordon left a comment

Choose a reason for hiding this comment

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

I think our release note needs to call out that the previous behavior could produce incorrect results for timestamp subtraction. For instance like this:

> select '2020-01-01'::timestamptz - '2018-01-01';
     ?column?
-------------------
  2 years 10 days

It seems hard to spin that as just a "sql change" and not a bug fix.

Reviewable status: :shipit: complete! 0 of 0 LGTMs obtained (waiting on @otan and @solongordon)


pkg/sql/logictest/testdata/logic_test/timestamp, line 487 at r2 (raw file):

29 days 05:43:04                  -29 days -05:43:04                    29 days 05:43:04    -29 days -05:43:04    29 days 05:43:04    -29 days -05:43:04
-1 mons -1 days -17:16:56         1 mon 1 day 17:16:56                  -29 days -17:16:56  29 days 17:16:56      -29 days -18:16:56  29 days 18:16:56
-18:16:56                         18:16:56                              -18:16:56           18:16:56              -18:16:56           18:16:56

@jordanlewis also proposed having a randomized test which asserts that adding and subtracting the same interval from a timestamp results in the same timestamp. Do you think that would also be valuable here or is this logic test sufficient? Though now that I'm saying this I'm remembering there might be counterexamples of this invariant in Postgres?


pkg/sql/sem/builtins/builtins.go, line 2116 at r2 (raw file):

			Info: "Calculates the interval between `val` and the current time, normalized into years, months and days." + `

			Note this may not be an accurate time span since years and months are normalized from days, and years and months are out of context. Use ` + "`timestamptz - now()`" + ` for day rounding which maintains this accuracy.`,

Did you mean now() - timestamptz? Also "rounding" seems like a confusing term here.

@otan
Copy link
Contributor Author

otan commented Nov 13, 2020


pkg/sql/logictest/testdata/logic_test/timestamp, line 487 at r2 (raw file):

Previously, solongordon (Solon) wrote…

@jordanlewis also proposed having a randomized test which asserts that adding and subtracting the same interval from a timestamp results in the same timestamp. Do you think that would also be valuable here or is this logic test sufficient? Though now that I'm saying this I'm remembering there might be counterexamples of this invariant in Postgres?

This does not work for age. The other randomized tests testing invariants may be useful (smells like metamorphic tests), I think it's worth filing a separate issue such we that we have those. Sounds like we can generalise these kinds of invariants.

@otan otan force-pushed the fix_normalize_bug branch 5 times, most recently from 6b9eb60 to 2b462d1 Compare November 14, 2020 07:57
This reverts commit 88a5d94.

Release note: None
@otan otan force-pushed the fix_normalize_bug branch from 2b462d1 to d9d3c68 Compare November 14, 2020 07:57
Copy link
Contributor

@solongordon solongordon left a comment

Choose a reason for hiding this comment

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

Reviewed 1 of 7 files at r4.
Reviewable status: :shipit: complete! 0 of 0 LGTMs obtained (waiting on @jordanlewis and @otan)


pkg/util/duration/duration.go, line 166 at r4 (raw file):

	// to be too large from the math above anyway.
	for nanos < 0 {
		nanos += int64(time.Nanosecond)

It looks like this should be nanos per second, not int64(time.Nanosecond) which is 1. Could you update this and include nanoseconds in your test cases?

Release note (sql change, bug fix): Previously, `timestamp/timestamptz -
timestamp/timestamptz` operators would normalize the interval into
months, days, H:M:S (in older versions, this may be just H:M:S).

This could result in an incorrect result:
```
> select '2020-01-01'::timestamptz - '2018-01-01';
     ?column?
-------------------
  2 years 10 days
```
This has now been fixed such that it is only normalized into
days/H:M:S. This is now more postgres compatible.

Release note (sql change, bug fix): Previously, the `age` builtin would
incorrectly normalize months and days based on 30 days a month (in older
versions this may be just H:M:S).

This can give an incorrect result, e.g.
```
> select age('2020-01-01'::timestamptz, '2018-01-01');
     ?column?
-------------------
  2 years 10 days
```

This is not the most accurate it could be as `age` can use the given
timestamptz arguments to be more accurate.
This is now more postgres compatible.
@otan otan force-pushed the fix_normalize_bug branch from d9d3c68 to abfe0d5 Compare November 16, 2020 18:25
@otan
Copy link
Contributor Author

otan commented Nov 16, 2020


pkg/util/duration/duration.go, line 166 at r4 (raw file):

Previously, solongordon (Solon) wrote…

It looks like this should be nanos per second, not int64(time.Nanosecond) which is 1. Could you update this and include nanoseconds in your test cases?

ah the one case i wish i had go coverage tools.
nice catch, cheers!
fixed.

Copy link
Contributor

@solongordon solongordon left a comment

Choose a reason for hiding this comment

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

Reviewable status: :shipit: complete! 0 of 0 LGTMs obtained (waiting on @jordanlewis)

@otan
Copy link
Contributor Author

otan commented Nov 16, 2020

bors r=solongordon

thanks!

@craig
Copy link
Contributor

craig bot commented Nov 16, 2020

Build failed (retrying...):

@craig
Copy link
Contributor

craig bot commented Nov 16, 2020

Build succeeded:

@craig craig bot merged commit 859be50 into cockroachdb:master Nov 16, 2020
@rafiss rafiss added this to the 20.2 milestone Apr 22, 2021
yuzefovich added a commit to yuzefovich/cockroach that referenced this pull request Jul 6, 2022
This commit fixes an oversight of cockroachdb#56667 (which fixed the normalization
of the timestamp subtraction) where we forgot to update the vectorized
code path as well. The regression tests added in that PR happened to be
complex enough so that the vectorized engine would fall back to wrapping
a row-by-row processor, so they didn't catch this.

Release note (bug fix): CockroachDB previously would not normalize
`timestamp/timestamptz - timestamp/timestamptz` like Postgres does in
some cases (depending on the query), and this is now fixed.
craig bot pushed a commit that referenced this pull request Jul 7, 2022
83812: sql/schemachanger: check nil table name for comment on column r=chengxiong-ruan a=chengxiong-ruan

addressing this [build error](#75604 (comment))
throw pg error instead of panic on nil pointer.

Release note: None.

83923: roachprod: fix target path when getting cluster artifacts. r=srosenberg a=renatolabs

A bug was introduced in the computation of the local path where
cluster artifacts are downloaded: instead of prefixing the path with
the node ID, the list of nodes would be used instead. This results
in (other than weird looking paths, such as `[1 2 3 4].logs`) only the
logs for the last node being downloaded.

This commit fixes the issue by using the node ID correctly.

Release note: None.

83927: storage: clarify and test overlapping SST range keys in `Export` r=nicktrav a=erikgrinaker

This patch clarifies that an `Export` with overlapping MVCC range
tombstones across two SSTs due to `SplitMidKey` will be handled
correctly both by multiplexed iteration with `NewPebbleSSTIterator()`,
and by `AddSSTable`.

Release note: None

83944: coexec: normalize the timestamp subtraction like postgres r=yuzefovich a=yuzefovich

This commit fixes an oversight of #56667 (which fixed the normalization
of the timestamp subtraction) where we forgot to update the vectorized
code path as well. The regression tests added in that PR happened to be
complex enough so that the vectorized engine would fall back to wrapping
a row-by-row processor, so they didn't catch this.

Fixes: #83094.

Release note (bug fix): CockroachDB previously would not normalize
`timestamp/timestamptz - timestamp/timestamptz` like Postgres does in
some cases (depending on the query), and this is now fixed.

Co-authored-by: Chengxiong Ruan <[email protected]>
Co-authored-by: Renato Costa <[email protected]>
Co-authored-by: Erik Grinaker <[email protected]>
Co-authored-by: Yahor Yuzefovich <[email protected]>
yuzefovich added a commit to yuzefovich/cockroach that referenced this pull request Jul 7, 2022
This commit fixes an oversight of cockroachdb#56667 (which fixed the normalization
of the timestamp subtraction) where we forgot to update the vectorized
code path as well. The regression tests added in that PR happened to be
complex enough so that the vectorized engine would fall back to wrapping
a row-by-row processor, so they didn't catch this.

Release note (bug fix): CockroachDB previously would not normalize
`timestamp/timestamptz - timestamp/timestamptz` like Postgres does in
some cases (depending on the query), and this is now fixed.
yuzefovich added a commit to yuzefovich/cockroach that referenced this pull request Jul 7, 2022
This commit fixes an oversight of cockroachdb#56667 (which fixed the normalization
of the timestamp subtraction) where we forgot to update the vectorized
code path as well. The regression tests added in that PR happened to be
complex enough so that the vectorized engine would fall back to wrapping
a row-by-row processor, so they didn't catch this.

Release note (bug fix): CockroachDB previously would not normalize
`timestamp/timestamptz - timestamp/timestamptz` like Postgres does in
some cases (depending on the query), and this is now fixed.
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

4 participants