To ensure that the data in a table conforms to your business requirements, you can define constraints at the column level.
Constraints limit the types of data that can be stored in columns. If you attempt to enter or update a value that does not satisfy the constraint on the corresponding column, an error is returned and the operation is rolled back. Likewise, if you attempt to add a constraint that conflicts with the existing data to a column in an existing table, an error is returned and the operation is rolled back.
Constraint types
OceanBase Database supports the following types of constraints in the Oracle mode of OceanBase Database:
NOT NULLconstraint: requires that the constrained column do not containNULLvalues.For a column with the
NOT NULLconstraint, you must specify the values in theINSERTstatement unless you have defined a default value for the column. Example: Create a table namedtbl1and specify theNOT NULLconstraint for thecol1column.obclient> CREATE TABLE tbl1(col1 INT NOT NULL,col2 INT); Query OK, 0 rows affected obclient> DESC tbl1; +-------+------------+------+-----+---------+-------+ | FIELD | TYPE | NULL | KEY | DEFAULT | EXTRA | +-------+------------+------+-----+---------+-------+ | COL1 | NUMBER(38) | NO | NULL | NULL | NULL | | COL2 | NUMBER(38) | YES | NULL | NULL | NULL | +-------+------------+------+-----+---------+-------+ 2 rows in setUNIQUEconstraint: requires that the constrained column do not contain duplicate values.NULLvalues are not prohibited by this constraint type.Example: Create a table named
tbl2and specify theUNIQUEconstraint for thecol1column.obclient> CREATE TABLE tbl2(col1 INT UNIQUE,col2 INT); Query OK, 0 rows affected obclient> desc tbl2; +-------+------------+------+-----+---------+-------+ | FIELD | TYPE | NULL | KEY | DEFAULT | EXTRA | +-------+------------+------+-----+---------+-------+ | COL1 | NUMBER(38) | YES | UNI | NULL | NULL | | COL2 | NUMBER(38) | YES | NULL | NULL | NULL | +-------+------------+------+-----+---------+-------+ 2 rows in setPRIMARY KEYconstraint: It is the combination of theNOT NULLconstraint and the UNIQUE constraint.Example: Create a table named
tbl3and specify thePRIMARY KEYconstraint for thecol1column.obclient> CREATE TABLE tbl3(col1 INT PRIMARY KEY,col2 INT); Query OK, 0 rows affected obclient> desc tbl3; +-------+------------+------+-----+---------+-------+ | FIELD | TYPE | NULL | KEY | DEFAULT | EXTRA | +-------+------------+------+-----+---------+-------+ | COL1 | NUMBER(38) | NO | PRI | NULL | NULL | | COL2 | NUMBER(38) | YES | NULL | NULL | NULL | +-------+------------+------+-----+---------+-------+ 2 rows in setIn the example, the
col1column must contain unique values and must not containNULLvalues.FOREIGN KEYconstraint: requires that the constrained column contain only values from the primary key column of another table.Example: Create a table named
tbl4and associate thecol2column with the primary key columncol1of thetbl3table.obclient> CREATE TABLE tbl4(col1 INT,col2 INT,FOREIGN KEY(col2) REFERENCES tbl3(col1)); Query OK, 0 rows affectedBy default, OceanBase Database checks foreign keys. To disable or enable foreign key check, modify the
foreign_key_checkstenant variable. For more information about theforeign_key_checksvariable, see foreign_key_checks.CHECKconstraint: enforces that the values of a column in the table must conform to specified conditions.
View constraints
You can check the constraints that you created by querying the ALL_CONS_COLUMNS, DBA_CONS_COLUMNS, and USER_CONS_COLUMNS views.
Here is an example:
obclient> SELECT * FROM USER_CONS_COLUMNS WHERE table_name='TBL3';
+-------+----------------------------+------------+-------------+----------+
| OWNER | CONSTRAINT_NAME | TABLE_NAME | COLUMN_NAME | POSITION |
+-------+----------------------------+------------+-------------+----------+
| SYS | TBL4_OBPK_1649992639477914 | TBL3 | COL1 | 1 |
+-------+----------------------------+------------+-------------+----------+
1 row in set
Manage constraints
Manage PRIMARY KEY constraints
After you create a table, you can add a PRIMARY KEY constraint to the table or modify a PRIMARY KEY constraint for the table.
Add a
PRIMARY KEYconstraint to the table.The syntax is as follows:
obclient> ALTER TABLE table_name ADD PRIMARY KEY(column_name);We recommend that you add a
PRIMARY KEYconstraint to a table when you create the table.Modify a
PRIMARY KEYconstraint for the table.The syntax is as follows:
obclient> ALTER TABLE table_name MODIFY PRIMARY KEY(column_name);Drop a
PRIMARY KEYconstraint from the table.The syntax is as follows:
obclient> ALTER TABLE table_name DROP PRIMARY KEY;
Here is an example:
Create a table named
tbl4.obclient> CREATE TABLE tbl4(col1 INT,col2 INT); Query OK, 0 rows affectedAdd a
PRIMARY KEYconstraint to the table.obclient> ALTER TABLE tbl4 ADD PRIMARY KEY(col1); Query OK, 0 rows affectedChange the column constrained by the
PRIMARY KEYconstraint tocol2for the table.obclient> ALTER TABLE tbl4 MODIFY PRIMARY KEY(col2);Drop a
PRIMARY KEYconstraint from the table.obclient> ALTER TABLE tbl4 DROP PRIMARY KEY; Query OK, 0 rows affected
Manage FOREIGN KEY constraints
After you create a table, you can manage FOREIGN KEY constraints for the table as follows:
Enable or disable a
FOREIGN KEYconstraint.By default, a constraint is enabled after it is created. If you have added a
FOREIGN KEYconstraint to a table when you created the table, you can enable or disable the constraint.The syntax is as follows:
obclient> ALTER TABLE table_name ENABLE | DISABLE CONSTRAINT constraint_name;Add a
FOREIGN KEYconstraint to the table.The syntax is as follows:
obclient> ALTER TABLE table_name1 ADD CONSTRAINT fk_name FOREIGN KEY (column_name1) REFERENCES table_name2(column_name2);The parameters are described as follows:
table_name1: the name of the table to which you want to add the constraint;table_name2: the name of the associated table.fk_name: the name of theFOREIGN KEYconstraint to be added.column_name1: the name of the column to which the constraint applies;column_name2: the name of the primary key column in the associated table.
Drop a
FOREIGN KEYconstraint from the table.The syntax is as follows:
obclient> ALTER TABLE test DROP CONSTRAINT fk_name;
Here is an example:
Create a table named
tbl5and a table namedtbl6.obclient> CREATE TABLE tbl5(col1 INT PRIMARY KEY,col2 INT); Query OK, 0 rows affected obclient> CREATE TABLE tbl6(col3 INT,col4 INT); Query OK, 0 rows affectedAdd a
FOREIGN KEYconstraint to thetbl6table.obclient> ALTER TABLE tbl6 ADD CONSTRAINT fk FOREIGN KEY(col4) REFERENCES tbl5(col1); Query OK, 0 rows affectedDrop the
FOREIGN KEYconstraint from thetbl6table.obclient> ALTER TABLE tbl6 DROP CONSTRAINT fk; Query OK, 0 rows affected
Manage CHECK constraints
After you create a table, you can manage CHECK constraints for the table as follows:
Enable or disable a
CHECKconstraint.If you have added a
CHECKconstraint to a table when you created the table, you can enable or disable the constraint.The syntax is as follows:
obclient> ALTER TABLE table_name ENABLE | DISABLE CONSTRAINT constraint_name;Add a
CHECKconstraint to the table.The syntax is as follows:
ALTER TABLE table_name ADD CONSTRAINT constraint_name CHECK(expression);Here is an example:
obclient> ALTER TABLE ware ADD CONSTRAINT cst CHECK(w_city='hz');
Manage NOT NULL constraints
After you create a table, you can add a NOT NULL constraint to the table or drop a NOT NULL constraint from the table.
Add a
NOT NULLconstraint to the table.The syntax is as follows:
obclient> ALTER TABLE table_name MODIFY c1 NOT NULL;Drop a
NOT NULLconstraint from the table.The syntax is as follows:
obclient> ALTER TABLE table_name DROP CONSTRAINT constraint_name;You can also use the following statement to drop a
NOT NULLconstraint:obclient> ALTER TABLE table_name MODIFY c1 NULL;
For more information about the syntax for managing constraints, see ALTER TABLE.
Default setting for a date or time column
We recommend that you specify a default value for a column with the NOT NULL constraint. For a date or time column, you can set the current date or time of the database as the default value.
Example: Call the current_timestamp function to set the default value for the datetime column of a table.
obclient> CREATE TABLE t1(
id bigint not null primary KEY
, gmt_create datetime not null default current_timestamp
, gmt_modified datetime not null default current_timestamp
);
Query OK, 0 rows affected
obclient> INSERT INTO t1(id) VALUES(1),(2),(3);
Query OK, 3 rows affected
obclient> SELECT * FROM t1;
+----+---------------------+---------------------+
| id | gmt_create | gmt_modified |
+----+---------------------+---------------------+
| 1 | 2020-02-27 17:09:23 | 2020-02-27 17:09:23 |
| 2 | 2020-02-27 17:09:23 | 2020-02-27 17:09:23 |
| 3 | 2020-02-27 17:09:23 | 2020-02-27 17:09:23 |
+----+---------------------+---------------------+
3 rows in set