How can I break referential integrity briefly, within a transaction, without disabling the foreign key constraint?
What you want is a 'deferred constraint'.
You can pick between the two types of deferrable constraints, 'INITIALLY IMMEDIATE' and 'INITIALLY DEFERRED' to drive default behavior - whether the database should default to check the constraint after every statement, or if it should default to only checking constraints at the end of the transaction.
Answered slower than Chi, but felt it would be nice to include code sample, so that the answer could be found on SO.
As Chi answered, deferrable constraints make this possible.
SQL> drop table t;
Table dropped.
SQL> create table T (ID number
2 , parent_ID number null
3 , name varchar2(40) not null
4 , constraint T_PK primary key (ID)
5 , constraint T_HIREARCHY_FK foreign key (parent_ID)
6 references T(ID) deferrable initially immediate);
Table created.
SQL> insert into T values (1, null, 'Big Boss');
1 row created.
SQL> insert into T values (2, 1, 'Worker Bee');
1 row created.
SQL> commit;
Commit complete.
SQL> -- Since initially immediate, the following statement will fail:
SQL> update T
2 set ID = 1000
3 where ID = 1;
update T
*
ERROR at line 1:
ORA-02292: integrity constraint (S.T_HIREARCHY_FK) violated - child record found
SQL> set constraints all deferred;
Constraint set.
SQL> update T
2 set ID = 1000
3 where ID = 1;
1 row updated.
SQL> update T
2 set parent_ID = 1000
3 where parent_ID = 1;
1 row updated.
SQL> commit;
Commit complete.
SQL> select * from T;
ID PARENT_ID NAME
---------- ---------- ----------------------------------------
1000 Big Boss
2 1000 Worker Bee
SQL> -- set constraints all deferred during that transaction
SQL> -- and the transaction has commited, the next
SQL> -- statement will fail
SQL> update T
2 set ID = 1
3 where ID = 1000;
update T
*
ERROR at line 1:
ORA-02292: integrity constraint S.T_HIREARCHY_FK) violated - child record found
I believe, but could not find the reference, that deferrability is defined at constraint creation time and can not be modified later. The default is non-deferrable. To change to deferrable constraints you'll need to do a one time drop and add constraint. (Properly scheduled, controlled, etc.)
SQL> drop table t;
Table dropped.
SQL> create table T (ID number
2 , parent_ID number null
3 , name varchar2(40) not null
4 , constraint T_PK primary key (ID)
5 , constraint T_HIREARCHY_FK foreign key (parent_ID)
6 references T(ID));
Table created.
SQL> alter table T drop constraint T_HIREARCHY_FK;
Table altered.
SQL> alter table T add constraint T_HIREARCHY_FK foreign key (parent_ID)
2 references T(ID) deferrable initially deferred;
Table altered.
The common advice with scenarios like this is to employ deferrable constraints. However, I think these situations are almost always a failure of application logic or data model. For instance, inserting a child record and a parent record in the same transaction can be a problem if we execute it as two statements:
My test data:
SQL> select * from t23 order by id, parent_id
2 /
ID PARENT_ID NAME
---------- ---------- ------------------------------
110 parent 1
111 parent 2
210 110 child 0
220 111 child 1
221 111 child 2
222 111 child 3
6 rows selected.
SQL>
The wrong way to do things:
SQL> insert into t23 (id, parent_id, name) values (444, 333, 'new child')
2 /
insert into t23 (id, parent_id, name) values (444, 333, 'new child')
*
ERROR at line 1:
ORA-02291: integrity constraint (APC.T23_T23_FK) violated - parent key not
found
SQL> insert into t23 (id, parent_id, name) values (333, null, 'new parent')
2 /
1 row created.
SQL>
However, Oracle supports a multi-table INSERT synatx which allows us to insert the parent and child records in the same statement, thus obviating the need for deferrable constraints:
SQL> rollback
2 /
Rollback complete.
SQL> insert all
2 into t23 (id, parent_id, name)
3 values (child_id, parent_id, child_name)
4 into t23 (id, name)
5 values (parent_id, parent_name)
6 select 333 as parent_id
7 , 'new parent' as parent_name
8 , 444 as child_id
9 , 'new child' as child_name
10 from dual
11 /
2 rows created.
SQL>
The situation you are in is similar: you want to update the primary key of the parent record but can't because of the existence of the child records: And you can't update the child records because there is no parent key. Catch-22:
SQL> update t23
2 set id = 555
3 where id = 111
4 /
update t23
*
ERROR at line 1:
ORA-02292: integrity constraint (APC.T23_T23_FK) violated - child record found
SQL> update t23
2 set parent_id = 555
3 where parent_id = 111
4 /
update t23
*
ERROR at line 1:
ORA-02291: integrity constraint (APC.T23_T23_FK) violated - parent key not
found
SQL>
Once again the solution is to do it in a single statement:
SQL> update t23
2 set id = decode(id, 111, 555, id)
3 , parent_id = decode(parent_id, 111, 555, parent_id)
4 where id = 111
5 or parent_id = 111
6 /
4 rows updated.
SQL> select * from t23 order by id, parent_id
2 /
ID PARENT_ID NAME
---------- ---------- ------------------------------
110 parent 1
210 110 child 0
220 555 child 1
221 555 child 2
222 555 child 3
333 new parent
444 333 new child
555 parent 2
8 rows selected.
SQL>
The syntax in the UPDATE statement is a bit clunky but kludges usually are. The point being that we should not have to update primary key columns very often. Indeed, as immutability is one of the characteristics of "primary key-ness" we shouldn't really have to update them at all. Needing to do so is a failure of the data model. One way of avoiding such failures is to use a synthetic (surrogate) primary key, and simply enforce the uniqueness of the natural (aka business) key with a unique constraint.
So why does Oracle offer deferrable constraints? They are useful when we undertake data migrations or bulk data uploads. They permit us to cleanse data in the database without staging tables. We really shouldn't need them for regular application tasks.