Skip to content

Commit

Permalink
Merge #60452
Browse files Browse the repository at this point in the history
60452: sql: add tests for check constraints on virtual columns r=RaduBerinde a=RaduBerinde

Release note: None

Co-authored-by: Radu Berinde <radu@cockroachlabs.com>
  • Loading branch information
craig[bot] and RaduBerinde committed Feb 17, 2021
2 parents 1173f64 + 1cfab22 commit 988e457
Show file tree
Hide file tree
Showing 3 changed files with 267 additions and 1 deletion.
139 changes: 138 additions & 1 deletion pkg/sql/logictest/testdata/logic_test/virtual_columns
Original file line number Diff line number Diff line change
Expand Up @@ -467,7 +467,107 @@ ALTER TABLE fk2 ADD CONSTRAINT foo FOREIGN KEY (x) REFERENCES fk(u)
statement error virtual column "v" cannot reference a foreign key
ALTER TABLE fk2 ADD CONSTRAINT foo FOREIGN KEY (v) REFERENCES fk(a)

subtest schema_changes
# Tests with not null virtual columns.
subtest NotNull

statement ok
CREATE TABLE n (
a INT PRIMARY KEY,
b INT,
v INT NOT NULL AS (a+b) VIRTUAL
)

statement error null value in column "v" violates not-null constraint
INSERT INTO n VALUES (1, NULL)

statement ok
INSERT INTO n VALUES (1, 1), (2, 2)

statement error null value in column "v" violates not-null constraint
UPDATE n SET b = NULL WHERE a > 0

statement error null value in column "v" violates not-null constraint
UPSERT INTO n VALUES (1, NULL)

statement error null value in column "v" violates not-null constraint
UPSERT INTO n VALUES (3, NULL)

statement ok
INSERT INTO n VALUES (1, NULL) ON CONFLICT DO NOTHING

statement error null value in column "v" violates not-null constraint
INSERT INTO n VALUES (3, NULL) ON CONFLICT DO NOTHING

statement error null value in column "v" violates not-null constraint
INSERT INTO n VALUES (1, 10) ON CONFLICT (a) DO UPDATE SET b = NULL

statement error null value in column "v" violates not-null constraint
INSERT INTO n VALUES (3, NULL) ON CONFLICT (a) DO UPDATE SET b = NULL

# Tests with check constraints on virtual columns.
subtest Checks

statement ok
CREATE TABLE t_check (
a INT PRIMARY KEY,
b INT,
v INT AS (a+b) VIRTUAL CHECK (v >= 10),
w INT AS (a*b) VIRTUAL,
CHECK (v < w)
)

statement error failed to satisfy CHECK constraint
INSERT INTO t_check VALUES (1,1), (5,5)

statement ok
INSERT INTO t_check VALUES (5,5), (6,6)

statement error failed to satisfy CHECK constraint
UPDATE t_check SET b=b-1

statement ok
UPDATE t_check SET b=b+1

query IIII colnames,rowsort
SELECT * FROM t_check
----
a b v w
5 6 11 30
6 7 13 42

statement error failed to satisfy CHECK constraint
UPSERT INTO t_check VALUES (5, 2), (8, 8)

statement error failed to satisfy CHECK constraint
UPSERT INTO t_check VALUES (5, 10), (8, 1)

statement ok
UPSERT INTO t_check VALUES (5, 10), (8, 8)

query IIII colnames,rowsort
SELECT * FROM t_check
----
a b v w
5 10 15 50
6 7 13 42
8 8 16 64

statement error failed to satisfy CHECK constraint
INSERT INTO t_check VALUES (5, 1) ON CONFLICT (a) DO UPDATE SET b=3

statement ok
INSERT INTO t_check VALUES (5, 1) ON CONFLICT (a) DO UPDATE SET b=5

query IIII colnames,rowsort
SELECT * FROM t_check
----
a b v w
5 5 10 25
6 7 13 42
8 8 16 64

