Tag Archives: ORA-02266

Oracle12c : Truncate Table Cascade

Prior to Oracle 12c truncating tables with dependent children was a  pain. We had to disable the constraint before truncating the parent table followed  by enabling the constraint.  The performance gain achieved using TRUNCATE instead of DELETE  almost disappeared if the constraints were enabled with VALIDATE option.  If enabling the constraint with NOVALIDATE option was not acceptable, then DELETE seemed  to be the only way to go.

Starting with Oracle 12c , Oracle supports truncating tables with CASCADE option similar to other RDBMS like MySQL & PostgreSQL. Well  It took some time for Oracle to introduce this option but glad we finally have this option.

Similar to DELETE , the constraints have to be defined with ON DELETE CASCADE. Otherwise just like  DELETE , TRUNCATE also will fail. Also the cascading effect will impact all children , grand children and so on.

Let us look at an example. See scripts to create the table towards end of this blog.

In t his example we have 3 tables DEPT (PARENT) , EMP(CHILD) & EMPPROJ (GRANDCHILD) . The child/grandchild tables are created without the “ON DELETE CASCADE” , So obviously the TRUNCATE command with CASCADE option will fail. Please do note the difference in the error message for with and without CASCADE option.

SQL> truncate table emp;

truncate table emp
*
ERROR at line 1:
ORA-02266: unique/primary keys in table referenced by enabled foreign keys
SQL> truncate table emp cascade ;
truncate table emp cascade
*
ERROR at line 1:
ORA-14705: unique or primary keys referenced by enabled foreign keys in table
“SHAN”.”EMPPROJ”

 

Now lets go ahead modify the table to add the ON DELETE CASCADE option; To do this, we have to drop existing constraint and add the constraint with ON DELETE CASCADE option.

 

ALTER TABLE EMP DROP CONSTRAINT fk_deptno_dept ;

ALTER TABLE EMPPROJ DROP CONSTRAINT fk_empno_emp ;

ALTER TABLE EMP ADD CONSTRAINT fk_deptno_dept FOREIGN KEY (DEPTNO) REFERENCES dept(deptno) ON DELETE CASCADE;

ALTER TABLE EMPPROJ ADD CONSTRAINT fk_empno_emp foreign key (empno) REFERENCES emp(empno) ON DELETE CASCADE;

Before we truncate the table, lets take the count of emp & empproj table.

SQL>

SQL> select count(*) from emp;

COUNT(*)
———-
5

SQL> select count(*) from empproj;

COUNT(*)
———-
5

 

Now let us truncate the table with and without t he CASACADE option and then take a count of emp and empproj tables. The key thing to remember is that the CASCADE option will truncate all  data from empproj when emp table is truncated because of child & grandchild option.

SQL> truncate table emp;

truncate table emp
*
ERROR at line 1:
ORA-02266: unique/primary keys in table referenced by enabled foreign keys
SQL> truncate table emp cascade;

Table truncated.

SQL> select count(*) from emp;

COUNT(*)
———-
0

SQL> select count(*) from empproj;

COUNT(*)
———-
0

 

x==x==x==x==x==x==x==x==x==x==x=x=x==x==x==x==x==x==x==x==x==x==x==x=x=x==x

 

Scripts to create the tables 
create table dept
(
deptno number(4) constraint pk_dept primary key,
dname varchar2(20) not null,
loc varchar2(30)
);

 

create table emp
(
empno number(4) constraint pk_emp primary key,
ename varchar2(20) not null,
salary number(10,2) ,
deptno number(4) constraint fk_deptno_dept references dept(deptno)
);

 

create table empproj
(
empno number(4) ,
proj varchar2(20) not null,
hours number(4) ,
constraint pk_empproj primary key (empno, proj),
constraint fk_empno_emp foreign key (empno) references emp(empno)
);

INSERT INTO DEPT VALUES (10,’FINANCE’,’RESTON’);
INSERT INTO DEPT VALUES (20,’ACCOUNTING’,’CHICAGO’);
INSERT INTO DEPT VALUES (30,’RESEARCH’,’DALLAS’);

INSERT INTO EMP VALUES ( 1001,’TIM’, 5800, 10);
INSERT INTO EMP VALUES ( 1002,’MIKE’, 5800, 30);
INSERT INTO EMP VALUES ( 1003,’SAM’, 5800, 30);
INSERT INTO EMP VALUES ( 1004,’JOE’, 5800, 20);
INSERT INTO EMP VALUES ( 1005,’SEAN’, 5800, 10);
INSERT INTO EMPPROJ VALUES (1001,’RED’,20);
INSERT INTO EMPPROJ VALUES (1001,’PINK’,30);
INSERT INTO EMPPROJ VALUES (1001,’BLUE’,10);
INSERT INTO EMPPROJ VALUES (1002,’PINK’,10);
INSERT INTO EMPPROJ VALUES (1002,’BLUE’,40);

 

 

 

ORA-14128: FOREIGN KEY constraint mismatch in ALTER TABLE EXCHANGE PARTITION : The solution

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

  1.  create table transaction_Duplicate as select * from Transaction where 1 = 0;
  2. alter table transaction_Duplicate add constraint Transaction_dup_pk primary key(transid);
  3. create index salesid_idx on Transaction_Duplicate(salesid) ;
  4. alter table transaction_Duplicate add constraint fk_salesid foreign key (salesid) references sales(salesid);
  5. alter table transaction exchange partition Transaction_part_2011 with table Transaction_Duplicate including indexes without validation;
  6. 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.