Oracle约束的关键字Enable/Disable/Validate/Novalidate


1 组合特性说明

 

Validate

Novalidate

已有记录

新增/删除记录

已有记录

新增/删除记录

Enable

Yes

Yes

No

Yes

Disable

Yes

No

No

No

Validate确保已有数据符合约束;

Novalidate不必考虑已有数据是否符合约束。

 

除非Novalidate被指定,Enable默认Validate

除非Validate被指定,Disable默认Novalidate

 

Enable ValidateEnable相同,检查已有记录和新增记录,确保都符合约束;

Enable Novalidate 允许已有记录不必满足约束条件,但新增/修改的记录必须满足;

Disable Validate禁用约束,删除约束上的索引,不允许修改任何被约束的记录;

Disable NovalidateDisable相同,禁用约束,删除约束上的索引,且允许修改被约束的记录。

2 建表

SQL> create table test(id int, name varchar2(10));

Table created

SQL> alter table test add constraint ck_id check(id > 10);

Table altered

3 测试1: Enable Validate

SQL> alter table test Enable validate constraint ck_id;

Table altered

SQL> insert into test values(5, 'Oracle');

insert into test values(5, 'Oracle')

ORA-02290: 违反检查约束条件 (MYHR.CK_ID)

SQL> insert into test values(17,'ERP');

1 row inserted

SQL> commit;

Commit complete

4 测试2: Enable Novalidate

SQL> alter table test disable constraint ck_id;

Table altered

SQL> insert into test values(5, 'Oracle');

1 row inserted

SQL> commit;

Commit complete

SQL> select * from test;

           ID NAME

----------- ----------

          17 ERP

            5 Oracle

 

SQL> alter table test enable novalidate constraint ck_id;

Table altered

SQL> insert into test values(32, 'SAP');

1 row inserted

SQL> insert into test values(3, 'Linux');

insert into test values(3, 'Linux')

ORA-02290: 违反检查约束条件 (MYHR.CK_ID)

SQL> commit;

Commit complete

5 测试3: Disable Validate

SQL> delete from test where id < 10;

1 row deleted

SQL> commit;

Commit complete

SQL> alter table test disable validate constraint ck_id;

Table altered

SQL> select * from test;

             ID NAME

------------- ----------

             17 ERP

             32 SAP

SQL> update test set name = 'Change' where id = 17;

update test set name = 'Change' where id = 17

ORA-25128: 不能对带有禁用和验证约束条件 (MYHR.CK_ID) 的表进行插入/更新/删除

6 测试4: Disable Novalidate

SQL> alter table test disable novalidate constraint ck_id;

Table altered

SQL> insert into test values(2, 'Linux');

1 row inserted

SQL> insert into test values(13, 'Windows');

1 row inserted

SQL> update test set name = 'Change' where id = 17;

1 row updated

SQL> commit;

Commit complete

SQL> select * from test;

          ID NAME

---------- ----------

          17 Change

          13 Windows

          32 SAP

           2 Linux

相关内容