# Test schema changes with virtual columns.
subtest SchemaChanges

statement ok
CREATE TABLE sc (a INT PRIMARY KEY, b INT)
Expand Down Expand Up @@ -635,3 +735,40 @@ SELECT a FROM sc@v_partial_idx WHERE v > 20
----
2
3

statement ok
INSERT INTO sc VALUES (10, 10), (11, 9)

query III rowsort,colnames
SELECT * FROM sc
----
a b v
1 10 11
2 20 22
3 30 33
10 10 20
11 9 20

# Create a partial unique index on v which should fail.
statement error violates unique constraint
CREATE UNIQUE INDEX v_partial_idx2 ON sc(v) WHERE v > 10

# Create a check constraint which should fail.
statement error validation.*failed on row
ALTER TABLE sc ADD CONSTRAINT c CHECK (v < 30)

statement ok
ALTER TABLE sc ADD CONSTRAINT c CHECK (v < 40)

statement error failed to satisfy CHECK constraint
UPDATE sc SET b=b+10

# Add a virtual column with a check constraint.
statement error validation.*failed on row
ALTER TABLE sc ADD COLUMN w INT AS (a*b) VIRTUAL CHECK (w < 100)

statement ok
ALTER TABLE sc ADD COLUMN w INT AS (a*b) VIRTUAL CHECK (w <= 100)

statement error failed to satisfy CHECK constraint
INSERT INTO sc VALUES (20, 20)
31 changes: 31 additions & 0 deletions pkg/sql/opt/exec/execbuilder/testdata/virtual_columns
Original file line number Diff line number Diff line change
Expand Up @@ -389,6 +389,8 @@ vectorized: true
table: t_idx@t_idx_v_idx
spans: /1-/2

subtest Update

query T
EXPLAIN (VERBOSE) UPDATE t SET a=a+1
----
Expand Down Expand Up @@ -707,6 +709,8 @@ vectorized: true
table: t_idx@primary
spans: FULL SCAN

subtest Upsert

query T
EXPLAIN (VERBOSE) UPSERT INTO t VALUES (1, 10), (2, 20), (3, 30), (4, 40)
----
Expand Down Expand Up @@ -1334,3 +1338,30 @@ vectorized: true
row 1, expr 0: 10
row 1, expr 1: 100
row 1, expr 2: 700

subtest Checks

statement ok
CREATE TABLE checks (
a INT PRIMARY KEY,
b INT NOT NULL,
v INT NOT NULL AS (b % 4) VIRTUAL CHECK (v IN (0,1,2,3)),
INDEX (v, b)
)

# Verify that we use the (v,b) index.
query T
EXPLAIN (VERBOSE) SELECT a FROM checks WHERE b BETWEEN 10 and 15
----
distribution: local
vectorized: true
·
• project
│ columns: (a)
│ estimated row count: 60 (missing stats)
└── • scan
columns: (a, b)
estimated row count: 60 (missing stats)
table: checks@checks_v_b_idx
spans: /0/10-/0/16 /1/10-/1/16 /2/10-/2/16 /3/10-/3/16
98 changes: 98 additions & 0 deletions pkg/sql/opt/optbuilder/testdata/virtual-columns
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,16 @@ CREATE TABLE t_idx2 (
)
----

exec-ddl
CREATE TABLE t_check (
a INT PRIMARY KEY,
b INT,
v INT AS (a+b) VIRTUAL CHECK (v >= 10),
w INT AS (a*b) VIRTUAL,
CHECK (v < w)
)
----

# -- SELECT tests --

# Column v should be produced.
Expand Down Expand Up @@ -158,6 +168,31 @@ insert t_idx
└── projections
└── column1:5 + column2:6 [as=column7:7]

