I am writing this blog to provide a simple way to resolve ORA-14128. I did not find any reasonable documented solution to fix this issue w/o disabling the constraints.
Here goes my story. Upgrading from Oracle 10.2.0.3 to 11.2.0.2 introduced few problems mainly due to our high concurrency and high availability OLTP system. In 10.2.0.3 , our partition maintenance was done online w/o disabling constraints using the approach described below with an example..
Lets assume tables transaction and sales with following attributes:
— Transaction (Parent/Child) table with transid as primary key and index on salesid
.
— Sales (Parent) table with salesid as primary key
.
— Foreign Key Definition: transaction.salesid references sales.salesid. Also lot of other tables references transid.transaction. Therefore transaction table is both parent and child.
.
Partition Maintenance Approach: Our ultimate goal for partition maintenance is to drop old partitions. So all I have do to issue “alter table transaction drop partition transaction_part_2011”. This command will only succeed if there are no foreign key constraints referencing this parent table. Otherwise it will result in “ORA-02266: unique/primary keys in table referenced by enabled foreign keys”. Since partition maintenance is done online, we don’t have the luxury to disable constraints.
Therefore we had to do all the additional steps involved with partition exchange to accommodate online partition maintenance. And one of the key requirements of partition exchange is that the tables being exchanged must be identical with respect to structure like same indexes , constraints etc. You also have the option of disabling constraints to get to this goal.
Note: With steps 1-4 we are trying to make transaction_duplicate table identical to transaction
.
- create table transaction_Duplicate as select * from Transaction where 1 = 0;
- alter table transaction_Duplicate add constraint Transaction_dup_pk primary key(transid);
- create index salesid_idx on Transaction_Duplicate(salesid) ;
- alter table transaction_Duplicate add constraint fk_salesid foreign key (salesid) references sales(salesid);
- alter table transaction exchange partition Transaction_part_2011 with table Transaction_Duplicate including indexes without validation;
- alter table transaction drop partition transaction_part_2011;
VERY IMPORTANT: Step-4 is optional if the one of the tables used in exchange is empty which is true in our case as we are creating a dummy duplicate table.
Our problems started with Step-4 after upgrading to 11.2.0.2. We started getting “ORA-00054:resource busy and acquire with NOWAIT specified” because Oracle changed the locking behavior in 11g.
We opened SR with Oracle and as per Oracle, the code fix for bug 5909305 introduces an intentional change in locking behavior and that change is effective from 11.1.0.6 onwards. ie: From 11g onwards it is correct and expected that DML on the child table will take an SX lock on the parent.
For customers that cannot live with the changed behavior the fix in bug 6117274 allows the change in locking to be reverted to pre-11g behavior by setting “_fix_control” to ‘5909305:OFF’.
.
In our case since Step-4 was optional , we removed step-4 but our problems did not stop there. Due to nature of our business , every change that goes into the database requires a rollback just in case its required. In other words, we wanted to rollback the partition exchange by performing another exchange. Now Step-4 became a must for rollback as both the tables are not empty after the 1st exchange(One of the partition is empty not the table.).
We were back to square one with small difference. Initially we were trying to fix ORA-00054 and now we are trying to fix ORA-14128. After lot of reading , trials and prototypes, I was able to fix ORA-14128. The solution is very simple. All you had to do was put the referential integrity constraints in “ENABLE NOVALIDATE“. This was OK for our database. So if you can put your constraints in “ENABLE NOVALIDATE” , then you have a simple fix for ORA-14128
Thanks for reading.
Tagged: 5909305:OFF, 6117274, ENABLE NOVALIDATE, ORA-02266, ORA-14128, ORA-14128:FOREIGN KEY constraint mismatch in ALTER TABLE EXCHANGE PARTITION, _FIX_CONTROL
Recent Comments