| Oracle FAQ | Your Portal to the Oracle Knowledge Grid | |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: truncate table
On Wed, 3 Jan 2001, Sajid Iqbal wrote:
> Hi > > Is there any way of doing a truncate table command in a package/procedure > ? > > Sajid Iqbal > Database Administrator
Here is stored procedure that I acquired some years ago.
It uses dynamic SQL to truncate a table.
WHat is so cool about it is that it disables FK constraints that would prevent truncation, truncates the table, then re-enables the constraints.
Jared Still
Certified Oracle DBA and Part Time Perl Evangelist ;)
jkstill_at_teleport.com
jared_still_at_enron.net
create or replace procedure trunc_tab
(tname varchar2, towner user_constraints.r_owner%TYPE default user,reuz boolean default false) as
/*-------------------------------------------------------------------------\ | Name: Trunc_tab | Description: Given a table name will truncate the table. The table is | assumed to be in the users schema. As a possible | enhancement add a table which has user table mapping, | and check the table before any processing if the current user | has rights to truncate the said (tname) table. | Parameters: tname --- Varchar2, In ; table to be truncated | towner --- varchar2, In ; owner of table - default to USER function | reuz --- Boolean, In ; Option to reause space | Date Written: 12-Feb-95 | Written By: Raj Pande |--------------------------------------------------------------------------- | Mod History: | 12-Feb-95 Date Written | 12-Feb-96 Given a table, Check dependencies, disable Fk's truncate | Table and then enable Fk constraints. | \*-------------------------------------------------------------------------*/ lv_chld_table user_constraints.table_name%TYPE; lv_chld_ownr user_constraints.r_owner%TYPE; lv_chld_cons user_constraints.constraint_name%TYPE; lv_parnt_cons user_constraints.r_constraint_name%TYPE;
--lv_ownr user_constraints.r_owner%TYPE := user;
lv_ownr user_constraints.r_owner%TYPE; src_cursor integer; stmt_string varchar2(800) ; temp_str varchar2(200); rc integer;
index by binary_integer;
enb_cons_tab str_tab;
dsbl_cons_tab str_tab;
CURSOR C_CHILD_TABS is
select chld.owner ownr, chld.table_name tabl, chld.constraint_name ccon,
chld.r_constraint_name crcon
from user_constraints parnt, all_constraints chld
where chld.constraint_type = 'R'
and chld.r_constraint_name = parnt.constraint_name
and chld.r_owner = parnt.owner
and chld.status = 'ENABLED'
and parnt.table_name = upper(trunc_tab.tname);
CURSOR C_CHILD_COLS is
SELECT column_name from all_cons_columns
WHERE owner = lv_chld_ownr
and table_name = lv_chld_table
and constraint_name = lv_chld_cons;
/*--------------------------------------------------------------------\
| Subroutine: DO_DDL_DSQL
\--------------------------------------------------------------------*/PROCEDURE DO_DDL_DSQL is
/*--------------------------------------------------------------------\| Subroutine: DO_DML_DSQL
\--------------------------------------------------------------------*/FUNCTION DO_DML_DSQL return Number is
/*------------------------------------------------------------------------\| Subroutine: BLD_DSBL_CON.
\------------------------------------------------------------------------*/PROCEDURE BLD_DSBL_CON is
dsbl_cons_tab(lv_cons_count) := 'ALTER TABLE ' || lv_chld_table ||
' disable constraint ' || lv_chld_cons;
END BLD_DSBL_CON;
/*------------------------------------------------------------------------\ | Subroutine: BLD_ENB_CON. | Description: A subroutine to build the create foreign key definitions | that must be created after the table is truncated. \------------------------------------------------------------------------*/PROCEDURE BLD_ENB_CON is
enb_cons_tab(lv_cons_count) := 'ALTER TABLE ' || lv_chld_table ||
' enable constraint ' || lv_chld_cons;
END BLD_ENB_CON;
/*----------------------------------------------------------------------\
| Subroutine: DSBL_CON
| Description: The subroutine to disable the existing foreign key constraints
| for the table.
\-----------------------------------------------------------------------*/
PROCEDURE DSBL_CON is
DO_DDL_DSQL; ------ Execute the Disable constraint.
END DSBL_CON; -- End of procedure dsbl_con
/*-- Start of Main Procedure ------------------------------ */
BEGIN
lv_ownr := towner;
src_cursor := dbms_sql.open_cursor; -- Open the cursor
FOR CHLD_TABS in C_CHILD_TABS LOOP -- Get the tables that refer this tab
lv_chld_table := chld_tabs.tabl;
lv_chld_cons := chld_tabs.ccon;
lv_parnt_cons := chld_tabs.crcon;
lv_chld_ownr := chld_tabs.ownr;
temp_str := ' ';
FOR child_cols in C_CHILD_COLS LOOP -- Check Ref columns, It'll help
-- If the child field has index
-- On the fields - Which one ??
temp_str := temp_str || child_cols.column_name ||
' is not null or ';
END LOOP;
temp_str := substr(temp_str, 1, length(temp_str) - 3);
stmt_string := 'Select ''x'' from ' || chld_tabs.ownr || '.' ||
chld_tabs.tabl || ' where ' || temp_str ||
' and rownum = 1';
if ( do_dml_dsql > 0 )
then
raise_application_error(-20200, 'Child Table ' ||
chld_tabs.ownr || '.' ||
chld_tabs.tabl || ' has Not Null values as FK ' ||
' Can Not truncate Table ' || upper(trunc_tab.tname));
END IF;
lv_cons_count := lv_cons_count + 1;
bld_enb_con; --------- Build the foreign key constraints string
bld_dsbl_con; --------- Build the Disable constraints string
-- Note that we Don't do the actual disable now as the next Child
![]() |
![]() |