Skip to content

Commit

Permalink
WL#929 - CHECK CONSTRAINTS
Browse files Browse the repository at this point in the history
The aim of this WL is to implement CHECK constraints feature.
The feature is supported for all the storage engines.

The WL provides following functionality:

  a) Create check constraints on a table:

      WL implements following syntax to add check constraint in
      CREATE TABLE and ALTER TABLE,

        check_constraint_definition:
          [CONSTRAINT [symbol]] CHECK(expr) [[NOT] ENFORCED]

        Example:
          CREATE TABLE t1 (f1 INT CHECK (f1 < 929), f2 INT,
                           CHECK (f2 < 929));

          ALTER TABLE t1 ADD COLUMN f3 INT CHECK (f3 < 929),
                         ADD CONSTRAINT ck CHECK (f2 > 1);

      If enforcement is not specified then check constraint is
      created in the ENFORCED state.

   b) Check constraints validation:

       For DML operations INSERT, UPDATE, REPLACE, LOAD DATA,
       LOAD XML, check constraints in ENFORCED states are
       validated on each row. The check constraint is satisfied
       if and only if expression is evaluated to TRUE or
       UNKNOWN(for NULL column value). Constraint violation
       error is reported otherwise.

       Example:
        CREATE TABLE t (s1 INT, CHECK (s1 > 0))

	INSERT INTO t VALUES (-1)
	/* this should fail, the condition is FALSE */

	INSERT INTO t VALUES (NULL)
	/* this should succeed, the condition is UNKNOWN */

	INSERT INTO t VALUES (1)
	/* this should succeed, the condition is TRUE */

   c) Alter check constraint's state:

       WL implements following syntax in ALTER TABLE statement
       to alter constraint's state.

         ALTER TABLE ... ALTER CHECK symbol [[NOT] ENFORCED]

         Example:
           ALTER TABLE t1 ALTER CHECK ck NOT ENFORCED;

           ALTER TABLE t1 ALTER CHECK ck ENFORCED;

   d) Drop check constraint:

       WL implements following syntax in ALTER TABLE statement
       to DROP check constraint.

         ALTER TABLE ... DROP CHECK symbol;

         Example:
	   ALTER TABLE t1 DROP CHECK ck;

    e) SHOW CREATE TABLE lists check constraints defined on the
       table.

         Example:
          CREATE TABLE t1(
            f1 INT CHECK (f1 < 10),
            f2 INT CHECK (f2 < 10) NOT ENFORCED);

          SHOW CREATE TABLE t1;
            Table   Create Table
            t1      CREATE TABLE `t1` (
              `f1` int(11) DEFAULT NULL,
              `f2` int(11) DEFAULT NULL,
              CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10)),
              CONSTRAINT `t1_chk_2` CHECK ((`f2` < 10)) /*!80015 NOT ENFORCED */,
            );

        All check constraints are listed in the table check constraint
        form.

        Check constraint in not enforced state are listed with the
        conditional comment "NOT ENFORCED".

    f) INFORMATION_SCHEMA.CHECK_CONSTRAINTS is introduced to list
       check constraints.

    g) INFORMATION_SCHEMA.TABLE_CONSTRAINTS now lists even check
       constraints defined on the table.

       Column "ENFORCED" is introduced to TABLE_CONSTRAINTS table
       to list enforcement state [YES/NO] for constraints.

    h) WL implements core features defined in the ANSI/ISO SQL
       standard E141-06 "CHECK CONSTRAINTS".

       Please refer WL's HLS section R for the common restrictions
       on the check constraints.

Change-Id: I9de7158200e829e05df322f8ffe7e782aa9b7ab1
  • Loading branch information
phulakun committed Jan 4, 2019
1 parent e958e0b commit 4d7d516
Show file tree
Hide file tree
Showing 177 changed files with 10,363 additions and 780 deletions.
7 changes: 4 additions & 3 deletions mysql-test/include/dd_schema_assert_and_fill_table_names.inc
Original file line number Diff line number Diff line change
Expand Up @@ -9,11 +9,11 @@ SET debug = '+d,skip_dd_table_access_check';
--echo ########################################################################
--echo # The number of hidden DD/DDSE tables must be as expected.
--echo ########################################################################
let $number_of_hidden_dd_tables = 31;
let $number_of_hidden_dd_tables = 32;
let $assert_cond = "[SELECT COUNT(*) from mysql.tables
WHERE schema_id = 1 AND hidden = \'System\']"
= $number_of_hidden_dd_tables;
--let $assert_text = There are 31 hidden DD/DDSE tables.
--let $assert_text = There are 32 hidden DD/DDSE tables.
--source include/assert.inc

