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);
Recent Comments