diff --git a/pkg/sql/logictest/testdata/logic_test/unique b/pkg/sql/logictest/testdata/logic_test/unique new file mode 100644 index 000000000000..50c5de5b3896 --- /dev/null +++ b/pkg/sql/logictest/testdata/logic_test/unique @@ -0,0 +1,268 @@ +statement ok +SET experimental_enable_unique_without_index_constraints = true + +statement ok +CREATE TABLE uniq ( + k INT PRIMARY KEY, + v INT UNIQUE, + w INT UNIQUE WITHOUT INDEX, + x INT, + y INT, + UNIQUE WITHOUT INDEX (x, y) +) + +statement ok +CREATE TABLE uniq_overlaps_pk ( + a INT, + b INT, + c INT, + d INT, + PRIMARY KEY (a, b), + UNIQUE WITHOUT INDEX (b, c), + UNIQUE WITHOUT INDEX (a, b, d), + UNIQUE WITHOUT INDEX (a), + UNIQUE WITHOUT INDEX (c, d) +) + +statement ok +CREATE TABLE uniq_hidden_pk ( + a INT, + b INT, + c INT, + d INT, + UNIQUE WITHOUT INDEX (b, c), + UNIQUE WITHOUT INDEX (a, b, d), + UNIQUE WITHOUT INDEX (a) +) + +# TODO(rytaft): make this table use UNIQUE WITHOUT INDEX constraints once +# we allow foreign keys to reference them (see #57977). +statement ok +CREATE TABLE uniq_fk_parent ( + a INT UNIQUE, + b INT, + c INT, + UNIQUE (b, c) +) + +statement ok +CREATE TABLE uniq_fk_child ( + a INT REFERENCES uniq_fk_parent (a), + b INT, + c INT, + FOREIGN KEY (b, c) REFERENCES uniq_fk_parent (b, c) ON UPDATE CASCADE, + UNIQUE WITHOUT INDEX (c) +) + +statement ok +CREATE TABLE other (k INT, v INT, w INT NOT NULL, x INT, y INT) + +# Insert some data into the other table. +statement ok +INSERT INTO other VALUES (10, 10, 1, 1, 1) + + +# -- Tests with INSERT -- +subtest Insert + +# Insert some non-null data. +statement ok +INSERT INTO uniq VALUES (1, 1, 1, 1, 1), (2, 2, 2, 2, 2) + +# Regular primary key violation. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "primary"\nDETAIL: Key \(k\)=\(1\) already exists\. +INSERT INTO uniq VALUES (1, 1, 1, 1, 1) + +# Regular unique index violation. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "uniq_v_key"\nDETAIL: Key \(v\)=\(1\) already exists\. +INSERT INTO uniq VALUES (3, 1, 1, 1, 1) + +# Attempt to insert the same keys twice in the same statement. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_w"\nDETAIL: Key \(w\)=\(3\) already exists\. +INSERT INTO uniq VALUES (3, 3, 3, 3, 3), (4, 4, 3, 3, 3) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_w"\nDETAIL: Key \(w\)=\(1\) already exists\. +INSERT INTO uniq VALUES (3, 3, 1, 1, 1) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_x_y"\nDETAIL: Key \(x, y\)=\(1, 1\) already exists\. +INSERT INTO uniq VALUES (3, 3, 3, 1, 1) + +# Even though y=1 already exists, (x,y)=(3,1) is unique. +statement ok +INSERT INTO uniq VALUES (3, 3, 3, 3, 1) + +# Inserting these rows should succeed since at least one of the columns in each +# UNIQUE WITHOUT INDEX constraint is null. +statement ok +INSERT INTO uniq VALUES (4, 4, NULL, NULL, 1), (5, 5, NULL, 2, NULL), (6, 6, NULL, NULL, 1), (7, 7, NULL, 2, NULL) + +# Insert with non-constant input. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_w"\nDETAIL: Key \(w\)=\(1\) already exists\. +INSERT INTO uniq SELECT k, v, w, x, y FROM other + +query IIIII colnames,rowsort +SELECT * FROM uniq +---- +k v w x y +1 1 1 1 1 +2 2 2 2 2 +3 3 3 3 1 +4 4 NULL NULL 1 +5 5 NULL 2 NULL +6 6 NULL NULL 1 +7 7 NULL 2 NULL + + +# Insert into a table in which the primary key overlaps some of the unique +# constraints. +statement ok +INSERT INTO uniq_overlaps_pk VALUES (1, 1, 1, 1), (2, 2, 2, 2) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_a"\nDETAIL: Key \(a\)=\(1\) already exists\. +INSERT INTO uniq_overlaps_pk VALUES (1, 2, 3, 4) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_b_c"\nDETAIL: Key \(b, c\)=\(1, 1\) already exists\. +INSERT INTO uniq_overlaps_pk VALUES (3, 1, 1, 3) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_c_d"\nDETAIL: Key \(c, d\)=\(1, 1\) already exists\. +INSERT INTO uniq_overlaps_pk VALUES (3, 3, 1, 1) + +statement ok +INSERT INTO uniq_overlaps_pk VALUES (3, 3, 1, 3) + +query IIII colnames,rowsort +SELECT * FROM uniq_overlaps_pk +---- +a b c d +1 1 1 1 +2 2 2 2 +3 3 1 3 + + +# Insert into a table with a hidden primary key. +statement ok +INSERT INTO uniq_hidden_pk VALUES (1, 1, 1, 1), (2, 2, 2, 2) + +# Insert with non-constant input. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_b_c"\nDETAIL: Key \(b, c\)=\(1, 1\) already exists\. +INSERT INTO uniq_hidden_pk SELECT k, w, x, y FROM other + +query IIII colnames,rowsort +SELECT * FROM uniq_hidden_pk +---- +a b c d +1 1 1 1 +2 2 2 2 + + +# Combine unique checks with foreign keys. +statement ok +INSERT INTO uniq_fk_parent VALUES (1, 1, 1), (2, 2, 2); +INSERT INTO uniq_fk_child VALUES (1, 1, 1), (2, 2, 2) + +# This passes the foreign key checks but fails the uniqueness checks. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_c"\nDETAIL: Key \(c\)=\(1\) already exists\. +INSERT INTO uniq_fk_child VALUES (1, 1, 1), (2, 2, 2) + +# This fails the foreign key checks but passes the uniqueness checks. +statement error pgcode 23503 pq: insert on table "uniq_fk_child" violates foreign key constraint "fk_b_ref_uniq_fk_parent"\nDETAIL: Key \(b, c\)=\(3, 3\) is not present in table "uniq_fk_parent"\. +INSERT INTO uniq_fk_child VALUES (3, 3, 3), (4, 4, 4) + +# This fails both types of checks. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_c"\nDETAIL: Key \(c\)=\(2\) already exists\. +INSERT INTO uniq_fk_child VALUES (1, 1, 2), (4, 2, 2) + +query III colnames,rowsort +SELECT * FROM uniq_fk_child +---- +a b c +1 1 1 +2 2 2 + + +# -- Tests with UPDATE -- +subtest Update + +# Set w to the same value it already has. +statement ok +UPDATE uniq SET w = 1, x = 2 WHERE k = 1 + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_w"\nDETAIL: Key \(w\)=\(1\) already exists\. +UPDATE uniq SET w = 1, x = 2 WHERE k = 2 + +# Fails because we are trying to update every row with the same values. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_w"\nDETAIL: Key \(w\)=\(100\) already exists\. +UPDATE uniq SET w = 100, x = 200 + +# This update targets the row (2, 2, 2, 2, 2). +statement ok +UPDATE uniq SET k = 10, v = 10, w = 10, x = NULL WHERE k = 2 + +# This insert should succeed now. +statement ok +INSERT INTO uniq VALUES (2, 2, 2, 2, 2) + +# No UNIQUE WITHOUT INDEX checks since none of the columns requiring checks are +# updated. +statement ok +UPDATE uniq SET k = 11, v = 11 WHERE k = 10 + +query IIIII colnames,rowsort +SELECT * FROM uniq +---- +k v w x y +1 1 1 2 1 +2 2 2 2 2 +3 3 3 3 1 +4 4 NULL NULL 1 +5 5 NULL 2 NULL +6 6 NULL NULL 1 +7 7 NULL 2 NULL +11 11 10 NULL 2 + + +# Update a table with multiple primary key columns. +# There are no rows with a=5. +statement ok +UPDATE uniq_overlaps_pk SET a = 1, b = 2, c = 3, d = 4 WHERE a = 5 + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_a"\nDETAIL: Key \(a\)=\(1\) already exists\. +UPDATE uniq_overlaps_pk SET a = 1, b = 2, c = 3, d = 4 WHERE a = 3 + +query IIII colnames,rowsort +SELECT * FROM uniq_overlaps_pk +---- +a b c d +1 1 1 1 +2 2 2 2 +3 3 1 3 + + +# Try to update a table with a hidden primary key with non-constant input. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_a"\nDETAIL: Key \(a\)=\(10\) already exists\. +UPDATE uniq_hidden_pk SET a = k FROM other + +query IIII colnames,rowsort +SELECT * FROM uniq_hidden_pk +---- +a b c d +1 1 1 1 +2 2 2 2 + + +# Combine unique checks with foreign keys. +# The cascade here should cause a uniqueness error for the child. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_c"\nDETAIL: Key \(c\)=\(1\) already exists\. +UPDATE uniq_fk_parent SET c = 1 + +# Combine unique checks with foreign keys. +# This passes the foreign key checks but fails the uniqueness check. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_c"\nDETAIL: Key \(c\)=\(2\) already exists\. +UPDATE uniq_fk_child SET b = 2, c = 2 + +query III colnames,rowsort +SELECT * FROM uniq_fk_child +---- +a b c +1 1 1 +2 2 2 diff --git a/pkg/sql/opt/exec/execbuilder/mutation.go b/pkg/sql/opt/exec/execbuilder/mutation.go index 4aecfb00b1f7..7a035cbf79ba 100644 --- a/pkg/sql/opt/exec/execbuilder/mutation.go +++ b/pkg/sql/opt/exec/execbuilder/mutation.go @@ -115,7 +115,9 @@ func (b *Builder) buildInsert(ins *memo.InsertExpr) (execPlan, error) { ep.outputCols = mutationOutputColMap(ins) } - // TODO(rytaft): build unique checks. + if err := b.buildUniqueChecks(ins.UniqueChecks); err != nil { + return execPlan{}, err + } if err := b.buildFKChecks(ins.FKChecks); err != nil { return execPlan{}, err @@ -148,6 +150,12 @@ func (b *Builder) tryBuildFastPathInsert(ins *memo.InsertExpr) (_ execPlan, ok b return execPlan{}, false, nil } + // We cannot use the fast path if any uniqueness checks are needed. + // TODO(rytaft): try to relax this restriction (see #58047). + if len(ins.UniqueChecks) > 0 { + return execPlan{}, false, nil + } + md := b.mem.Metadata() tab := md.Table(ins.Table) @@ -337,7 +345,9 @@ func (b *Builder) buildUpdate(upd *memo.UpdateExpr) (execPlan, error) { return execPlan{}, err } - // TODO(rytaft): build unique checks. + if err := b.buildUniqueChecks(upd.UniqueChecks); err != nil { + return execPlan{}, err + } if err := b.buildFKChecks(upd.FKChecks); err != nil { return execPlan{}, err @@ -421,7 +431,9 @@ func (b *Builder) buildUpsert(ups *memo.UpsertExpr) (execPlan, error) { return execPlan{}, err } - // TODO(rytaft): build unique checks. + if err := b.buildUniqueChecks(ups.UniqueChecks); err != nil { + return execPlan{}, err + } if err := b.buildFKChecks(ups.FKChecks); err != nil { return execPlan{}, err @@ -769,6 +781,38 @@ func mutationOutputColMap(mutation memo.RelExpr) opt.ColMap { return colMap } +// buildUniqueChecks builds uniqueness check queries. These check queries are +// used to enforce UNIQUE WITHOUT INDEX constraints. +// +// The checks consist of queries that will only return rows if a constraint is +// violated. Those queries are each wrapped in an ErrorIfRows operator, which +// will throw an appropriate error in case the inner query returns any rows. +func (b *Builder) buildUniqueChecks(checks memo.UniqueChecksExpr) error { + md := b.mem.Metadata() + for i := range checks { + c := &checks[i] + // Construct the query that returns uniqueness violations. + query, err := b.buildRelational(c.Check) + if err != nil { + return err + } + // Wrap the query in an error node. + mkErr := func(row tree.Datums) error { + keyVals := make(tree.Datums, len(c.KeyCols)) + for i, col := range c.KeyCols { + keyVals[i] = row[query.getNodeColumnOrdinal(col)] + } + return mkUniqueCheckErr(md, c, keyVals) + } + node, err := b.factory.ConstructErrorIfRows(query.root, mkErr) + if err != nil { + return err + } + b.checks = append(b.checks, node) + } + return nil +} + func (b *Builder) buildFKChecks(checks memo.FKChecksExpr) error { md := b.mem.Metadata() for i := range checks { @@ -795,6 +839,48 @@ func (b *Builder) buildFKChecks(checks memo.FKChecksExpr) error { return nil } +// mkUniqueCheckErr generates a user-friendly error describing a uniqueness +// violation. The keyVals are the values that correspond to the +// cat.UniqueConstraint columns. +func mkUniqueCheckErr(md *opt.Metadata, c *memo.UniqueChecksItem, keyVals tree.Datums) error { + tabMeta := md.TableMeta(c.Table) + uc := tabMeta.Table.Unique(c.CheckOrdinal) + constraintName := uc.Name() + var msg, details bytes.Buffer + + // Generate an error of the form: + // ERROR: duplicate key value violates unique constraint "foo" + // DETAIL: Key (k)=(2) already exists. + msg.WriteString("duplicate key value violates unique constraint ") + lexbase.EncodeEscapedSQLIdent(&msg, constraintName) + + details.WriteString("Key (") + for i := 0; i < uc.ColumnCount(); i++ { + if i > 0 { + details.WriteString(", ") + } + col := tabMeta.Table.Column(uc.ColumnOrdinal(tabMeta.Table, i)) + details.WriteString(string(col.ColName())) + } + details.WriteString(")=(") + for i, d := range keyVals { + if i > 0 { + details.WriteString(", ") + } + details.WriteString(d.String()) + } + + details.WriteString(") already exists.") + + return errors.WithDetail( + pgerror.WithConstraintName( + pgerror.Newf(pgcode.UniqueViolation, "%s", msg.String()), + constraintName, + ), + details.String(), + ) +} + // mkFKCheckErr generates a user-friendly error describing a foreign key // violation. The keyVals are the values that correspond to the // cat.ForeignKeyConstraint columns. diff --git a/pkg/sql/opt/exec/execbuilder/testdata/unique b/pkg/sql/opt/exec/execbuilder/testdata/unique new file mode 100644 index 000000000000..7f209d8d4d4f --- /dev/null +++ b/pkg/sql/opt/exec/execbuilder/testdata/unique @@ -0,0 +1,809 @@ +# LogicTest: local + +statement ok +SET experimental_enable_unique_without_index_constraints = true + +statement ok +CREATE TABLE uniq ( + k INT PRIMARY KEY, + v INT UNIQUE, + w INT UNIQUE WITHOUT INDEX, + x INT, + y INT, + UNIQUE WITHOUT INDEX (x, y) +) + +statement ok +CREATE TABLE uniq_overlaps_pk ( + a INT, + b INT, + c INT, + d INT, + PRIMARY KEY (a, b), + UNIQUE WITHOUT INDEX (b, c), + UNIQUE WITHOUT INDEX (a, b, d), + UNIQUE WITHOUT INDEX (a), + UNIQUE WITHOUT INDEX (c, d) +) + +statement ok +CREATE TABLE uniq_hidden_pk ( + a INT, + b INT, + c INT, + d INT, + UNIQUE WITHOUT INDEX (b, c), + UNIQUE WITHOUT INDEX (a, b, d), + UNIQUE WITHOUT INDEX (a) +) + +# TODO(rytaft): make this table use UNIQUE WITHOUT INDEX constraints once +# we allow foreign keys to reference them (see #57977). +statement ok +CREATE TABLE uniq_fk_parent ( + a INT UNIQUE, + b INT, + c INT, + UNIQUE (b, c), + FAMILY (rowid, a, b, c) +) + +statement ok +CREATE TABLE uniq_fk_child ( + a INT REFERENCES uniq_fk_parent (a), + b INT, + c INT, + FOREIGN KEY (b, c) REFERENCES uniq_fk_parent (b, c) ON UPDATE CASCADE, + UNIQUE WITHOUT INDEX (c) +) + +statement ok +CREATE TABLE other (k INT, v INT, w INT NOT NULL, x INT, y INT) + +# -- Tests with INSERT -- +subtest Insert + +# None of the inserted values have nulls. +query T +EXPLAIN INSERT INTO uniq VALUES (1, 1, 1, 1, 1), (2, 2, 2, 2, 2) +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq(k, v, w, x, y) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • values +│ size: 5 columns, 2 rows +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (right semi) +│ │ equality: (w) = (column3) +│ │ pred: column1 != k +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: uniq@primary +│ │ spans: FULL SCAN +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (right semi) + │ equality: (x, y) = (column4, column5) + │ pred: column1 != k + │ + ├── • scan + │ missing stats + │ table: uniq@primary + │ spans: FULL SCAN + │ + └── • scan buffer + label: buffer 1 + +# No need to plan checks for w since it's aways null. +# We still plan checks for x,y since neither column is null in all rows. +query T +EXPLAIN INSERT INTO uniq VALUES (4, 4, NULL, NULL, 1), (5, 5, NULL, 2, NULL) +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq(k, v, w, x, y) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • values +│ size: 5 columns, 2 rows +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (right semi) + │ equality: (x, y) = (column4, column5) + │ pred: column1 != k + │ + ├── • scan + │ missing stats + │ table: uniq@primary + │ spans: FULL SCAN + │ + └── • scan buffer + label: buffer 1 + +# Insert with non-constant input. +query T +EXPLAIN INSERT INTO uniq SELECT k, v, w, x, y FROM other +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq(k, v, w, x, y) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: other@primary +│ spans: FULL SCAN +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (semi) +│ │ equality: (w) = (w) +│ │ pred: k != k +│ │ +│ ├── • scan buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: uniq@primary +│ spans: FULL SCAN +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (semi) + │ equality: (x, y) = (x, y) + │ pred: k != k + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq@primary + spans: FULL SCAN + +# Add inequality filters for the primary key columns that are not part of each +# unique constraint to prevent rows from matching themselves in the semi join. +query T +EXPLAIN INSERT INTO uniq_overlaps_pk VALUES (1, 1, 1, 1), (2, 2, 2, 2) +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq_overlaps_pk(a, b, c, d) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • values +│ size: 4 columns, 2 rows +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (right semi) +│ │ equality: (b, c) = (column2, column3) +│ │ pred: column1 != a +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: uniq_overlaps_pk@primary +│ │ spans: FULL SCAN +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • lookup join (semi) +│ │ table: uniq_overlaps_pk@primary +│ │ equality: (column1) = (a) +│ │ pred: column2 != b +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (right semi) + │ equality: (c, d) = (column3, column4) + │ pred: (column1 != a) OR (column2 != b) + │ + ├── • scan + │ missing stats + │ table: uniq_overlaps_pk@primary + │ spans: FULL SCAN + │ + └── • scan buffer + label: buffer 1 + +# Insert with non-constant input. +# Add inequality filters for the hidden primary key column. +query T +EXPLAIN INSERT INTO uniq_hidden_pk SELECT k, v, x, y FROM other +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq_hidden_pk(a, b, c, d, rowid) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: other@primary +│ spans: FULL SCAN +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (semi) +│ │ equality: (v, x) = (b, c) +│ │ pred: column16 != rowid +│ │ +│ ├── • scan buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: uniq_hidden_pk@primary +│ spans: FULL SCAN +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (semi) +│ │ equality: (k, v, y) = (a, b, d) +│ │ pred: column16 != rowid +│ │ +│ ├── • scan buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: uniq_hidden_pk@primary +│ spans: FULL SCAN +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (semi) + │ equality: (k) = (a) + │ pred: column16 != rowid + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq_hidden_pk@primary + spans: FULL SCAN + +# Combine unique checks with foreign keys. +# TODO(rytaft): This currently isn't testing anything, since uniq_fk_parent +# doesn't have any UNIQUE WITHOUT INDEX constraints. See comment above where +# uniq_fk_parent is created. +query T +EXPLAIN INSERT INTO uniq_fk_parent VALUES (1, 1, 1), (2, 2, 2) +---- +distribution: local +vectorized: true +· +• insert +│ into: uniq_fk_parent(a, b, c, rowid) +│ auto commit +│ +└── • render + │ + └── • values + size: 3 columns, 2 rows + +# Combine unique checks with foreign keys. There should be two foreign key +# checks and one uniqueness check. +query T +EXPLAIN INSERT INTO uniq_fk_child VALUES (1, 1, 1), (2, 2, 2) +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq_fk_child(a, b, c, rowid) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • values +│ size: 3 columns, 2 rows +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (right semi) +│ │ equality: (c) = (column3) +│ │ pred: column10 != rowid +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: uniq_fk_child@primary +│ │ spans: FULL SCAN +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • lookup join (anti) +│ │ table: uniq_fk_parent@uniq_fk_parent_b_c_key +│ │ equality: (column2, column3) = (b,c) +│ │ equality cols are key +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • lookup join (anti) + │ table: uniq_fk_parent@uniq_fk_parent_a_key + │ equality: (column1) = (a) + │ equality cols are key + │ + └── • scan buffer + label: buffer 1 + +# -- Tests with UPDATE -- +subtest Update + +# None of the updated values have nulls. +query T +EXPLAIN UPDATE uniq SET w = 1, x = 2 +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq +│ │ set: w, x +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: uniq@primary +│ spans: FULL SCAN +│ locking strength: for update +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (semi) +│ │ equality: (w_new) = (w) +│ │ pred: k != k +│ │ +│ ├── • scan buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: uniq@primary +│ spans: FULL SCAN +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (semi) + │ equality: (x_new, y) = (x, y) + │ pred: k != k + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq@primary + spans: FULL SCAN + +# No need to plan checks for x,y since x is aways null. +# Also update the primary key. +query T +EXPLAIN UPDATE uniq SET k = 1, w = 2, x = NULL +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq +│ │ set: k, w, x +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: uniq@primary +│ spans: FULL SCAN +│ locking strength: for update +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (semi) + │ equality: (w_new) = (w) + │ pred: k_new != k + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq@primary + spans: FULL SCAN + +# No need to plan checks since none of the columns requiring checks are updated. +query T +EXPLAIN UPDATE uniq SET k = 1, v = 2 +---- +distribution: local +vectorized: true +· +• update +│ table: uniq +│ set: k, v +│ auto commit +│ +└── • render + │ + └── • scan + missing stats + table: uniq@primary + spans: FULL SCAN + locking strength: for update + +# Add inequality filters for the primary key columns that are not part of each +# unique constraint to prevent rows from matching themselves in the semi join. +query T +EXPLAIN UPDATE uniq_overlaps_pk SET a = 1, b = 2, c = 3, d = 4 WHERE a = 5 +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq_overlaps_pk +│ │ set: a, b, c, d +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: uniq_overlaps_pk@primary +│ spans: [/5 - /5] +│ locking strength: for update +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (right semi) +│ │ equality: (b, c) = (b_new, c_new) +│ │ pred: a_new != a +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: uniq_overlaps_pk@primary +│ │ spans: FULL SCAN +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • lookup join (semi) +│ │ table: uniq_overlaps_pk@primary +│ │ equality: (a_new) = (a) +│ │ pred: b_new != b +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (right semi) + │ equality: (c, d) = (c_new, d_new) + │ pred: (a_new != a) OR (b_new != b) + │ + ├── • scan + │ missing stats + │ table: uniq_overlaps_pk@primary + │ spans: FULL SCAN + │ + └── • scan buffer + label: buffer 1 + +# Update with non-constant input. +# No need to add a check for b,c since those columns weren't updated. +# Add inequality filters for the hidden primary key column. +query T +EXPLAIN UPDATE uniq_hidden_pk SET a = k FROM other +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq_hidden_pk +│ │ set: a +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • cross join +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: uniq_hidden_pk@primary +│ │ spans: FULL SCAN +│ │ +│ └── • scan +│ missing stats +│ table: other@primary +│ spans: FULL SCAN +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (semi) +│ │ equality: (k, b, d) = (a, b, d) +│ │ pred: rowid != rowid +│ │ +│ ├── • scan buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: uniq_hidden_pk@primary +│ spans: FULL SCAN +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (semi) + │ equality: (k) = (a) + │ pred: rowid != rowid + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq_hidden_pk@primary + spans: FULL SCAN + +# Combine unique checks with foreign keys. +# The cascade here affects the unique column in uniq_fk_child. +query T +EXPLAIN UPDATE uniq_fk_parent SET c = 1 +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq_fk_parent +│ │ set: c +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: uniq_fk_parent@primary +│ spans: FULL SCAN +│ locking strength: for update +│ +└── • fk-cascade + fk: fk_b_ref_uniq_fk_parent + input: buffer 1 + +# Combine unique checks with foreign keys. +# There is no uniquness check since column c is not updated. +query T +EXPLAIN UPDATE uniq_fk_child SET a = 1, b = 2 +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq_fk_child +│ │ set: a, b +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: uniq_fk_child@primary +│ spans: FULL SCAN +│ locking strength: for update +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (right anti) +│ │ equality: (b, c) = (b_new, c) +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: uniq_fk_parent@uniq_fk_parent_b_c_key +│ │ spans: FULL SCAN +│ │ +│ └── • filter +│ │ filter: c IS NOT NULL +│ │ +│ └── • scan buffer +│ label: buffer 1 +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (anti) + │ equality: (a_new) = (a) + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq_fk_parent@uniq_fk_parent_a_key + spans: FULL SCAN + +# Combine unique checks with foreign keys. +# There should be one fk check and one uniqueness check. +query T +EXPLAIN UPDATE uniq_fk_child SET b = 1, c = 2 +---- +distribution: local +vectorized: true +· +• root +│ +├── • update +│ │ table: uniq_fk_child +│ │ set: b, c +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • scan +│ missing stats +│ table: uniq_fk_child@primary +│ spans: FULL SCAN +│ locking strength: for update +│ +├── • constraint-check +│ │ +│ └── • error if rows +│ │ +│ └── • hash join (semi) +│ │ equality: (c_new) = (c) +│ │ pred: rowid != rowid +│ │ +│ ├── • scan buffer +│ │ label: buffer 1 +│ │ +│ └── • scan +│ missing stats +│ table: uniq_fk_child@primary +│ spans: FULL SCAN +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (anti) + │ equality: (b_new, c_new) = (b, c) + │ + ├── • scan buffer + │ label: buffer 1 + │ + └── • scan + missing stats + table: uniq_fk_parent@uniq_fk_parent_b_c_key + spans: FULL SCAN diff --git a/pkg/sql/opt/optbuilder/mutation_builder_unique.go b/pkg/sql/opt/optbuilder/mutation_builder_unique.go index af3fbb0536c6..65f97269c4be 100644 --- a/pkg/sql/opt/optbuilder/mutation_builder_unique.go +++ b/pkg/sql/opt/optbuilder/mutation_builder_unique.go @@ -212,8 +212,11 @@ func (h *uniqueCheckHelper) buildInsertionCheck() memo.UniqueChecksItem { return f.ConstructUniqueChecksItem(semiJoin, &memo.UniqueChecksItemPrivate{ Table: h.mb.tabID, CheckOrdinal: h.uniqueOrdinal, - KeyCols: withScanCols, - OpName: h.mb.opName, + // uniqueOrdinals is always a prefix of uniqueAndPrimaryKeyOrdinals, which + // maps 1-to-1 to the columns in withScanCols. The remaining columns are + // primary key columns and should not be included in the KeyCols. + KeyCols: withScanCols[:len(h.uniqueOrdinals)], + OpName: h.mb.opName, }) } diff --git a/pkg/sql/opt_catalog.go b/pkg/sql/opt_catalog.go index 351efaa72d66..0e24fdab3c5c 100644 --- a/pkg/sql/opt_catalog.go +++ b/pkg/sql/opt_catalog.go @@ -1068,14 +1068,12 @@ func (ot *optTable) InboundForeignKey(i int) cat.ForeignKeyConstraint { // UniqueCount is part of the cat.Table interface. func (ot *optTable) UniqueCount() int { - // TODO(rytaft): return the number of unique constraints (both with and - // without indexes). - return 0 + return len(ot.uniqueConstraints) } // Unique is part of the cat.Table interface. func (ot *optTable) Unique(i int) cat.UniqueConstraint { - panic(errors.AssertionFailedf("unique constraint [%d] does not exist", i)) + return &ot.uniqueConstraints[i] } // lookupColumnOrdinal returns the ordinal of the column with the given ID. A diff --git a/pkg/sql/testdata/savepoints b/pkg/sql/testdata/savepoints index 24fb390a5ffc..7c1f4a16c9f2 100644 --- a/pkg/sql/testdata/savepoints +++ b/pkg/sql/testdata/savepoints @@ -172,7 +172,7 @@ COMMIT -- NoTxn -> Open ###..... (none) 4: SAVEPOINT foo -- 0 rows -- Open -> Open ####.... foo -5: INSERT INTO t(x) VALUES (1) -- pq: duplicate key value violates unique constraint "t_x_key"\nDETAIL: Key (x)=(1) already exists\. +5: INSERT INTO t(x) VALUES (1) -- pq: duplicate key value violates unique constraint "t_x_key" -- Open -> Aborted XXXXXXXX foo 6: ROLLBACK TO SAVEPOINT foo -- 0 rows -- Aborted -> Open ####.... foo