# Fill two help tables with the names of the DDSE and DD tables.
Expand Down Expand Up @@ -46,6 +46,7 @@ eval INSERT INTO $dd_table_names (name) VALUES
('catalogs'),
('character_sets'),
('collations'),
('check_constraints'),
('column_statistics'),
('column_type_elements'),
('columns'),
Expand Down Expand Up @@ -78,7 +79,7 @@ eval INSERT INTO $dd_table_names (name) VALUES
let $assert_cond = "[SELECT (SELECT COUNT(*) FROM $dd_table_names) +
(SELECT COUNT(*) FROM $ddse_table_names)]"
= $number_of_hidden_dd_tables + 2;
--let $assert_text = There are 33 DD/DDSE tables in total.
--let $assert_text = There are 34 DD/DDSE tables in total.
--source include/assert.inc

--echo ########################################################################
Expand Down
2,613 changes: 2,613 additions & 0 deletions mysql-test/r/check_constraints.result

Large diffs are not rendered by default.

135 changes: 135 additions & 0 deletions mysql-test/r/check_constraints_debug.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,135 @@
#------------------------------------------------------------------------
# Test case to verify MDL locking on check constraints with same names
# in the concurrent CREATE TABLE statements.
#------------------------------------------------------------------------
SET DEBUG_SYNC="after_acquiring_lock_on_check_constraints SIGNAL cc_locked WAIT_FOR continue";
CREATE TABLE t1 (f1 INT CHECK (f1 < 10), f2 INT, CONSTRAINT t1_ck CHECK(f2 < 10));;
CONNECT con1, localhost, root;
SET DEBUG_SYNC="now WAIT_FOR cc_locked";
CREATE TABLE t2 (f1 INT, f2 INT, CONSTRAINT t1_ck CHECK(f2 < 10));;
CONNECT con2, localhost, root;
# default connection acquires MDL lock on the check constraint name 'test.t1_ck'.
# con1 waits for the MDL lock on 'test.t1_ck' at this point.
SET DEBUG_SYNC="now SIGNAL continue";
connection con1;
ERROR HY000: Duplicate check constraint name 't1_ck'.
connection default;
#------------------------------------------------------------------------
# Test case to verify MDL locking on check constraints names in the
# RENAME TABLE and CREATE TABLE statements.
#------------------------------------------------------------------------
SET DEBUG_SYNC="after_acquiring_lock_on_check_constraints_for_rename SIGNAL cc_locked WAIT_FOR continue";
RENAME TABLE t1 to t2;;
connection con1;
SET DEBUG_SYNC="now WAIT_FOR cc_locked";
CREATE TABLE t3 (f1 INT, CONSTRAINT t1_chk_1 CHECK (f1 < 10));;
connection con2;
# default connection acquires lock on check constraint 'test.t1_chk_1'.
# Concurrent create operation with same name for check constraint in con1
# waits for the lock.
SET DEBUG_SYNC="now SIGNAL continue";
connection con1;
connection default;
SHOW CREATE TABLE t2;
Table Create Table
t2 CREATE TABLE `t2` (
`f1` int(11) DEFAULT NULL,
`f2` int(11) DEFAULT NULL,
CONSTRAINT `t1_ck` CHECK ((`f2` < 10)),
CONSTRAINT `t2_chk_1` CHECK ((`f1` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
SHOW CREATE TABLE t3;
Table Create Table
t3 CREATE TABLE `t3` (
`f1` int(11) DEFAULT NULL,
CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
DROP TABLE t3;
#------------------------------------------------------------------------
# Test case to verify MDL locking on generated check constraints names
# in the RENAME TABLE using the target table name and CREATE TABLE
# statements.
#------------------------------------------------------------------------
SET DEBUG_SYNC="after_acquiring_lock_on_check_constraints_for_rename SIGNAL cc_locked WAIT_FOR continue";
RENAME TABLE t2 to t1;;
connection con1;
SET DEBUG_SYNC="now WAIT_FOR cc_locked";
CREATE TABLE t3 (f1 INT, CONSTRAINT t1_chk_1 CHECK (f1 < 10));;
connection con2;
# default connection acquires lock on check constraint name('test.t1_chk_1')
# generated using target table t1.
# concurrent con1 waits for the MDL on test.t1_chk_1 in CREATE TABLE
# statement.
SET DEBUG_SYNC="now SIGNAL continue";
connection con1;
ERROR HY000: Duplicate check constraint name 't1_chk_1'.
SHOW CREATE TABLE t1;
Table Create Table
t1 CREATE TABLE `t1` (
`f1` int(11) DEFAULT NULL,
`f2` int(11) DEFAULT NULL,
CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10)),
CONSTRAINT `t1_ck` CHECK ((`f2` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
connection default;
#------------------------------------------------------------------------
# Test case to verify MDL locking on check constraint name in ALTER
# TABLE statement to RENAME table and CREATE TABLE statements.
#------------------------------------------------------------------------
SET DEBUG_SYNC="after_acquiring_lock_on_check_constraints_for_rename SIGNAL cc_locked WAIT_FOR continue";
ALTER TABLE t1 RENAME TO t3;;
connection con1;
SET DEBUG_SYNC="now WAIT_FOR cc_locked";
CREATE TABLE t2 (f1 INT, CONSTRAINT t1_chk_1 CHECK (f1 < 10));;
connection con2;
# default connection acquires lock on check constraint 'test.t1_chk_1'.
# Concurrent con1 waits for lock on test.t1_chk_1.
SET DEBUG_SYNC="now SIGNAL continue";
connection con1;
connection default;
SHOW CREATE TABLE t2;
Table Create Table
t2 CREATE TABLE `t2` (
`f1` int(11) DEFAULT NULL,
CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
SHOW CREATE TABLE t3;
Table Create Table
t3 CREATE TABLE `t3` (
`f1` int(11) DEFAULT NULL,
`f2` int(11) DEFAULT NULL,
CONSTRAINT `t1_ck` CHECK ((`f2` < 10)),
CONSTRAINT `t3_chk_1` CHECK ((`f1` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
DROP TABLE t2;
#------------------------------------------------------------------------
# Test case to verify MDL locking on generated check constraint name
# using target table name in ALTER TABLE statement to RENAME table and
# CREATE TABLE statements.
#------------------------------------------------------------------------
SET DEBUG_SYNC="after_acquiring_lock_on_check_constraints_for_rename SIGNAL cc_locked WAIT_FOR continue";
ALTER TABLE t3 RENAME TO t1;;
connection con1;
SET DEBUG_SYNC="now WAIT_FOR cc_locked";
CREATE TABLE t2 (f1 INT, CONSTRAINT t1_chk_1 CHECK (f1 < 10));;
connection con2;
# default connection acquires lock on the generated check constraint
# name('test.t1_chk_1') using target table name t1. con1 waits for
# the lock on same name for check constraint.
SET DEBUG_SYNC="now SIGNAL continue";
connection con1;
ERROR HY000: Duplicate check constraint name 't1_chk_1'.
connection default;
SHOW CREATE TABLE t1;
Table Create Table
t1 CREATE TABLE `t1` (
`f1` int(11) DEFAULT NULL,
`f2` int(11) DEFAULT NULL,
CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10)),
CONSTRAINT `t1_ck` CHECK ((`f2` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
connection default;
disconnect con1;
disconnect con2;
DROP TABLE t1;
SET DEBUG_SYNC='RESET';
3 changes: 3 additions & 0 deletions mysql-test/r/constraints.result
Original file line number Diff line number Diff line change
Expand Up @@ -2,14 +2,17 @@ drop table if exists t1;
create table t1 (a int check (a>0));
insert into t1 values (1);
insert into t1 values (0);
ERROR HY000: Check constraint 't1_chk_1' is violated.
drop table t1;
create table t1 (a int, b int, check (a>b));
insert into t1 values (1,0);
insert into t1 values (0,1);
ERROR HY000: Check constraint 't1_chk_1' is violated.
drop table t1;
create table t1 (a int ,b int, constraint abc check (a>b));
insert into t1 values (1,0);
insert into t1 values (0,1);
ERROR HY000: Check constraint 'abc' is violated.
drop table t1;
create table t1 (a int null);
insert into t1 values (1),(NULL);
Expand Down
1 change: 1 addition & 0 deletions mysql-test/r/dd_is_compatibility_ci.result
Original file line number Diff line number Diff line change
Expand Up @@ -154,6 +154,7 @@ WHERE table_schema LIKE 'information_schema'
SELECT * FROM v1;
table_name
CHARACTER_SETS
CHECK_CONSTRAINTS
COLLATIONS
COLLATION_CHARACTER_SET_APPLICABILITY
COLUMNS
Expand Down
1 change: 1 addition & 0 deletions mysql-test/r/dd_is_compatibility_cs.result
Original file line number Diff line number Diff line change
Expand Up @@ -154,6 +154,7 @@ WHERE table_schema LIKE 'information_schema'
SELECT * FROM v1;
table_name
CHARACTER_SETS
CHECK_CONSTRAINTS
COLLATIONS
COLLATION_CHARACTER_SET_APPLICABILITY
COLUMNS
Expand Down
16 changes: 8 additions & 8 deletions mysql-test/r/dd_schema_definition_after_upgrade_debug.result
Original file line number Diff line number Diff line change
Expand Up @@ -50,8 +50,8 @@ SET debug = '+d,skip_dd_table_access_check';
########################################################################
# The number of hidden DD/DDSE tables must be as expected.
########################################################################
include/assert.inc [There are 31 hidden DD/DDSE tables.]
include/assert.inc [There are 33 DD/DDSE tables in total.]
include/assert.inc [There are 32 hidden DD/DDSE tables.]
include/assert.inc [There are 34 DD/DDSE tables in total.]
########################################################################
# No unexpected DD tables must be present.
########################################################################
Expand Down Expand Up @@ -190,8 +190,8 @@ SET debug = '+d,skip_dd_table_access_check';
########################################################################
# The number of hidden DD/DDSE tables must be as expected.
########################################################################
include/assert.inc [There are 31 hidden DD/DDSE tables.]
include/assert.inc [There are 33 DD/DDSE tables in total.]
include/assert.inc [There are 32 hidden DD/DDSE tables.]
include/assert.inc [There are 34 DD/DDSE tables in total.]
########################################################################
# No unexpected DD tables must be present.
########################################################################
Expand Down Expand Up @@ -332,8 +332,8 @@ SET debug = '+d,skip_dd_table_access_check';
########################################################################
# The number of hidden DD/DDSE tables must be as expected.
########################################################################
include/assert.inc [There are 31 hidden DD/DDSE tables.]
include/assert.inc [There are 33 DD/DDSE tables in total.]
include/assert.inc [There are 32 hidden DD/DDSE tables.]
include/assert.inc [There are 34 DD/DDSE tables in total.]
########################################################################
# No unexpected DD tables must be present.
########################################################################
Expand Down Expand Up @@ -474,8 +474,8 @@ SET debug = '+d,skip_dd_table_access_check';
########################################################################
# The number of hidden DD/DDSE tables must be as expected.
########################################################################
include/assert.inc [There are 31 hidden DD/DDSE tables.]
include/assert.inc [There are 33 DD/DDSE tables in total.]
include/assert.inc [There are 32 hidden DD/DDSE tables.]
include/assert.inc [There are 34 DD/DDSE tables in total.]
########################################################################
# No unexpected DD tables must be present.
########################################################################
Expand Down
8 changes: 4 additions & 4 deletions mysql-test/r/dd_schema_definition_debug.result
Original file line number Diff line number Diff line change
Expand Up @@ -141,8 +141,8 @@ SET debug = '+d,skip_dd_table_access_check';
########################################################################
# The number of hidden DD/DDSE tables must be as expected.
########################################################################
include/assert.inc [There are 31 hidden DD/DDSE tables.]
include/assert.inc [There are 33 DD/DDSE tables in total.]
include/assert.inc [There are 32 hidden DD/DDSE tables.]
include/assert.inc [There are 34 DD/DDSE tables in total.]
########################################################################
# No unexpected DD tables must be present.
########################################################################
Expand All @@ -165,7 +165,7 @@ SET debug = '+d,skip_dd_table_access_check';
########################################################################
# The actual DD version stored on disk.
########################################################################
DD_VERSION=80014
DD_VERSION=80015
########################################################################
# List the CREATE TABLE statements for the DD tables.
# Mask the AUTO INCREMENT counter, which is not
Expand Down Expand Up @@ -719,5 +719,5 @@ SET debug = '-d,skip_dd_table_access_check';
SET debug = '+d,skip_dd_table_access_check';
include/assert.inc [The group concat max length is sufficient.]
CHECK_STATUS
The schema checksum corresponds to DD version 80014.
The schema checksum corresponds to DD version 80015.
include/assert.inc [The schema checksum corresponds to a known DD version.]
31 changes: 31 additions & 0 deletions mysql-test/r/dd_upgrade_test.result
Original file line number Diff line number Diff line change
Expand Up @@ -864,4 +864,35 @@ t_set CREATE TABLE `t_set` (
# Remove copied files
# Restart the server with default options.
# restart
#-----------------------------------------------------------------------
# WL#929: CHECK Constraint
# Test case to verify upgrade from version before check
# constraint suppport.
#-----------------------------------------------------------------------
# Copy the remote tablespace & DB zip files from suite location to working location.
# Check that the file exists in the working folder.
# Set different paths for --datadir
CREATE TABLE t1 (f1 INT CHECK (f1 < 10));
# After upgrade CHECK_CONSTRAINTS table should be present and should list
# check constraints.
SELECT * FROM INFORMATION_SCHEMA.CHECK_CONSTRAINTS;
CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME CHECK_CLAUSE
def test t1_chk_1 (`f1` < 10)
# After upgrade TABLE_CONSTRAINTS should list check constraints.
SELECT * FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS WHERE TABLE_NAME='t1';
CONSTRAINT_CATALOG CONSTRAINT_SCHEMA CONSTRAINT_NAME TABLE_SCHEMA TABLE_NAME CONSTRAINT_TYPE ENFORCED
def test t1_chk_1 test t1 CHECK YES
SHOW CREATE TABLE t1;
Table Create Table
t1 CREATE TABLE `t1` (
`f1` int(11) DEFAULT NULL,
CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10))
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
INSERT INTO t1 VALUES (100);
ERROR HY000: Check constraint 't1_chk_1' is violated.
DROP TABLE t1;
# Stop the server
# Remove copied files
# Restart the server with default options.
# restart
# end of test
2 changes: 2 additions & 0 deletions mysql-test/r/dictionary_tablespace.result
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,7 @@ mysql.tablespaces ON tables1.tablespace_id = tablespaces.id
WHERE tables1.name NOT IN ('ndb_binlog_index') ORDER BY tables1.name;
catalogs mysql
character_sets mysql
check_constraints mysql
collations mysql
column_statistics mysql
column_type_elements mysql
Expand Down Expand Up @@ -82,6 +83,7 @@ name NOT IN ('ndb_binlog_index')
ORDER BY name ASC;
catalogs
character_sets
check_constraints
collations
column_statistics
column_type_elements
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/r/group_min_max.result
Original file line number Diff line number Diff line change
Expand Up @@ -2527,7 +2527,7 @@ FLUSH STATUS;
CREATE TABLE t2 SELECT max(b), a FROM t1 GROUP BY a;
SHOW STATUS LIKE 'handler_read__e%';
Variable_name Value
Handler_read_key 23
Handler_read_key 24
Handler_read_next 2
FLUSH STATUS;
SELECT * FROM (SELECT max(b), a FROM t1 GROUP BY a) b;
Expand Down
14 changes: 14 additions & 0 deletions mysql-test/r/import.result
Original file line number Diff line number Diff line change
Expand Up @@ -499,4 +499,18 @@ IMPORT TABLE FROM 't1_*.sdi';
ERROR HY000: Unable to create or change a table without a primary key, when the system variable 'sql_require_primary_key' is set. Add a primary key to the table or unset this variable to avoid this message. Note that tables without a primary key can cause performance problems in row-based replication, so please consult your DBA before changing this setting.
SET SESSION sql_require_primary_key= OFF;
# Clean SDI files in $EXPORT_DIR
#-----------------------------------------------------------------------
# WL#929 - Check constraint.
# Test case to verify check constraint import from SDI.
#-----------------------------------------------------------------------
CREATE TABLE t1 (f1 INT CHECK (f1 < 10)) ENGINE=MyISAM;
DROP TABLE t1;
IMPORT TABLE FROM 'test/t1*.sdi';
SHOW CREATE TABLE t1;
Table Create Table
t1 CREATE TABLE `t1` (
`f1` int(11) DEFAULT NULL,
CONSTRAINT `t1_chk_1` CHECK ((`f1` < 10))
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
DROP TABLE t1;
# Remove 'export' folder created at the beginning of test file.
Loading

0 comments on commit 4d7d516

Please sign in to comment.