build
INSERT INTO t_check VALUES (1, 1)
----
insert t_check
├── columns: <none>
├── insert-mapping:
│ ├── column1:6 => a:1
│ ├── column2:7 => b:2
│ ├── column8:8 => v:3
│ └── column9:9 => w:4
├── check columns: check1:10 check2:11
└── project
├── columns: check1:10!null check2:11!null column1:6!null column2:7!null column8:8!null column9:9!null
├── project
│ ├── columns: column8:8!null column9:9!null column1:6!null column2:7!null
│ ├── values
│ │ ├── columns: column1:6!null column2:7!null
│ │ └── (1, 1)
│ └── projections
│ ├── column1:6 + column2:7 [as=column8:8]
│ └── column1:6 * column2:7 [as=column9:9]
└── projections
├── column8:8 < column9:9 [as=check1:10]
└── column8:8 >= 10 [as=check2:11]

# -- DELETE tests --

build
Expand Down Expand Up @@ -617,6 +652,44 @@ project
├── a:7 + b_new:13 [as=column14:14]
└── c:9 + 1 [as=column15:15]

build
UPDATE t_check SET b=b+1
----
update t_check
├── columns: <none>
├── fetch columns: a:6 b:7 v:8 w:9
├── update-mapping:
│ ├── b_new:11 => b:2
│ ├── column12:12 => v:3
│ └── column13:13 => w:4
├── check columns: check1:14 check2:15
└── project
├── columns: check1:14 check2:15 a:6!null b:7 v:8 w:9 crdb_internal_mvcc_timestamp:10 b_new:11 column12:12 column13:13
├── project
│ ├── columns: column12:12 column13:13 a:6!null b:7 v:8 w:9 crdb_internal_mvcc_timestamp:10 b_new:11
│ ├── project
│ │ ├── columns: b_new:11 a:6!null b:7 v:8 w:9 crdb_internal_mvcc_timestamp:10
│ │ ├── project
│ │ │ ├── columns: v:8 w:9 a:6!null b:7 crdb_internal_mvcc_timestamp:10
│ │ │ ├── scan t_check
│ │ │ │ ├── columns: a:6!null b:7 crdb_internal_mvcc_timestamp:10
│ │ │ │ └── computed column expressions
│ │ │ │ ├── v:8
│ │ │ │ │ └── a:6 + b:7
│ │ │ │ └── w:9
│ │ │ │ └── a:6 * b:7
│ │ │ └── projections
│ │ │ ├── a:6 + b:7 [as=v:8]
│ │ │ └── a:6 * b:7 [as=w:9]
│ │ └── projections
│ │ └── b:7 + 1 [as=b_new:11]
│ └── projections
│ ├── a:6 + b_new:11 [as=column12:12]
│ └── a:6 * b_new:11 [as=column13:13]
└── projections
├── column12:12 < column13:13 [as=check1:14]
└── column12:12 >= 10 [as=check2:15]

# -- UPSERT / INSERT ON CONFLICT tests --

build
Expand Down Expand Up @@ -715,6 +788,31 @@ project
└── projections
└── column1:5 + column2:6 [as=column7:7]

build
UPSERT INTO t_check VALUES (1, 1)
----
upsert t_check
├── columns: <none>
├── upsert-mapping:
│ ├── column1:6 => a:1
│ ├── column2:7 => b:2
│ ├── column8:8 => v:3
│ └── column9:9 => w:4
├── check columns: check1:10 check2:11
└── project
├── columns: check1:10!null check2:11!null column1:6!null column2:7!null column8:8!null column9:9!null
├── project
│ ├── columns: column8:8!null column9:9!null column1:6!null column2:7!null
│ ├── values
│ │ ├── columns: column1:6!null column2:7!null
│ │ └── (1, 1)
│ └── projections
│ ├── column1:6 + column2:7 [as=column8:8]
│ └── column1:6 * column2:7 [as=column9:9]
└── projections
├── column8:8 < column9:9 [as=check1:10]
└── column8:8 >= 10 [as=check2:11]

build
INSERT INTO t VALUES (1, 1) ON CONFLICT DO NOTHING RETURNING v
----
Expand Down

0 comments on commit 988e457

Please sign in to comment.