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

release-22.2: opt: fix ambiguous column error for computed column expressions #105024

Merged
merged 1 commit into from Jun 27, 2023

Conversation

blathers-crl[bot]
Copy link

@blathers-crl blathers-crl bot commented Jun 16, 2023

Backport 1/1 commits from #104924 on behalf of @mgartner.

/cc @cockroachdb/release


This commit fixes a rare bug that caused "ambiguous column" errors for
INSERT .. ON CONFLICT .. DO UPDATE statements.

Consider the schema and statement:

CREATE TABLE t (
  id INT PRIMARY KEY,
  a INT DEFAULT 1,
  b INT,
  c INT AS (a + b) STORED
)

INSERT INTO t(id) VALUES (0) ON CONFLICT (id) DO UPDATE SET b = 1

In the SET clause, an explicit reference to a is ambiguous. It could
be a reference to t.a, the a of the conflicting row(s), or it could
be a reference to excluded.a, the a of the insert row(s) from the
VALUES clause. If the SET clause contained b = a, the result would
be an "ambiguous column" error, which is correct and matches Postgres's
behavior.

With the SET clause as b = 1, there should be no ambiguity. However,
prior to this commit, ambiguity arose when building an implicit SET
expression to generate the new value for the computed column c. When
building a + b, we used the same scope used to build the b = 1
projection: the scope of the SET clause. Using this scope makes a
ambiguous, even though it always refers to t.a - the a of the
conflicting row(s).

Normally, this ambiguity is avoided by calling
mutationBuilder.disambiguateColumns, which is called before computed
column expressions are built. However, it's not effective in this
specific edge case where the new value of b and the default value of
a are the same expression, 1. In this case, we conserve column IDs
by using the same ID for both, which prevents
mutationBuilder.disambiguateColumns from removing the ambiguity in the
SET clause scope.

The bug has been fixed by creating a new scope for resolving column
references in computed column expressions. The scope contains no columns
with duplicate names, so ambiguity is impossible.

I believe the long-term fix is to avoid using scopes when building these
synthesized expressions. I attempted to do this, but there are many
tricky edge cases to iron out and the change quickly grew beyond the
size of a comfortable backport. This future work is tracked by #61298.

Fixes #102909

Release note (bug fix): A bug has been fixed that caused
INSERT .. ON CONFLICT .. DO UPDATE queries to incorrectly result in an
"ambiguous column" error. The bug only presented if the target table had
a computed column with an expression referencing a column with a DEFAULT
value.


Release justification: Fix for a bug that causes ambiguous column reference
errors for some INSERTs.

@blathers-crl blathers-crl bot requested a review from a team as a code owner June 16, 2023 01:28
@blathers-crl blathers-crl bot force-pushed the blathers/backport-release-22.2-104924 branch from 702b4ef to f51f3f4 Compare June 16, 2023 01:28
@blathers-crl blathers-crl bot requested a review from cucaroach June 16, 2023 01:28
@blathers-crl blathers-crl bot force-pushed the blathers/backport-release-22.2-104924 branch from ef0976f to a1a73b1 Compare June 16, 2023 01:28
@blathers-crl blathers-crl bot added blathers-backport This is a backport that Blathers created automatically. O-robot Originated from a bot. labels Jun 16, 2023
@blathers-crl
Copy link
Author

blathers-crl bot commented Jun 16, 2023

Thanks for opening a backport.

Please check the backport criteria before merging:

  • Patches should only be created for serious issues or test-only changes.
  • Patches should not break backwards-compatibility.
  • Patches should change as little code as possible.
  • Patches should not change on-disk formats or node communication protocols.
  • Patches should not add new functionality.
  • Patches must not add, edit, or otherwise modify cluster versions; or add version gates.
If some of the basic criteria cannot be satisfied, ensure that the exceptional criteria are satisfied within.
  • There is a high priority need for the functionality that cannot wait until the next release and is difficult to address in another way.
  • The new functionality is additive-only and only runs for clusters which have specifically “opted in” to it (e.g. by a cluster setting).
  • New code is protected by a conditional check that is trivial to verify and ensures that it only runs for opt-in clusters.
  • The PM and TL on the team that owns the changed code have signed off that the change obeys the above rules.

