游标的用法:
--打开游标方式1,最标准的操作方式
declare
rec scott.emp%ROWTYPE;
--游标可以有参数,参数也允许有默认值
cursor c1(low number default 0, high number default 10000) return scott.emp%ROWTYPE is
select * from scott.emp where sal between low and high;
begin
open c1(1000,3000); --open游标的时候提供参数
loop
fetch c1 into rec;
exit when c1%NOTFOUND;
dbms_output.put_line(rec.empno || ' ' || rec.sal);
end loop;
close c1;
end;
--for循环打开游标,无需open和close,也不用处理exit
declare
cursor c1(low number default 0, high number default 10000) return scott.emp%ROWTYPE is
select * from scott.emp where sal between low and high;
begin
for rec in c1(1000,3000)
loop
dbms_output.put_line(rec.empno || ' ' || rec.sal);
end loop;
end;
--最简单的方式,无需声明游标,将select语句直接作为游标
declare
low integer;
high integer;
begin
low :=1000;
high := 3000;
for rec in (select * from scott.emp where sal between low and high)
loop
dbms_output.put_line(rec.empno || ' ' || rec.sal);
end loop;
end;
declare
cursor cur1 is select * from test for update; --表明游标用来更新
rec test%ROWTYPE;
begin
open cur1;
for i in 1..100 loop
fetch cur1 into rec;
update test set object_name='haha' where current of cur1; --游标可以用来更新,where current of 游标名
end loop;
commit;
close cur1;
end;
游标变量的用法:
--游标变量
CREATE OR REPLACE PACKAGE emp_data AS
TYPE empcurtyp IS REF CURSOR --包中可以声明游标变量类型,但是无法声明游标变量
RETURN employees%ROWTYPE;
PROCEDURE open_emp_cv (emp_cv IN OUT empcurtyp); --游标变量经常用作存储过程的输出参数
END emp_data;
CREATE OR REPLACE PACKAGE BODY emp_data AS
PROCEDURE open_emp_cv (emp_cv IN OUT empcurtyp) IS --存储过程返回游标变量
BEGIN
OPEN emp_cv FOR
SELECT *
FROM employees;
END open_emp_cv;
END emp_data;
declare
cur emp_data.empcurtyp;
type rectable is table of employees%ROWTYPE;
rec rectable;
i number;
begin
emp_data.open_emp_cv(cur);
fetch cur bulk collect into rec; --批量取游标变量的值
i := rec.first;
while i <= rec.last loop
dbms_output.put_line(rec(i).first_name || ' ' || rec(i).last_name);
i := rec.next(i);
end loop;
close cur;
end;
declare
cur emp_data.empcurtyp;
rec employees%ROWTYPE;
i number;
begin
emp_data.open_emp_cv(cur);
fetch cur into rec; --单条取游标变量的值
loop
exit when cur%NOTFOUND;
dbms_output.put_line(rec(i).first_name || ' ' || rec(i).last_name);
end loop;
close cur;
end;
EXCEPTION
WHEN ROWTYPE_MISMATCH THEN
WHEN INVALID_CURSOR THEN
如果两个游标变量都是强类型,且类型不同,哪怕return的值一样,也不能相互赋值。
如下面的赋值是错误的
declare
type emp_cur_type1 is ref cursor return employees%ROWTYPE;
cur1 emp_cur_type1;
type emp_cur_type2 is ref cursor return employees%ROWTYPE;
cur2 emp_cur_type2;
begin
open cur1 for select * from employees;
cur1 := cur2; -- causes 'wrong type' error
...
end;
两个游标变量相互赋值后,操作其一相当于操作两者。
declare
type emp_cur_type is ref cursor return employees%ROWTYPE;
cur1 emp_cur_type;
cur2 emp_cur_type;
rec1 employees%ROWTYPE;
rec2 employees%ROWTYPE;
begin
open cur1 for select * from employees;
cur2 := cur1;
loop
fetch cur1 into rec1;
exit when cur1%NOTFOUND;
dbms_output.put_line(rec1.first_name || ' ' || rec1.last_name);
end loop;
dbms_output.put_line('-----------------------------------------------------');
--此后将打印不出来内容,因为前面的cur1数据已经取完,指针移到了最后
--cur2和cur1指向的是同一个区域,所以操作cur1相当于操作cur2
loop
fetch cur2 into rec2;
exit when cur2%NOTFOUND;
dbms_output.put_line(rec2.first_name || ' ' || rec2.last_name);
end loop;
close cur1;
-- close cur2; --不能再次关闭,因为cur1和cur2指向的是同一个区域,close cur1后cur2也随之关闭了
end;
游标属性:
%FOUND, %NOTFOUND, %ROWCOUNT, %ISOPEN
隐式游标
SQL%FOUND, SQL%NOTFOUND, SQL%ROWCOUNT, SQL%ISOPEN
这些属性与最近一次执行的语句相关,如果要用到,最好在待考察语句结束后,马上用变量保存起来。
自治事务:
PRAGMA AUTONOMOUS_TRANSACTION; --在声明的任何部分加入这句话都可以,一般在第一句。
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; --将事务隔离级别设置为serializable
create package debugging as
function log_msg(msg varchar2) return varchar2;
pragma restrict_references(log_msg,WNDS,RNDS); --限制函数log_msg写数据表或者读数据表
end debugging;
create package body debugging as
function log_msg(msg varcahr2)
return varchar2
is
pragma autonomous_transaction; --自治事务可以免收上面的限制
begin
insert into debug_output
values(msg);
commit;
return msg;
end;
end debugging;
posted on 2012-03-26 16:51
futual 阅读(226)
评论(0) 编辑 收藏 引用 所属分类:
SQL/plsql