如果你不小心覆盖了之前的存储过程,那得赶紧闪回,时长越长闪回的可能性越小。原理很简单,存储过程的定义就是数据字典,修改数据字典跟修改普通表的数据没有区别,此时会把修改前的内容放到undo中,我们可以根据这一点来进行闪回,所以我说要尽快,要不然找不回来了。
下面我们来做一个实验:
第一步,在用户TEST下14:31下建立存储过程
代码如下:1
2
3
4
5
6
7
8
9
10
11
12
13create or replace procedure GG_TEST as
l_cnt number;
begin
for i in 1 .. 10000 loop
execute immediate 'select count(*) from t where x = ' || i into l_cnt;
end loop;
end;
第二步,在用户TEST下在14:33下删除存储过程
1 | drop procedure GG_TEST; |
第三步,登录到sys账户下
执行代码如下:1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21create table p_temp as
select *
from dba_source as of timestamp TO_TIMESTAMP('2014-05-04 14:33:00', 'YYYY-MM-DD HH24:MI:SS')
where TYPE = 'PROCEDURE'
And owner = 'TEST'
And Name = 'GG_TEST';
select text
from p_temp
where name like upper('%GG_TEST%')
and owner = 'TEST'
order by line;
再查询该临时表中的数据,能查到刚才删掉的存储过程文本:1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17TEXT
---------------------------------------------------------------------------
procedure GG_TEST as
l_cnt number;
begin
for i in 1 .. 10000 loop
execute immediate 'select count(*) from t where x = ' || i into l_cnt;
end loop;
end;