eygle.com   eygle.com
eygle.com eygle
eygle.com  
 

« 自己动手,丰衣足食 | Blog首页 | Redo allocation latch介绍 »

如何有条件的分步删除数据表中的记录
modb.pro

有时候我们需要分配删除数据表的一些记录,分批提交以减少对于Undo的使用,本文提供一个简单的存储过程用于实现该逻辑。
你可以根据你的需要进行适当调整,本例仅供参考:

SQL> create table test as select * from dba_objects;

Table created.

SQL> create or replace procedure deleteTab
  2  /**
  3   ** Usage: run the script to create the proc deleteTab
  4   **        in SQL*PLUS, type "exec deleteTab('Foo','ID>=1000000','3000');"
  5   **        to delete the records in the table "Foo", commit per 3000 records.
  6   **       Condition with default value '1=1' and default Commit batch is 10000.
  7   **/
  8  (
  9    p_TableName    in    varchar2,    -- The TableName which you want to delete from
 10    p_Condition    in    varchar2 default '1=1',    -- Delete condition, such as "id>=100000"
 11    p_Count        in    varchar2 default '10000'    -- Commit after delete How many records
 12  )
 13  as
 14   pragma autonomous_transaction;
 15   n_delete number:=0;
 16  begin
 17   while 1=1 loop
 18     EXECUTE IMMEDIATE
 19       'delete from '||p_TableName||' where '||p_Condition||' and rownum <= :rn'
 20     USING p_Count;
 21     if SQL%NOTFOUND then
 22     exit;
 23     else
 24          n_delete:=n_delete + SQL%ROWCOUNT;
 25     end if;
 26     commit;
 27   end loop;
 28   commit;
 29   DBMS_OUTPUT.PUT_LINE('Finished!'); 
 30   DBMS_OUTPUT.PUT_LINE('Totally '||to_char(n_delete)||' records deleted!');
 31  end;
 32  /

Procedure created.


SQL> insert into test select * from dba_objects;

6374 rows created.

SQL> /

6374 rows created.

SQL> /

6374 rows created.

SQL> commit;

Commit complete.

SQL> exec deleteTab('TEST','object_id >0','3000')
Finished!
Totally 19107 records deleted!

PL/SQL procedure successfully completed.


很简单,但是想来也有人可以用到。

修正了一下,增加了2个缺省值,完整过程如下:
create or replace procedure deleteTab
(                                                                                                
  p_TableName    in    varchar2,    -- The TableName which you want to delete from               
  p_Condition    in    varchar2 default '1=1',    -- Delete condition, such as "id>=100000"                    
  p_Count        in    varchar2 default '10000'    -- Commit after delete How many records                      
)                                                                                                
as                                                                                               
 pragma autonomous_transaction;                                                                  
 n_delete number:=0;                                                                             
begin                                                                                            
 while 1=1 loop                                                                                  
   EXECUTE IMMEDIATE                                                                             
     'delete from '||p_TableName||' where '||p_Condition||' and rownum <= :rn'                   
   USING p_Count;                                                                                
   if SQL%NOTFOUND then                                                                          
   exit;                                                                                         
   else                                                                                          
        n_delete:=n_delete + SQL%ROWCOUNT;                                                       
   end if;                                                                                       
   commit;                                                                                       
 end loop;                                                                                       
 commit;                                                                                         
 DBMS_OUTPUT.PUT_LINE('Finished!');                                                              
 DBMS_OUTPUT.PUT_LINE('Totally '||to_char(n_delete)||' records deleted!');                       
end;                                                                                             
/                                                                                                



历史上的今天...
    >> 2012-02-22文章:
    >> 2011-02-22文章:
    >> 2009-02-22文章:
    >> 2008-02-22文章:
           What's Mean "reliable message"?
    >> 2006-02-22文章:

By eygle on 2005-02-22 16:27 | Comments (5) | HowTo | SQL.PLSQL | 186 |

5 Comments

赞一个,最近我就碰到了这个问题。

删除条件为空时,会出错。呵呵

条件为空时,可以加个‘1=1’代替。

修正了一下,增加了2个缺省值.

问下老大,为什么要用自治事务呢?


CopyRight © 2004~2020 云和恩墨,成就未来!, All rights reserved.
数据恢复·紧急救援·性能优化 云和恩墨 24x7 热线电话:400-600-8755 业务咨询:010-59007017-7040 or 7037 业务合作: marketing@enmotech.com