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,tree: differentiate UNIQUE and UNIQUE INDEX in CREATE TABLE #65825

Draft
wants to merge 7 commits into
base: master
Choose a base branch
from

Conversation

ajwerner
Copy link
Contributor

@ajwerner ajwerner commented May 28, 2021

While we treated the cases of ALTER TABLE ... ADD CONSTRAINT UNIQUE from
CREATE UNIQUE INDEX we didn't treat the two clauses differently in the
context of CREATE TABLE. While functionally they are largely identical concepts,
they have different semantic meanings (you can't use drop constraint on the index
or drop index on the constraint). We also didn't differentiate these concepts for display.

The root of this problem is twofold:

  1. Unique indexes and unique constraints always displayed indentically in SHOW CREATE TABLE even though some other catalog fields treated them distinctly.
  2. UNIQUE and UNIQUE INDEX clauses were treated identically in CREATE TABLE statements.
root@localhost:26257/test> CREATE TABLE t (i INT PRIMARY KEY, j INT, UNIQUE (j), UNIQUE INDEX (j));
CREATE TABLE

Before:

root@localhost:26257/test> SHOW CREATE TABLE t;
  table_name |               create_statement
-------------+------------------------------------------------
  t          | CREATE TABLE public.t (
             |     i INT8 NOT NULL,
             |     j INT8 NULL,
             |     CONSTRAINT "primary" PRIMARY KEY (i ASC),
             |     UNIQUE INDEX t_j_key (j ASC),
             |     UNIQUE INDEX t_j_key1 (j ASC),
             |     FAMILY "primary" (i, j)
             | )

After:

[email protected]:55769/movr> SHOW CREATE TABLE t;
  table_name |               create_statement
-------------+------------------------------------------------
  t          | CREATE TABLE public.t (
             |     i INT8 NOT NULL,
             |     j INT8 NULL,
             |     CONSTRAINT "primary" PRIMARY KEY (i ASC),
             |     UNIQUE INDEX t_j_key1 (j ASC),
             |     FAMILY "primary" (i, j),
             |     CONSTRAINT t_j_key UNIQUE (j)
             | )

Release note (bug fix): UNIQUE INDEX clauses in a CREATE TABLE statement
are no longer treated as CONSTRAINT UNIQUE clauses.

Release note (bug fix): UNIQUE constraints were displayed as UNIQUE INDEX
entries in SHOW CREATE TABLE.

@cockroach-teamcity
Copy link
Member

This change is Reviewable

@ajwerner ajwerner force-pushed the ajwerner/make-explicit-indexing-part-of-the-ast branch 5 times, most recently from c4f60c6 to aa2e283 Compare May 28, 2021 15:54
@mgartner mgartner self-requested a review May 28, 2021 17:35
Copy link
Member

@RaduBerinde RaduBerinde left a comment

Choose a reason for hiding this comment

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

:lgtm: Nice cleanup!

Reviewed 1 of 2 files at r1, 21 of 21 files at r2.
Reviewable status: :shipit: complete! 1 of 0 LGTMs obtained (waiting on @ajwerner and @mgartner)