Add a brief release justification to the body of your PR to justify this backport.

Some other things to consider:

  • What did we do to ensure that a user that doesn’t know & care about this backport, has no idea that it happened?
  • Will this work in a cluster of mixed patch versions? Did we test that?
  • If a user upgrades a patch version, uses this feature, and then downgrades, what happens?

@cockroach-teamcity
Copy link
Member

This change is Reviewable

Copy link
Collaborator

@rharding6373 rharding6373 left a comment

Choose a reason for hiding this comment

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

:lgtm:

Reviewable status: :shipit: complete! 1 of 0 LGTMs obtained (waiting on @cucaroach, @mgartner, and @msirek)

@mgartner
Copy link
Collaborator

Probably worth letting this bake for a bit.

@mgartner mgartner force-pushed the blathers/backport-release-22.2-104924 branch from a1a73b1 to 7ecb92f Compare June 22, 2023 14:06
@mgartner mgartner force-pushed the blathers/backport-release-22.2-104924 branch from 7ecb92f to 78c7591 Compare June 26, 2023 21:16
This commit fixes a rare bug that caused "ambiguous column" errors for
`INSERT .. ON CONFLICT .. DO UPDATE` statements.

Consider the schema and statement:

    CREATE TABLE t (
      id INT PRIMARY KEY,
      a INT DEFAULT 1,
      b INT,
      c INT AS (a + b) STORED
    )

    INSERT INTO t(id) VALUES (0) ON CONFLICT (id) DO UPDATE SET b = 1

In the `SET` clause, an explicit reference to `a` is ambiguous. It could
be a reference to `t.a`, the `a` of the conflicting row(s), or it could
be a reference to `excluded.a`, the `a` of the insert row(s) from the
`VALUES` clause. If the `SET` clause contained `b = a`, the result would
be an "ambiguous column" error, which is correct and matches Postgres's
behavior.

With the `SET` clause as `b = 1`, there should be no ambiguity. However,
prior to this commit, ambiguity arose when building an implicit `SET`
expression to generate the new value for the computed column `c`. When
building `a + b`, we used the same scope used to build the `b = 1`
projection: the scope of the `SET` clause. Using this scope makes `a`
ambiguous, even though it always refers to `t.a` - the `a` of the
conflicting row(s).

Normally, this ambiguity is avoided by calling
`mutationBuilder.disambiguateColumns`, which is called before computed
column expressions are built. However, it's not effective in this
specific edge case where the new value of `b` and the default value of
`a` are the same expression, `1`. In this case, we conserve column IDs
by using the same ID for both, which prevents
`mutationBuilder.disambiguateColumns` from removing the ambiguity in the
`SET` clause scope.

The bug has been fixed by creating a new scope for resolving column
references in computed column expressions. The scope contains no columns
with duplicate names, so ambiguity is impossible.

I believe the long-term fix is to avoid using scopes when building these
synthesized expressions. I attempted to do this, but there are many
tricky edge cases to iron out and the change quickly grew beyond the
size of a comfortable backport. This future work is tracked by #61298.

Fixes #102909

Release note (bug fix): A bug has been fixed that caused
`INSERT .. ON CONFLICT .. DO UPDATE` queries to incorrectly result in an
"ambiguous column" error. The bug only presented if the target table had
a computed column with an expression referencing a column with a DEFAULT
value.
@mgartner mgartner force-pushed the blathers/backport-release-22.2-104924 branch from 78c7591 to bc04436 Compare June 27, 2023 13:49
@mgartner mgartner merged commit 5bc3886 into release-22.2 Jun 27, 2023
6 checks passed
@mgartner mgartner deleted the blathers/backport-release-22.2-104924 branch June 27, 2023 15:16
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
blathers-backport This is a backport that Blathers created automatically. O-robot Originated from a bot.
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

4 participants