diff --git a/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row b/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row index 8209c741846e..62d578cea78c 100644 --- a/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row +++ b/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row @@ -1035,6 +1035,54 @@ pk a b crdb_region_col statement error cannot drop column crdb_region_col as it is used to store the region in a REGIONAL BY ROW table\nHINT: You must change the table locality before dropping this table ALTER TABLE regional_by_row_table_as DROP COLUMN crdb_region_col +# We do not need uniqueness checks on pk since uniqueness can be inferred +# through the functional dependency between pk and the computed region column. +query T +EXPLAIN INSERT INTO regional_by_row_table_as (pk, a, b) VALUES (1, 1, 1) +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: regional_by_row_table_as(pk, a, b, crdb_region_col) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • values +│ size: 5 columns, 1 row +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • lookup join (semi) + │ table: regional_by_row_table_as@regional_by_row_table_as_b_key + │ equality: (lookup_join_const_col_@21, column3) = (crdb_region_col,b) + │ equality cols are key + │ pred: (column1 != pk) OR (column10 != crdb_region_col) + │ + └── • cross join + │ + ├── • values + │ size: 1 column, 3 rows + │ + └── • scan buffer + label: buffer 1 + +# TODO(mgartner): Update this error message to remove crdb_region (see #59504). +statement error pq: duplicate key value violates unique constraint "primary"\nDETAIL: Key \(crdb_region_col,pk\)=\('us-east-1',1\) already exists\. +INSERT INTO regional_by_row_table_as (pk, a, b) VALUES (1, 1, 1) + +statement ok +INSERT INTO regional_by_row_table_as (pk, a, b) VALUES (30, 1, 1) + +statement error pq: duplicate key value violates unique constraint "regional_by_row_table_as_b_key"\nDETAIL: Key \(b\)=\(1\) already exists\. +INSERT INTO regional_by_row_table_as (pk, a, b) VALUES (2, 1, 1) + + # Tests for altering the survivability of a REGIONAL BY ROW table. statement ok CREATE DATABASE alter_survive_db PRIMARY REGION "us-east-1" REGIONS "ca-central-1", "ap-southeast-2" SURVIVE REGION FAILURE diff --git a/pkg/sql/logictest/testdata/logic_test/unique b/pkg/sql/logictest/testdata/logic_test/unique index 3de7a80548ba..ace06c2edae0 100644 --- a/pkg/sql/logictest/testdata/logic_test/unique +++ b/pkg/sql/logictest/testdata/logic_test/unique @@ -86,6 +86,23 @@ CREATE TABLE uniq_enum ( UNIQUE WITHOUT INDEX (s, j) ) +statement ok +CREATE TABLE uniq_computed_pk ( + i INT, + s STRING, + d DECIMAL, + c_i_expr STRING AS (CASE WHEN i < 0 THEN 'foo' ELSE 'bar' END) STORED, + c_s STRING AS (s) VIRTUAL, + c_d DECIMAL AS (d) STORED, + c_d_expr STRING AS (d::string) STORED, + PRIMARY KEY (c_i_expr, i), + UNIQUE (c_s, s), + UNIQUE (c_d_expr, d), + UNIQUE WITHOUT INDEX (i), + UNIQUE WITHOUT INDEX (s), + UNIQUE WITHOUT INDEX (d) +) + statement ok CREATE TABLE other (k INT, v INT, w INT NOT NULL, x INT, y INT) @@ -322,6 +339,28 @@ a b NULL 5 NULL 5 +# Check that uniqueness violations are detected in a table with UNIQUE indexes +# containing computed columns that are dependent on UNIQUE WITHOUT INDEX +# columns. +statement ok +INSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'a', 1.0), (2, 'b', 2.0) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "primary"\nDETAIL: Key \(c_i_expr,i\)=\('bar',1\) already exists\. +INSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'c', 3.0) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "uniq_computed_pk_c_s_s_key"\nDETAIL: Key \(c_s,s\)=\('b','b'\) already exists\. +INSERT INTO uniq_computed_pk (i, s, d) VALUES (3, 'b', 3.0) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_d"\nDETAIL: Key \(d\)=\(1\.00\) already exists\. +INSERT INTO uniq_computed_pk (i, s, d) VALUES (3, 'c', 1.00) + +query ITFTTFT colnames,rowsort +SELECT * FROM uniq_computed_pk +---- +i s d c_i_expr c_s c_d c_d_expr +1 a 1.0 bar a 1.0 1.0 +2 b 2.0 bar b 2.0 2.0 + # -- Tests with UPDATE -- subtest Update @@ -475,6 +514,25 @@ NULL 5 NULL 5 NULL 10 +# Check that uniqueness violations are detected in a table with UNIQUE indexes +# containing computed columns that are dependent on UNIQUE WITHOUT INDEX +# columns. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "primary"\nDETAIL: Key \(c_i_expr,i\)=\('bar',1\) already exists\. +UPDATE uniq_computed_pk SET i = 1 WHERE i = 2 + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "uniq_computed_pk_c_s_s_key"\nDETAIL: Key \(c_s,s\)=\('a','a'\) already exists\. +UPDATE uniq_computed_pk SET s = 'a' WHERE i = 2 + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_d"\nDETAIL: Key \(d\)=\(1\.00\) already exists\. +UPDATE uniq_computed_pk SET d = 1.00 WHERE i = 2 + +query ITFTTFT colnames,rowsort +SELECT * FROM uniq_computed_pk +---- +i s d c_i_expr c_s c_d c_d_expr +1 a 1.0 bar a 1.0 1.0 +2 b 2.0 bar b 2.0 2.0 + # -- Tests with UPSERT -- subtest Upsert @@ -670,6 +728,26 @@ SELECT * FROM uniq_partial_index_and_constraint i 2 +# Check that uniqueness violations are detected in a table with UNIQUE indexes +# containing computed columns that are dependent on UNIQUE WITHOUT INDEX +# columns. +statement error pgcode 23505 pq: duplicate key value violates unique constraint "primary"\nDETAIL: Key \(c_i_expr,i\)=\('bar',2\) already exists\. +INSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'a', 1.0) ON CONFLICT (s) DO UPDATE SET i = 2 + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "uniq_computed_pk_c_s_s_key"\nDETAIL: Key \(c_s,s\)=\('b','b'\) already exists\. +UPSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'b', 1.0) + +statement error pgcode 23505 pq: duplicate key value violates unique constraint "unique_d"\nDETAIL: Key \(d\)=\(2\.00\) already exists\. +UPSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'a', 2.00) + +query ITFTTFT colnames,rowsort +SELECT * FROM uniq_computed_pk +---- +i s d c_i_expr c_s c_d c_d_expr +1 a 1.0 bar a 1.0 1.0 +2 b 2.0 bar b 2.0 2.0 + + # -- Tests with DELETE -- subtest Delete diff --git a/pkg/sql/opt/exec/execbuilder/testdata/unique b/pkg/sql/opt/exec/execbuilder/testdata/unique index 539b288c00ed..3a8640df2f30 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/unique +++ b/pkg/sql/opt/exec/execbuilder/testdata/unique @@ -110,8 +110,6 @@ CREATE TABLE uniq_partial_hidden_pk ( statement ok CREATE TYPE region AS ENUM ('us-east', 'us-west', 'eu-west') -# TODO(rytaft): When more of the multi-region syntax is supported, -# add it here. statement ok CREATE TABLE uniq_enum ( r region DEFAULT CASE (random()*3)::int WHEN 0 THEN 'us-east' WHEN 1 THEN 'us-west' ELSE 'eu-west' END, @@ -202,6 +200,29 @@ ALTER TABLE uniq_partial_enum INJECT STATISTICS '[ } ]' +statement ok +CREATE TABLE uniq_computed_pk ( + i INT, + s STRING, + d DECIMAL, + c_i_expr STRING AS (CASE WHEN i < 0 THEN 'foo' ELSE 'bar' END) STORED, + c_s STRING AS (s) VIRTUAL, + c_d DECIMAL AS (d) STORED, + c_d_expr STRING AS (d::string) STORED, + PRIMARY KEY (c_i_expr, i), + UNIQUE (c_s, s), + UNIQUE (c_d_expr, d), + UNIQUE WITHOUT INDEX (i), + UNIQUE WITHOUT INDEX (s), + UNIQUE WITHOUT INDEX (d), + FAMILY (i), + FAMILY (s), + FAMILY (d), + FAMILY (c_i_expr), + FAMILY (c_d), + FAMILY (c_d_expr) +) + statement ok CREATE TABLE other (k INT, v INT, w INT NOT NULL, x INT, y INT) @@ -1641,6 +1662,45 @@ vectorized: true columns: (column1, column2, column3, column4, check1, partial_index_put1) label: buffer 1 +# We can eliminate uniqueness checks for i and s due to functional dependencies. +# We cannot eliminate checks for d, since functional dependencies could not be +# inferred due to composite sensitivity of d::string. +query T +EXPLAIN INSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'a', 1.0), (2, 'b', 2.0) +---- +distribution: local +vectorized: true +· +• root +│ +├── • insert +│ │ into: uniq_computed_pk(i, s, d, c_i_expr, c_s, c_d, c_d_expr) +│ │ +│ └── • buffer +│ │ label: buffer 1 +│ │ +│ └── • render +│ │ +│ └── • values +│ size: 3 columns, 2 rows +│ +└── • constraint-check + │ + └── • error if rows + │ + └── • hash join (right semi) + │ equality: (d) = (column3) + │ pred: (column1 != i) OR (column13 != c_i_expr) + │ + ├── • scan + │ missing stats + │ table: uniq_computed_pk@uniq_computed_pk_c_d_expr_d_key + │ spans: FULL SCAN + │ + └── • scan buffer + label: buffer 1 + + # -- Tests with UPDATE -- subtest Update diff --git a/pkg/sql/opt/memo/testdata/logprops/scan b/pkg/sql/opt/memo/testdata/logprops/scan index f7133bf4cb62..09b535283756 100644 --- a/pkg/sql/opt/memo/testdata/logprops/scan +++ b/pkg/sql/opt/memo/testdata/logprops/scan @@ -399,6 +399,9 @@ index-join c └── interesting orderings: (+1) (+3,+1) # Test FDs for computed columns. +# We add equivalencies s=c_s and d=c_d, a strict dependency i->c_i_expr, and +# no dependency d->c_d_expr since the expression d::string is composite- +# sensitive. exec-ddl CREATE TABLE computed ( i INT, diff --git a/pkg/sql/opt/optbuilder/mutation_builder_unique.go b/pkg/sql/opt/optbuilder/mutation_builder_unique.go index 492875cff950..9b6d2cec5621 100644 --- a/pkg/sql/opt/optbuilder/mutation_builder_unique.go +++ b/pkg/sql/opt/optbuilder/mutation_builder_unique.go @@ -153,6 +153,11 @@ type uniqueCheckHelper struct { // primaryKeyOrdinals includes the ordinals from any primary key columns // that are not included in uniqueOrdinals. primaryKeyOrdinals util.FastIntSet + + // The scope and column ordinals of the scan that will serve as the right + // side of the semi join for the uniqueness checks. + scanScope *scope + scanOrdinals []int } // init initializes the helper with a unique constraint. @@ -179,7 +184,7 @@ func (h *uniqueCheckHelper) init(mb *mutationBuilder, uniqueOrdinal int) bool { // with columns that are a subset of the unique constraint columns. // Similarly, we don't need a check for a partial unique constraint if there // exists a non-partial unique constraint with columns that are a subset of - // the partial unique constrain columns. + // the partial unique constraint columns. primaryOrds := getIndexLaxKeyOrdinals(mb.tab.Index(cat.PrimaryIndex)) primaryOrds.DifferenceWith(uniqueOrds) if primaryOrds.Empty() { @@ -203,7 +208,44 @@ func (h *uniqueCheckHelper) init(mb *mutationBuilder, uniqueOrdinal int) bool { // If at least one unique column is getting a NULL value, unique check not // needed. - return numNullCols == 0 + if numNullCols != 0 { + return false + } + + // Build the scan that will serve as the right side of the semi join in the + // uniqueness check. We need to build the scan now so that we can use its + // FDs below. + h.scanScope, h.scanOrdinals = h.buildTableScan() + + // Check that the columns in the unique constraint aren't already known to + // form a lax key. This can happen if there is a unique index on a superset of + // these columns, where all other columns are computed columns that depend + // only on our columns. This is especially important for multi-region tables + // when the region column is computed. + // + // For example: + // + // CREATE TABLE tab ( + // k INT PRIMARY KEY, + // region crdb_internal_region AS ( + // CASE WHEN k < 10 THEN 'us-east1' ELSE 'us-west1' END + // ) STORED + // ) LOCALITY REGIONAL BY ROW AS region + // + // Because this is a REGIONAL BY ROW table, the region column is implicitly + // added to the front of every index, including the primary index. As a + // result, we would normally need to add a uniqueness check to all mutations + // to ensure that the primary key column (k in this case) remains unique. + // However, because the region column is computed and depends only on k, the + // presence of the unique index on (region, k) (i.e., the primary index) is + // sufficient to guarantee the uniqueness of k. + var uniqueCols opt.ColSet + h.uniqueOrdinals.ForEach(func(ord int) { + colID := h.scanScope.cols[ord].id + uniqueCols.Add(colID) + }) + fds := &h.scanScope.expr.Relational().FuncDeps + return !fds.ColsAreLaxKey(uniqueCols) } // buildInsertionCheck creates a unique check for rows which are added to a @@ -214,10 +256,9 @@ func (h *uniqueCheckHelper) buildInsertionCheck() memo.UniqueChecksItem { // Build a self semi-join, with the new values on the left and the // existing values on the right. - scanScope, ordinals := h.buildTableScan() withScanScope, _ := h.mb.buildCheckInputScan( - checkInputScanNewVals, ordinals, + checkInputScanNewVals, h.scanOrdinals, ) // Build the join filters: @@ -238,7 +279,7 @@ func (h *uniqueCheckHelper) buildInsertionCheck() memo.UniqueChecksItem { semiJoinFilters = append(semiJoinFilters, f.ConstructFiltersItem( f.ConstructEq( f.ConstructVariable(withScanScope.cols[i].id), - f.ConstructVariable(scanScope.cols[i].id), + f.ConstructVariable(h.scanScope.cols[i].id), ), )) } @@ -255,8 +296,8 @@ func (h *uniqueCheckHelper) buildInsertionCheck() memo.UniqueChecksItem { withScanPred := h.mb.b.buildScalar(typedPred, withScanScope, nil, nil, nil) semiJoinFilters = append(semiJoinFilters, f.ConstructFiltersItem(withScanPred)) - typedPred = scanScope.resolveAndRequireType(pred, types.Bool) - scanPred := h.mb.b.buildScalar(typedPred, scanScope, nil, nil, nil) + typedPred = h.scanScope.resolveAndRequireType(pred, types.Bool) + scanPred := h.mb.b.buildScalar(typedPred, h.scanScope, nil, nil, nil) semiJoinFilters = append(semiJoinFilters, f.ConstructFiltersItem(scanPred)) } @@ -268,7 +309,7 @@ func (h *uniqueCheckHelper) buildInsertionCheck() memo.UniqueChecksItem { for i, ok := h.primaryKeyOrdinals.Next(0); ok; i, ok = h.primaryKeyOrdinals.Next(i + 1) { pkFilterLocal := f.ConstructNe( f.ConstructVariable(withScanScope.cols[i].id), - f.ConstructVariable(scanScope.cols[i].id), + f.ConstructVariable(h.scanScope.cols[i].id), ) if pkFilter == nil { pkFilter = pkFilterLocal @@ -278,7 +319,7 @@ func (h *uniqueCheckHelper) buildInsertionCheck() memo.UniqueChecksItem { } semiJoinFilters = append(semiJoinFilters, f.ConstructFiltersItem(pkFilter)) - semiJoin := f.ConstructSemiJoin(withScanScope.expr, scanScope.expr, semiJoinFilters, memo.EmptyJoinPrivate) + semiJoin := f.ConstructSemiJoin(withScanScope.expr, h.scanScope.expr, semiJoinFilters, memo.EmptyJoinPrivate) // Collect the key columns that will be shown in the error message if there // is a duplicate key violation resulting from this uniqueness check. diff --git a/pkg/sql/opt/optbuilder/testdata/unique-checks-insert b/pkg/sql/opt/optbuilder/testdata/unique-checks-insert index 178d3b4dc14d..b1dee1aa9ec5 100644 --- a/pkg/sql/opt/optbuilder/testdata/unique-checks-insert +++ b/pkg/sql/opt/optbuilder/testdata/unique-checks-insert @@ -1562,3 +1562,80 @@ insert uniq_partial_constraint_and_partial_index ├── b:25 > 10 ├── uniq_partial_constraint_and_partial_index.b:21 > 10 └── k:23 != uniq_partial_constraint_and_partial_index.k:19 + +exec-ddl +CREATE TABLE uniq_computed_pk ( + i INT, + s STRING, + d DECIMAL, + c_i_expr STRING AS (CASE WHEN i < 0 THEN 'foo' ELSE 'bar' END) STORED, + c_s STRING AS (s) VIRTUAL, + c_d DECIMAL AS (d) STORED, + c_d_expr STRING AS (d::string) STORED, + PRIMARY KEY (c_i_expr, i), + UNIQUE (c_s, s), + UNIQUE (c_d_expr, d), + UNIQUE WITHOUT INDEX (i), + UNIQUE WITHOUT INDEX (s), + UNIQUE WITHOUT INDEX (d) +) +---- + +# We can eliminate uniqueness checks for i and s due to functional dependencies. +# We cannot eliminate checks for d, since functional dependencies could not be +# inferred due to composite sensitivity of d::string. +build +INSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'a', 1.0), (2, 'b', 2.0) +---- +insert uniq_computed_pk + ├── columns: + ├── insert-mapping: + │ ├── column1:9 => uniq_computed_pk.i:1 + │ ├── column2:10 => uniq_computed_pk.s:2 + │ ├── column3:11 => uniq_computed_pk.d:3 + │ ├── column12:12 => uniq_computed_pk.c_i_expr:4 + │ ├── column2:10 => uniq_computed_pk.c_s:5 + │ ├── column3:11 => uniq_computed_pk.c_d:6 + │ └── column13:13 => uniq_computed_pk.c_d_expr:7 + ├── input binding: &1 + ├── project + │ ├── columns: column12:12!null column13:13!null column1:9!null column2:10!null column3:11!null + │ ├── values + │ │ ├── columns: column1:9!null column2:10!null column3:11!null + │ │ ├── (1, 'a', 1.0) + │ │ └── (2, 'b', 2.0) + │ └── projections + │ ├── CASE WHEN column1:9 < 0 THEN 'foo' ELSE 'bar' END [as=column12:12] + │ └── column3:11::STRING [as=column13:13] + └── unique-checks + └── unique-checks-item: uniq_computed_pk(d) + └── semi-join (hash) + ├── columns: i:38!null s:39!null d:40!null c_i_expr:41!null c_s:42!null c_d:43!null c_d_expr:44!null + ├── with-scan &1 + │ ├── columns: i:38!null s:39!null d:40!null c_i_expr:41!null c_s:42!null c_d:43!null c_d_expr:44!null + │ └── mapping: + │ ├── column1:9 => i:38 + │ ├── column2:10 => s:39 + │ ├── column3:11 => d:40 + │ ├── column12:12 => c_i_expr:41 + │ ├── column2:10 => c_s:42 + │ ├── column3:11 => c_d:43 + │ └── column13:13 => c_d_expr:44 + ├── project + │ ├── columns: uniq_computed_pk.c_s:34 uniq_computed_pk.i:30!null uniq_computed_pk.s:31 uniq_computed_pk.d:32 uniq_computed_pk.c_i_expr:33!null uniq_computed_pk.c_d:35 uniq_computed_pk.c_d_expr:36 + │ ├── scan uniq_computed_pk + │ │ ├── columns: uniq_computed_pk.i:30!null uniq_computed_pk.s:31 uniq_computed_pk.d:32 uniq_computed_pk.c_i_expr:33!null uniq_computed_pk.c_d:35 uniq_computed_pk.c_d_expr:36 + │ │ └── computed column expressions + │ │ ├── uniq_computed_pk.c_i_expr:33 + │ │ │ └── CASE WHEN uniq_computed_pk.i:30 < 0 THEN 'foo' ELSE 'bar' END + │ │ ├── uniq_computed_pk.c_s:34 + │ │ │ └── uniq_computed_pk.s:31 + │ │ ├── uniq_computed_pk.c_d:35 + │ │ │ └── uniq_computed_pk.d:32 + │ │ └── uniq_computed_pk.c_d_expr:36 + │ │ └── uniq_computed_pk.d:32::STRING + │ └── projections + │ └── uniq_computed_pk.s:31 [as=uniq_computed_pk.c_s:34] + └── filters + ├── d:40 = uniq_computed_pk.d:32 + └── (i:38 != uniq_computed_pk.i:30) OR (c_i_expr:41 != uniq_computed_pk.c_i_expr:33) diff --git a/pkg/sql/opt/optbuilder/testdata/unique-checks-update b/pkg/sql/opt/optbuilder/testdata/unique-checks-update index a1627c60cd21..8a3398c8ec03 100644 --- a/pkg/sql/opt/optbuilder/testdata/unique-checks-update +++ b/pkg/sql/opt/optbuilder/testdata/unique-checks-update @@ -1011,3 +1011,98 @@ update uniq_partial_hidden_pk ├── b:21 > 0 ├── uniq_partial_hidden_pk.b:17 > 0 └── rowid:22 != uniq_partial_hidden_pk.rowid:18 + +exec-ddl +CREATE TABLE uniq_computed_pk ( + i INT, + s STRING, + d DECIMAL, + c_i_expr STRING AS (CASE WHEN i < 0 THEN 'foo' ELSE 'bar' END) STORED, + c_s STRING AS (s) VIRTUAL, + c_d DECIMAL AS (d) STORED, + c_d_expr STRING AS (d::string) STORED, + PRIMARY KEY (c_i_expr, i), + UNIQUE (c_s, s), + UNIQUE (c_d_expr, d), + UNIQUE WITHOUT INDEX (i), + UNIQUE WITHOUT INDEX (s), + UNIQUE WITHOUT INDEX (d) +) +---- + +# We can eliminate uniqueness checks for i and s due to functional dependencies. +# We cannot eliminate checks for d, since functional dependencies could not be +# inferred due to composite sensitivity of d::string. +build +UPDATE uniq_computed_pk SET i=1, s='a', d=1.0 +---- +update uniq_computed_pk + ├── columns: + ├── fetch columns: uniq_computed_pk.i:9 uniq_computed_pk.s:10 uniq_computed_pk.d:11 uniq_computed_pk.c_i_expr:12 uniq_computed_pk.c_s:13 uniq_computed_pk.c_d:14 uniq_computed_pk.c_d_expr:15 + ├── update-mapping: + │ ├── i_new:17 => uniq_computed_pk.i:1 + │ ├── s_new:18 => uniq_computed_pk.s:2 + │ ├── d_new:19 => uniq_computed_pk.d:3 + │ ├── column20:20 => uniq_computed_pk.c_i_expr:4 + │ ├── s_new:18 => uniq_computed_pk.c_s:5 + │ ├── d_new:19 => uniq_computed_pk.c_d:6 + │ └── column21:21 => uniq_computed_pk.c_d_expr:7 + ├── input binding: &1 + ├── project + │ ├── columns: column20:20!null column21:21!null uniq_computed_pk.i:9!null uniq_computed_pk.s:10 uniq_computed_pk.d:11 uniq_computed_pk.c_i_expr:12!null uniq_computed_pk.c_s:13 uniq_computed_pk.c_d:14 uniq_computed_pk.c_d_expr:15 crdb_internal_mvcc_timestamp:16 i_new:17!null s_new:18!null d_new:19!null + │ ├── project + │ │ ├── columns: i_new:17!null s_new:18!null d_new:19!null uniq_computed_pk.i:9!null uniq_computed_pk.s:10 uniq_computed_pk.d:11 uniq_computed_pk.c_i_expr:12!null uniq_computed_pk.c_s:13 uniq_computed_pk.c_d:14 uniq_computed_pk.c_d_expr:15 crdb_internal_mvcc_timestamp:16 + │ │ ├── project + │ │ │ ├── columns: uniq_computed_pk.c_s:13 uniq_computed_pk.i:9!null uniq_computed_pk.s:10 uniq_computed_pk.d:11 uniq_computed_pk.c_i_expr:12!null uniq_computed_pk.c_d:14 uniq_computed_pk.c_d_expr:15 crdb_internal_mvcc_timestamp:16 + │ │ │ ├── scan uniq_computed_pk + │ │ │ │ ├── columns: uniq_computed_pk.i:9!null uniq_computed_pk.s:10 uniq_computed_pk.d:11 uniq_computed_pk.c_i_expr:12!null uniq_computed_pk.c_d:14 uniq_computed_pk.c_d_expr:15 crdb_internal_mvcc_timestamp:16 + │ │ │ │ └── computed column expressions + │ │ │ │ ├── uniq_computed_pk.c_i_expr:12 + │ │ │ │ │ └── CASE WHEN uniq_computed_pk.i:9 < 0 THEN 'foo' ELSE 'bar' END + │ │ │ │ ├── uniq_computed_pk.c_s:13 + │ │ │ │ │ └── uniq_computed_pk.s:10 + │ │ │ │ ├── uniq_computed_pk.c_d:14 + │ │ │ │ │ └── uniq_computed_pk.d:11 + │ │ │ │ └── uniq_computed_pk.c_d_expr:15 + │ │ │ │ └── uniq_computed_pk.d:11::STRING + │ │ │ └── projections + │ │ │ └── uniq_computed_pk.s:10 [as=uniq_computed_pk.c_s:13] + │ │ └── projections + │ │ ├── 1 [as=i_new:17] + │ │ ├── 'a' [as=s_new:18] + │ │ └── 1.0 [as=d_new:19] + │ └── projections + │ ├── CASE WHEN i_new:17 < 0 THEN 'foo' ELSE 'bar' END [as=column20:20] + │ └── d_new:19::STRING [as=column21:21] + └── unique-checks + └── unique-checks-item: uniq_computed_pk(d) + └── semi-join (hash) + ├── columns: i:46!null s:47!null d:48!null c_i_expr:49!null c_s:50!null c_d:51!null c_d_expr:52!null + ├── with-scan &1 + │ ├── columns: i:46!null s:47!null d:48!null c_i_expr:49!null c_s:50!null c_d:51!null c_d_expr:52!null + │ └── mapping: + │ ├── i_new:17 => i:46 + │ ├── s_new:18 => s:47 + │ ├── d_new:19 => d:48 + │ ├── column20:20 => c_i_expr:49 + │ ├── s_new:18 => c_s:50 + │ ├── d_new:19 => c_d:51 + │ └── column21:21 => c_d_expr:52 + ├── project + │ ├── columns: uniq_computed_pk.c_s:42 uniq_computed_pk.i:38!null uniq_computed_pk.s:39 uniq_computed_pk.d:40 uniq_computed_pk.c_i_expr:41!null uniq_computed_pk.c_d:43 uniq_computed_pk.c_d_expr:44 + │ ├── scan uniq_computed_pk + │ │ ├── columns: uniq_computed_pk.i:38!null uniq_computed_pk.s:39 uniq_computed_pk.d:40 uniq_computed_pk.c_i_expr:41!null uniq_computed_pk.c_d:43 uniq_computed_pk.c_d_expr:44 + │ │ └── computed column expressions + │ │ ├── uniq_computed_pk.c_i_expr:41 + │ │ │ └── CASE WHEN uniq_computed_pk.i:38 < 0 THEN 'foo' ELSE 'bar' END + │ │ ├── uniq_computed_pk.c_s:42 + │ │ │ └── uniq_computed_pk.s:39 + │ │ ├── uniq_computed_pk.c_d:43 + │ │ │ └── uniq_computed_pk.d:40 + │ │ └── uniq_computed_pk.c_d_expr:44 + │ │ └── uniq_computed_pk.d:40::STRING + │ └── projections + │ └── uniq_computed_pk.s:39 [as=uniq_computed_pk.c_s:42] + └── filters + ├── d:48 = uniq_computed_pk.d:40 + └── (i:46 != uniq_computed_pk.i:38) OR (c_i_expr:49 != uniq_computed_pk.c_i_expr:41) diff --git a/pkg/sql/opt/optbuilder/testdata/unique-checks-upsert b/pkg/sql/opt/optbuilder/testdata/unique-checks-upsert index 2d4e220a5389..fdd063532a35 100644 --- a/pkg/sql/opt/optbuilder/testdata/unique-checks-upsert +++ b/pkg/sql/opt/optbuilder/testdata/unique-checks-upsert @@ -1565,3 +1565,128 @@ upsert t └── filters ├── i:17 = t.i:14 └── rowid:18 != t.rowid:15 + +exec-ddl +CREATE TABLE uniq_computed_pk ( + i INT, + s STRING, + d DECIMAL, + c_i_expr STRING AS (CASE WHEN i < 0 THEN 'foo' ELSE 'bar' END) STORED, + c_s STRING AS (s) VIRTUAL, + c_d DECIMAL AS (d) STORED, + c_d_expr STRING AS (d::string) STORED, + PRIMARY KEY (c_i_expr, i), + UNIQUE (c_s, s), + UNIQUE (c_d_expr, d), + UNIQUE WITHOUT INDEX (i), + UNIQUE WITHOUT INDEX (s), + UNIQUE WITHOUT INDEX (d) +) +---- + +# We can eliminate uniqueness checks for i and s due to functional dependencies. +# We cannot eliminate checks for d, since functional dependencies could not be +# inferred due to composite sensitivity of d::string. +build +UPSERT INTO uniq_computed_pk (i, s, d) VALUES (1, 'a', 1.0), (2, 'b', 2.0) +---- +upsert uniq_computed_pk + ├── columns: + ├── arbiter indexes: primary + ├── canary column: uniq_computed_pk.c_i_expr:17 + ├── fetch columns: uniq_computed_pk.i:14 uniq_computed_pk.s:15 uniq_computed_pk.d:16 uniq_computed_pk.c_i_expr:17 uniq_computed_pk.c_s:18 uniq_computed_pk.c_d:19 uniq_computed_pk.c_d_expr:20 + ├── insert-mapping: + │ ├── column1:9 => uniq_computed_pk.i:1 + │ ├── column2:10 => uniq_computed_pk.s:2 + │ ├── column3:11 => uniq_computed_pk.d:3 + │ ├── column12:12 => uniq_computed_pk.c_i_expr:4 + │ ├── column2:10 => uniq_computed_pk.c_s:5 + │ ├── column3:11 => uniq_computed_pk.c_d:6 + │ └── column13:13 => uniq_computed_pk.c_d_expr:7 + ├── update-mapping: + │ ├── column2:10 => uniq_computed_pk.s:2 + │ ├── column3:11 => uniq_computed_pk.d:3 + │ ├── column2:10 => uniq_computed_pk.c_s:5 + │ ├── column3:11 => uniq_computed_pk.c_d:6 + │ └── column13:13 => uniq_computed_pk.c_d_expr:7 + ├── input binding: &1 + ├── project + │ ├── columns: upsert_i:23 upsert_c_i_expr:24 column1:9!null column2:10!null column3:11!null column12:12!null column13:13!null uniq_computed_pk.i:14 uniq_computed_pk.s:15 uniq_computed_pk.d:16 uniq_computed_pk.c_i_expr:17 uniq_computed_pk.c_s:18 uniq_computed_pk.c_d:19 uniq_computed_pk.c_d_expr:20 crdb_internal_mvcc_timestamp:21 column22:22 + │ ├── project + │ │ ├── columns: column22:22 column1:9!null column2:10!null column3:11!null column12:12!null column13:13!null uniq_computed_pk.i:14 uniq_computed_pk.s:15 uniq_computed_pk.d:16 uniq_computed_pk.c_i_expr:17 uniq_computed_pk.c_s:18 uniq_computed_pk.c_d:19 uniq_computed_pk.c_d_expr:20 crdb_internal_mvcc_timestamp:21 + │ │ ├── left-join (hash) + │ │ │ ├── columns: column1:9!null column2:10!null column3:11!null column12:12!null column13:13!null uniq_computed_pk.i:14 uniq_computed_pk.s:15 uniq_computed_pk.d:16 uniq_computed_pk.c_i_expr:17 uniq_computed_pk.c_s:18 uniq_computed_pk.c_d:19 uniq_computed_pk.c_d_expr:20 crdb_internal_mvcc_timestamp:21 + │ │ │ ├── ensure-upsert-distinct-on + │ │ │ │ ├── columns: column1:9!null column2:10!null column3:11!null column12:12!null column13:13!null + │ │ │ │ ├── grouping columns: column1:9!null column12:12!null + │ │ │ │ ├── project + │ │ │ │ │ ├── columns: column12:12!null column13:13!null column1:9!null column2:10!null column3:11!null + │ │ │ │ │ ├── values + │ │ │ │ │ │ ├── columns: column1:9!null column2:10!null column3:11!null + │ │ │ │ │ │ ├── (1, 'a', 1.0) + │ │ │ │ │ │ └── (2, 'b', 2.0) + │ │ │ │ │ └── projections + │ │ │ │ │ ├── CASE WHEN column1:9 < 0 THEN 'foo' ELSE 'bar' END [as=column12:12] + │ │ │ │ │ └── column3:11::STRING [as=column13:13] + │ │ │ │ └── aggregations + │ │ │ │ ├── first-agg [as=column2:10] + │ │ │ │ │ └── column2:10 + │ │ │ │ ├── first-agg [as=column3:11] + │ │ │ │ │ └── column3:11 + │ │ │ │ └── first-agg [as=column13:13] + │ │ │ │ └── column13:13 + │ │ │ ├── project + │ │ │ │ ├── columns: uniq_computed_pk.c_s:18 uniq_computed_pk.i:14!null uniq_computed_pk.s:15 uniq_computed_pk.d:16 uniq_computed_pk.c_i_expr:17!null uniq_computed_pk.c_d:19 uniq_computed_pk.c_d_expr:20 crdb_internal_mvcc_timestamp:21 + │ │ │ │ ├── scan uniq_computed_pk + │ │ │ │ │ ├── columns: uniq_computed_pk.i:14!null uniq_computed_pk.s:15 uniq_computed_pk.d:16 uniq_computed_pk.c_i_expr:17!null uniq_computed_pk.c_d:19 uniq_computed_pk.c_d_expr:20 crdb_internal_mvcc_timestamp:21 + │ │ │ │ │ └── computed column expressions + │ │ │ │ │ ├── uniq_computed_pk.c_i_expr:17 + │ │ │ │ │ │ └── CASE WHEN uniq_computed_pk.i:14 < 0 THEN 'foo' ELSE 'bar' END + │ │ │ │ │ ├── uniq_computed_pk.c_s:18 + │ │ │ │ │ │ └── uniq_computed_pk.s:15 + │ │ │ │ │ ├── uniq_computed_pk.c_d:19 + │ │ │ │ │ │ └── uniq_computed_pk.d:16 + │ │ │ │ │ └── uniq_computed_pk.c_d_expr:20 + │ │ │ │ │ └── uniq_computed_pk.d:16::STRING + │ │ │ │ └── projections + │ │ │ │ └── uniq_computed_pk.s:15 [as=uniq_computed_pk.c_s:18] + │ │ │ └── filters + │ │ │ ├── column1:9 = uniq_computed_pk.i:14 + │ │ │ └── column12:12 = uniq_computed_pk.c_i_expr:17 + │ │ └── projections + │ │ └── CASE WHEN uniq_computed_pk.i:14 < 0 THEN 'foo' ELSE 'bar' END [as=column22:22] + │ └── projections + │ ├── CASE WHEN uniq_computed_pk.c_i_expr:17 IS NULL THEN column1:9 ELSE uniq_computed_pk.i:14 END [as=upsert_i:23] + │ └── CASE WHEN uniq_computed_pk.c_i_expr:17 IS NULL THEN column12:12 ELSE uniq_computed_pk.c_i_expr:17 END [as=upsert_c_i_expr:24] + └── unique-checks + └── unique-checks-item: uniq_computed_pk(d) + └── semi-join (hash) + ├── columns: i:49 s:50!null d:51!null c_i_expr:52 c_s:53!null c_d:54!null c_d_expr:55!null + ├── with-scan &1 + │ ├── columns: i:49 s:50!null d:51!null c_i_expr:52 c_s:53!null c_d:54!null c_d_expr:55!null + │ └── mapping: + │ ├── upsert_i:23 => i:49 + │ ├── column2:10 => s:50 + │ ├── column3:11 => d:51 + │ ├── upsert_c_i_expr:24 => c_i_expr:52 + │ ├── column2:10 => c_s:53 + │ ├── column3:11 => c_d:54 + │ └── column13:13 => c_d_expr:55 + ├── project + │ ├── columns: uniq_computed_pk.c_s:45 uniq_computed_pk.i:41!null uniq_computed_pk.s:42 uniq_computed_pk.d:43 uniq_computed_pk.c_i_expr:44!null uniq_computed_pk.c_d:46 uniq_computed_pk.c_d_expr:47 + │ ├── scan uniq_computed_pk + │ │ ├── columns: uniq_computed_pk.i:41!null uniq_computed_pk.s:42 uniq_computed_pk.d:43 uniq_computed_pk.c_i_expr:44!null uniq_computed_pk.c_d:46 uniq_computed_pk.c_d_expr:47 + │ │ └── computed column expressions + │ │ ├── uniq_computed_pk.c_i_expr:44 + │ │ │ └── CASE WHEN uniq_computed_pk.i:41 < 0 THEN 'foo' ELSE 'bar' END + │ │ ├── uniq_computed_pk.c_s:45 + │ │ │ └── uniq_computed_pk.s:42 + │ │ ├── uniq_computed_pk.c_d:46 + │ │ │ └── uniq_computed_pk.d:43 + │ │ └── uniq_computed_pk.c_d_expr:47 + │ │ └── uniq_computed_pk.d:43::STRING + │ └── projections + │ └── uniq_computed_pk.s:42 [as=uniq_computed_pk.c_s:45] + └── filters + ├── d:51 = uniq_computed_pk.d:43 + └── (i:49 != uniq_computed_pk.i:41) OR (c_i_expr:52 != uniq_computed_pk.c_i_expr:44)