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: CBO fails to run CHECK constraint on input row to UPSERT/INSERT ON CONFLICT #35370

Open
knz opened this issue Mar 4, 2019 · 9 comments
Open
Labels
A-sql-mutations Mutation statements: UPDATE/INSERT/UPSERT/DELETE. A-sql-optimizer SQL logical planning and optimizations. A-sql-pgcompat Semantic compatibility with PostgreSQL C-bug Code not up to spec/doc, specs & docs deemed correct. Solution expected to change code/behavior. docs-done docs-known-limitation S-0-visible-logical-error Database stores inconsistent data in some cases, or queries return invalid results silently. T-sql-queries SQL Queries Team

Comments

@knz
Copy link
Contributor

knz commented Mar 4, 2019

The CBO runs CHECK only on the result of conflict resolution; it must run it on the input as well.

This is a regression (set optimizer=off provides the proper behavior)

> create table t(x int primary key, y int, constraint c check(y>10));
> insert into t(x,y) values (0,20);
>  insert into t(x,y) values (0,10) on conflict(x) do update set y= 20; -- fails in HP and PostgreSQL; succeeds with CBO

Related (but distinct from) #35364

cc @andy-kimball

Jira issue: CRDB-4590

@knz knz added C-bug Code not up to spec/doc, specs & docs deemed correct. Solution expected to change code/behavior. A-sql-pgcompat Semantic compatibility with PostgreSQL A-sql-optimizer SQL logical planning and optimizations. A-sql-mutations Mutation statements: UPDATE/INSERT/UPSERT/DELETE. S-3-erroneous-edge-case Database produces or stores erroneous data without visible error/warning, in rare edge cases. labels Mar 4, 2019
@knz knz added this to To do in BACKLOG, NO NEW ISSUES: SQL Optimizer via automation Mar 4, 2019
@knz knz added this to Triage in (DEPRECATED) SQL Front-end, Lang & Semantics via automation Mar 4, 2019
@knz
Copy link
Contributor Author

knz commented Mar 4, 2019

I think the CHECK constraint also needs to be run on the output, regardless; this should fail too given the example above:

> insert into t(x,y) values (0,30) on conflict(x) do update set y= 10;

@knz
Copy link
Contributor Author

knz commented Mar 4, 2019

Discussed offline, @rmloveland this should be documented as a known limitation / difference with postgres, and we'll hope that users are OK with that.

We can leave the issue open (low priority) and perhaps label it with a new label "deliberate choice" so we can provide a better support experience when people ask.

@knz knz added the docs-todo label Mar 4, 2019
@andy-kimball
Copy link
Contributor

As another data point, @knz and I discovered that PG is inconsistent with applying CHECK constraint:

template1=# create table t(x int primary key, y int, constraint c check(y>10));
CREATE TABLE
template1=# insert into t(x,y) values (0,20) on conflict(x) do update set y=10;
INSERT 0 1
template1=# insert into t(x,y) values (0,10) on conflict(x) do update set y=20;
2019-03-04 14:52:34.541 PST [50218] ERROR:  new row for relation "t" violates check constraint "c"
2019-03-04 14:52:34.541 PST [50218] DETAIL:  Failing row contains (0, 10).
2019-03-04 14:52:34.541 PST [50218] STATEMENT:  insert into t(x,y) values (0,10) on conflict(x) do update set y=20;
ERROR:  new row for relation "t" violates check constraint "c"
DETAIL:  Failing row contains (0, 10).

Notice that PG does not check the constraint on set y=10 when the update is not made, but it does check the constraint on the insert values (0,10) even when the insert is not made.

I think the important thing for check constraints is to verify that bad data does not get inserted/updated into table. It doesn't seem too important for input that never makes it into the table to be checked. The fact that PG is sometimes checking input and sometimes not suggests their current behavior is just an implementation accident.

The CBO is consistent, in that it always checks the output values, and never checks the input values.

@knz knz added C-question A question rather than an issue. No code/spec/doc change needed. and removed C-bug Code not up to spec/doc, specs & docs deemed correct. Solution expected to change code/behavior. S-3-erroneous-edge-case Database produces or stores erroneous data without visible error/warning, in rare edge cases. labels Mar 4, 2019
@RaduBerinde RaduBerinde moved this from Triage to Lower Priority Backlog in BACKLOG, NO NEW ISSUES: SQL Optimizer Jul 9, 2019
@jseldess
Copy link
Contributor

jseldess commented Nov 4, 2019

@knz, can you help me with a blurb on this for the known limitations page?

@knz
Copy link
Contributor Author

knz commented Nov 4, 2019

  • pages/sections: UPSERT and INSERT ON CONFLICT
  • Known limitation: "CockroachDB only validates CHECK constraints on the final result of a DML statement, to prevent rows that violate the constraint from being written in the table. This differs from PostgreSQL, which also validates CHECK constraints on the input rows of an UPSERT or INSERT ON CONFLICT statement, prior to conflict resolution."

@jseldess
Copy link
Contributor

jseldess commented Nov 5, 2019

Documented in cockroachdb/docs#5785.

@RaduBerinde RaduBerinde moved this from Lower Priority Backlog to Functional issues in BACKLOG, NO NEW ISSUES: SQL Optimizer Apr 18, 2020
@github-actions
Copy link

github-actions bot commented Jun 5, 2021

We have marked this issue as stale because it has been inactive for
18 months. If this issue is still relevant, removing the stale label
or adding a comment will keep it active. Otherwise, we'll close it in
5 days to keep the issue queue tidy. Thank you for your contribution
to CockroachDB!

@knz knz added C-bug Code not up to spec/doc, specs & docs deemed correct. Solution expected to change code/behavior. and removed C-question A question rather than an issue. No code/spec/doc change needed. labels Jun 5, 2021
@knz knz added this to Triage in SQL Queries via automation Jun 5, 2021
@knz
Copy link
Contributor Author

knz commented Jun 5, 2021

This bug still exists in v21.1.

@rytaft rytaft moved this from Triage to Backlog in SQL Queries Jun 8, 2021
@jlinder jlinder added the T-sql-queries SQL Queries Team label Jun 16, 2021
@mgartner mgartner moved this from Backlog to New Backlog in SQL Queries Feb 16, 2023
@github-actions
Copy link

We have marked this issue as stale because it has been inactive for
18 months. If this issue is still relevant, removing the stale label
or adding a comment will keep it active. Otherwise, we'll close it in
10 days to keep the issue queue tidy. Thank you for your contribution
to CockroachDB!

@knz knz added the S-0-visible-logical-error Database stores inconsistent data in some cases, or queries return invalid results silently. label Sep 20, 2023
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
A-sql-mutations Mutation statements: UPDATE/INSERT/UPSERT/DELETE. A-sql-optimizer SQL logical planning and optimizations. A-sql-pgcompat Semantic compatibility with PostgreSQL C-bug Code not up to spec/doc, specs & docs deemed correct. Solution expected to change code/behavior. docs-done docs-known-limitation S-0-visible-logical-error Database stores inconsistent data in some cases, or queries return invalid results silently. T-sql-queries SQL Queries Team
Projects
Status: Backlog
SQL Queries
New Backlog
Development

No branches or pull requests

4 participants