pkg/sql/show_create_clauses.go, line 604 at r1 (raw file):

		}
	}
	for _, idx := range desc.AllIndexes() {

[nit] Maybe we want to show them before UNIQUE WITHOUT INDEX (since they are more "vanilla")? Also, I'd add a comment along the lines of // Show unique constraints that are implemented by implicitly created unique indexes.


pkg/sql/logictest/testdata/logic_test/show_create_all_tables, line 59 at r2 (raw file):

);
CREATE TABLE public.full_test (
                                                                                                                                                                     x INT8 NULL,

What's with the extra blank lines? Maybe a bug in -rewrite?


pkg/sql/sem/tree/create.go, line 885 at r2 (raw file):

	PrimaryKey    bool
	WithoutIndex  bool
	ExplicitIndex bool

[nit] Maybe add a comment for the field (mentioning CONSTRAINT vs UNIQUE INDEX syntax). And that at most one of PrimaryKey, WithoutIndex, ExplicitIndex can be true.

Copy link
Collaborator

@rytaft rytaft left a comment

Choose a reason for hiding this comment

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

Nice change -- this will get us closer to PG compatibility, since Postgres distinguishes between unique constraints and unique indexes.

This issue seems relevant, since it's related to the fact that we weren't distinguishing between unique constraints and unique indexes before: #42840. (not that you need to fix it with this PR, just wanted to surface it)

Reviewed 2 of 2 files at r1, 21 of 21 files at r2.
Reviewable status: :shipit: complete! 1 of 0 LGTMs obtained (waiting on @ajwerner, @mgartner, and @RaduBerinde)


pkg/ccl/logictestccl/testdata/logic_test/partitioning_index, line 50 at r2 (raw file):

     CONSTRAINT "primary" PRIMARY KEY (a ASC),
     FAMILY "primary" (a, b),
     CONSTRAINT ok2_b_key UNIQUE (b)

the partition by list isn't shown now


pkg/sql/show_create_clauses.go, line 604 at r1 (raw file):

Previously, RaduBerinde wrote…

[nit] Maybe we want to show them before UNIQUE WITHOUT INDEX (since they are more "vanilla")? Also, I'd add a comment along the lines of // Show unique constraints that are implemented by implicitly created unique indexes.

I'd also show them before the families


pkg/sql/logictest/testdata/logic_test/create_table, line 279 at r2 (raw file):

            INVERTED INDEX like_table_j_idx (j),
            FAMILY "primary" (a, b, c, h, j, k),
            CONSTRAINT foo UNIQUE (b, c)

now the DESC marker is gone from b

@ajwerner
Copy link
Contributor Author

Thanks for the early looks! There's a good bit more I want to do here. I'll mark it as Ready for review when it's in good shape.

  1. Make the behavior consistent for partially added things.
  2. Change the parser to disallow a bunch of the index parameters on unique constraints
    • We'll need to allow WHERE clauses on UNIQUE WITHOUT INDEX because we can't take
      that feature away. It's fine because it's a cockroach extension.
    • Other modifiers will be removed from UNIQUE constraints for the most part
  3. (follows from 2) Implement a migration and repair logic to turn all of the unique constraints which use index features into unique indexes explicitly. This includes:
    • non-standard column directions,
    • partition clauses
    • interleave clauses
    • storing (technically in postgres you can have an INCLUDE CLAUSE but we don't support that syntax). When we add it, I'm fine supporting it in both cases.
  4. Fix some other bugs revealed along the way.
    • For example, we disallow NOT VALID on UNIQUE in a CREATE TABLE but we ignore it in when adding a constraint via ALTER TABLE.
      return purposelyUnimplemented(sqllex, "table constraint", typ + " constraints cannot be marked NOT VALID")
    • There's some other issues with adding multiple constraints in a single ALTER TABLE I'm chewing through.

This bug is due to both using the same object in descs.Txn (sort of) and the
fact the fact that MakeMutationComplete does not remove the mutation any
longer. I have a feeling, but have not checked, that we lost this back-
reference in older versions.

Release note (bug fix): Fixed a bug which prevented adding self-referencing
FOREIGN KEY constraints in the NOT VALID state.
@ajwerner ajwerner force-pushed the ajwerner/make-explicit-indexing-part-of-the-ast branch 2 times, most recently from 0e1facd to 81447ba Compare May 30, 2021 22:42
ajwerner added 5 commits May 30, 2021 20:33
…being added

This is potentially controversial but it will make things more akin to other
behaviors. It retains `NOT VALID` for constraints created as `NOT VALID` but
it does not display constraint which are in the process of being validated.

We currently do not display indexes (unique or otherwise) or foreign key
constraints which are in the process of being added. I think we should
pick one and stick to it.

Release note (sql change): SHOW CREATE TABLE will no longer show CHECK or
UNIQUE WITHOUT INDEX constraints which are in the process of being added.
In earlier versions, they would appear with NOT VALID. Now NOT VALID will
only appear for constraints which were created that way.
While we treated the cases of `ALTER TABLE ... ADD CONSTRAINT UNIQUE` from
`CREATE UNIQUE INDEX` we didn't treat the two clauses differently in the
context of `CREATE TABLE`. While functionally they are indentical concepts,
they do display differently and have different semantic meanings (you can't
use drop constraint on the index or drop index on the constraint).

Release note (bug fix): UNIQUE INDEX clauses in a CREATE TABLE statement
are no longer treated as CONSTRAINT UNIQUE clauses.
This was the behavior in CREATE TABLE but not in ALTER TABLE. The impact was
that the parser would allow such clauses but ignore them. Secondarily, we
permitted (and supported) using NOT VALID for UNIQUE WITHOUT INDEX in
ALTER TABLE but not in CREATE TABLE. I've added support for it for symmetry.
I don't know that there's ever a reason one would want to do that though.

UNIQUE WITHOUT INDEX constraints may still be created in a NOT VALID state.

Release note (bug fix): An error is now reported when using NOT VALID with
a UNIQUE constraint in ALTER TABLE. Previously the clause was silently
ignored.
Before this commit we would allow, in the grammar, a variety of options like
interleaving, partitioning, and storing as well as attributes on columns
related to sorting. None of these are valid in postgres nor do they have much
to do with the constraint. Instead, we remove all of these from the grammar and
hint to users that `UNIQUE INDEX` is what they are looking for.

This is a backwards incompatible change; prior to this change, one could use
the syntax of a unique constraint to construct a unique index. We accept this
change because it drives closer to postgresql compatibility.

Furthermore, because of bugs in how we display these constraints, it was
very difficult to determine whether something was a unique constraint or
a unique index.

Release note (backward-incompatible change): The use of PARTITION BY,
INTERLEAVE, and STORING clauses as well as ordering parameters on columns
in UNIQUE constraint definitions is no longer supported; instead, users
are directed towards UNIQUE INDEX which supports all of these features.
```
root@localhost:26257/test> CREATE TABLE t (i INT PRIMARY KEY, j INT);
CREATE TABLE
root@localhost:26257/test> ALTER TABLE t ADD CONSTRAINT c UNIQUE (j);
ALTER TABLE
root@localhost:26257/test> CREATE UNIQUE INDEX idx ON t (j);
CREATE INDEX
```

Before:
```
root@localhost:26257/test> SHOW CREATE TABLE t;
  table_name |               create_statement
-------------+------------------------------------------------
  t          | CREATE TABLE public.t (
             |     i INT8 NOT NULL,
             |     j INT8 NULL,
             |     CONSTRAINT "primary" PRIMARY KEY (i ASC),
             |     UNIQUE INDEX c (j ASC),
             |     UNIQUE INDEX idx (j ASC),
             |     FAMILY "primary" (i, j)
             | )
```

After:
```
[email protected]:55792/movr> SHOW CREATE TABLE t;
  table_name |               create_statement
-------------+------------------------------------------------
  t          | CREATE TABLE public.t (
             |     i INT8 NOT NULL,
             |     j INT8 NULL,
             |     CONSTRAINT "primary" PRIMARY KEY (i ASC),
             |     UNIQUE INDEX idx (j ASC),
             |     FAMILY "primary" (i, j),
             |     CONSTRAINT c UNIQUE (j)
             | )
```

Release note (bug fix): UNIQUE constraints were displayed as UNIQUE INDEX
entries in SHOW CREATE TABLE.
@ajwerner ajwerner force-pushed the ajwerner/make-explicit-indexing-part-of-the-ast branch from 81447ba to 4794611 Compare May 31, 2021 00:35
Postgres names the indexes due to unique constraints (as well as the
constraint) with the `key` suffix but names unique indexes like regular
indexes, with the `idx` suffix.

Release note (sql change): Indexes which are automatically named using
a CREATE UNIQUE INDEX statement or a UNIQUE INDEX clause in a CREATE
TABLE statement now have the suffix idx instead of key which is used
for UNIQUE constraints. This matches the postgres behavior.
mgartner added a commit to mgartner/cockroach that referenced this pull request Jul 6, 2021
Postgres does not allow expressions in unique constraints, but it does
allow expressions in unique indexes. For now we allow expressions in
unique constraints, because we cannot differentiate between a unique
constraint and a unique index table definition: they are both parsed
into the same struct, `tree.UniqueConstraintTableDef`.

In the long term we may want to disallow expression in unique
constraints to be consistent with Postgres. We could do this by changing
the parser so that `UNIQUE ((a + b))` does not parse successfully.
See cockroachdb#65825.

Release note: None
mgartner added a commit to mgartner/cockroach that referenced this pull request Jul 12, 2021
Postgres does not allow expressions in unique constraints, but it does
allow expressions in unique indexes. For now we allow expressions in
unique constraints, because we cannot differentiate between a unique
constraint and a unique index table definition: they are both parsed
into the same struct, `tree.UniqueConstraintTableDef`.

In the long term we may want to disallow expression in unique
constraints to be consistent with Postgres. We could do this by changing
the parser so that `UNIQUE ((a + b))` does not parse successfully.
See cockroachdb#65825.

Release note: None
mgartner added a commit to mgartner/cockroach that referenced this pull request Jul 15, 2021
Postgres does not allow expressions in unique constraints, but it does
allow expressions in unique indexes. For now we allow expressions in
unique constraints, because we cannot differentiate between a unique
constraint and a unique index table definition: they are both parsed
into the same struct, `tree.UniqueConstraintTableDef`.

In the long term we may want to disallow expression in unique
constraints to be consistent with Postgres. We could do this by changing
the parser so that `UNIQUE ((a + b))` does not parse successfully.
See cockroachdb#65825.

Release note: None
@mgartner
Copy link
Collaborator

mgartner commented Jul 15, 2021

@ajwerner Do you think we should try to get this into 21.2? I ask not to pressure you, but because there's some related issues that have come up which would be solved by this. There's other temporary solutions that I can work on if we think this PR is too big of a lift for 21.2. I could also take over where you left off.

craig bot pushed a commit that referenced this pull request Jul 15, 2021
67197: sql: improve expression index usability r=mgartner a=mgartner

#### sql: do not allow renaming inaccessible columns

Release note: None

#### sql: do not allow inaccessible columns in primary keys

Release note: None

#### sql: support expressions in unique constraints

Postgres does not allow expressions in unique constraints, but it does
allow expressions in unique indexes. For now we allow expressions in
unique constraints, because we cannot differentiate between a unique
constraint and a unique index table definition: they are both parsed
into the same struct, `tree.UniqueConstraintTableDef`.

In the long term we may want to disallow expression in unique
constraints to be consistent with Postgres. We could do this by changing
the parser so that `UNIQUE ((a + b))` does not parse successfully.
See #65825.

Release note: None

#### sql: better error message when creating a view with an inaccessible column

Previously, the error message returned when attempting to create a view
with an inaccessible column was confusing:

    unimplemented: views do not currently support * expressions

The error message now reads:

    column "x" does not exist

Release note: None

#### sql: do not allow inaccessible columns to be dropped

Release note: None


67631: dev: teach `dev` how to run benchmarks r=rail a=rickystewart

Also a little bit of refactoring, and adding some code to make the code
less stringent (e.g. now you can just do
`dev build //pkg/cmd/cockroach-short` and it will succeed).

Closes #67141.

Release note: None

67638: colexec: improve sort operator a bit r=yuzefovich a=yuzefovich

**colexec: improve sort operator a bit**

Previously, we were missing memory accounting around some slices
allocated internally by the sort operator which is now added.
Additionally, the references to those slices are now kept by the
operator which will be useful when the sorter is used by the external
sorter.

Additionally, this commit eliminates some bounds checks.

Release note: None

**colexec: add some BCE assertions for distinct and sort**

This is achieved by templating the inlined execgen functions. Note that
in some cases this templating leaves redundant `_ = true` lines, but
figuring out what's up with that is left as a TODO.

Additionally, this commit removes some redundant attempts at achieving
BCE for non-sliceable vectors (which had a negative impact in case of
JSONs) and clarifies the name of a utility function.

Release note: None

67651: sql: require placeholder types to be identical to use a cached plan r=RaduBerinde a=rafiss

fixes #67605

Release note (bug fix): Fix a bug where a prepared statement could
incorrectly reuse the query plan of a different prepared statements that
had similar, but not identical type hints.

67674: dev: teach `dev` how to `stress` r=rail a=rickystewart

Only the latest commit counts for this review, the other is from #67631.

The previous version of this code would assume that you had `stress`
installed globally -- this doesn't work in the long term, so instead if
you're stress testing pre-build the `stress` binary and pass it in to
`bazel test` invocation.

Closes #67165.

Release note: None

67675: dev: get rid of fuzzing stubs r=rail a=rickystewart

I don't think anyone actually uses fuzzing and it doesn't seem to be a
requirement for `dev`. Until such a point as we actually need it for
something, remove these stubs.

Release note: None

Co-authored-by: Marcus Gartner <[email protected]>
Co-authored-by: Ricky Stewart <[email protected]>
Co-authored-by: Yahor Yuzefovich <[email protected]>
Co-authored-by: Rafi Shamim <[email protected]>
pawalt pushed a commit to pawalt/cockroach that referenced this pull request Jul 22, 2021
Postgres does not allow expressions in unique constraints, but it does
allow expressions in unique indexes. For now we allow expressions in
unique constraints, because we cannot differentiate between a unique
constraint and a unique index table definition: they are both parsed
into the same struct, `tree.UniqueConstraintTableDef`.

In the long term we may want to disallow expression in unique
constraints to be consistent with Postgres. We could do this by changing
the parser so that `UNIQUE ((a + b))` does not parse successfully.
See cockroachdb#65825.

Release note: None
@ajwerner
Copy link
Contributor Author

@ajwerner Do you think we should try to get this into 21.2? I ask not to pressure you, but because there's some related issues that have come up which would be solved by this. There's other temporary solutions that I can work on if we think this PR is too big of a lift for 21.2.

Thanks for the ping and I'm very sorry I let this sit for so long. Increasingly I'm afraid of breaking compatibility with ourselves, even in cases where we handled it poorly in the past. I'd like @vy-ton to get involved here as we do some decision making. Maybe the right approach here is to treat all of the uses of index features in a constraint clause as valid but as syntactically implying an INDEX as opposed to a constraint. More concretely, revert the parser changes but retain the other changes to convert those constraints to indexes. Then during CREATE TABLE and ALTER TABLE ... ADD CONSTRAINT, actually construct an ExplicitlyCreated index, perhaps with a notice. That would give us some latitude to disallow it one day but would be less disruptive if anybody is depending on it.

I could also take over where you left off.

As far as getting this done, is this something you feel like you have resources to tackle?

@mgartner
Copy link
Collaborator

mgartner commented Aug 2, 2021

As far as getting this done, is this something you feel like you have resources to tackle?

Probably not before the stability period. I'll look for quick workarounds for the minor issues I linked to for now, and hopefully we can make some progress on this in 22.1.

mgartner added a commit to mgartner/cockroach that referenced this pull request Aug 3, 2021
Previously, a `WHERE` clause in `ALTER TABLE .. ADD CONSTRAINT .. UNIQUE`
statements was parsed successfully but ignored so that the resulting
unique constraint was not partial. This commit disallows the `WHERE`
clause. Postgres allows partial unique indexes, but not partial unique
constraints, so we will likely remove support for partial unique
constraints in `CREATE TABLE` statements in an upcoming major release.
See discussion in cockroachdb#65825.

Fixes cockroachdb#67234

Release note (bug fix/sql change): A bug was identified that created
non-partial unique constraints when a user attempted to create a partial
unique constraint in `ALTER TABLE` statements. Creating partial unique
constraints in `ALTER TABLE` is now disallowed. A partial unique index
can be created instead with `CREATE UNIQUE INDEX .. WHERE`.
mgartner added a commit to mgartner/cockroach that referenced this pull request Aug 6, 2021
Previously, a `WHERE` clause in `ALTER TABLE .. ADD CONSTRAINT .. UNIQUE`
statements was parsed successfully but ignored so that the resulting
unique constraint was not partial. This commit disallows the `WHERE`
clause. Postgres allows partial unique indexes, but not partial unique
constraints, so we will likely remove support for partial unique
constraints in `CREATE TABLE` statements in an upcoming major release.
See discussion in cockroachdb#65825.

Fixes cockroachdb#67234

Release note (bug fix/sql change): A bug was identified that created
non-partial unique constraints when a user attempted to create a partial
unique constraint in `ALTER TABLE` statements. Creating partial unique
constraints in `ALTER TABLE` is now disallowed. A partial unique index
can be created instead with `CREATE UNIQUE INDEX .. WHERE`.
@mgartner mgartner removed their request for review December 20, 2022 20:33
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.

5 participants