浏览 5758 次
锁定老帖子 主题:学习笔记:15使用游标
精华帖 (0) :: 良好帖 (0) :: 新手帖 (0) :: 隐藏帖 (0)
|
|
---|---|
作者 | 正文 |
发表时间:2010-01-05
15-1:使用标量变量接收游标数据 DECLARE CURSOR emp_cursor IS SELECT ename,job,sal FROM emp WHERE deptno=&dno; v_ename emp.ename%TYPE; v_sal emp.sal%TYPE; v_job emp.job%TYPE; BEGIN OPEN emp_cursor; LOOP FETCH emp_cursor INTO v_ename,v_job,v_sal; EXIT WHEN emp_cursor%NOTFOUND; dbms_output.put_line('姓名:'||v_ename||',岗位:'||v_job||',工资:'||v_sal); END LOOP; CLOSE emp_cursor; END; / 15-2:使用pl/sql纪录变量接收游标数据 DECLARE CURSOR emp_cursor IS SELECT ename,sal FROM emp ORDER BY sal DESC; emp_record emp_cursor%ROWTYPE; BEGIN OPEN emp_cursor; LOOP FETCH emp_cursor INTO emp_record; EXIT WHEN emp_cursor%NOTFOUND OR emp_cursor%ROWCOUNT>&n; dbms_output.put_line('姓名:'||emp_record.ename|| ',工资:'||emp_record.sal); END LOOP; CLOSE emp_cursor; END; / 15-3:使用pl/sql集合变量接收游标数据 DECLARE CURSOR emp_cursor IS SELECT ename,sal FROM emp WHERE lower(job)=lower('&job'); TYPE emp_table_type IS TABLE OF emp_cursor%ROWTYPE INDEX BY BINARY_INTEGER; emp_table emp_table_type; i INT; BEGIN OPEN emp_cursor; LOOP i:=emp_cursor%ROWCOUNT+1; FETCH emp_cursor INTO emp_table(i); EXIT WHEN emp_cursor%NOTFOUND; dbms_output.put_line('姓名:'||emp_table(i).ename|| ',工资:'||emp_table(i).sal); END LOOP; CLOSE emp_cursor; END; / 15-4:在游标for循环中引用已定义游标 DECLARE CURSOR emp_cursor IS SELECT ename,hiredate FROM emp ORDER BY hiredate DESC; BEGIN FOR emp_record IN emp_cursor LOOP dbms_output.put_line('姓名:'||emp_record.ename ||',工作日期:'||emp_record.hiredate); EXIT WHEN emp_cursor%ROWCOUNT=&n; END LOOP; END; / 15-5:在游标for循环中直接引用子查询 BEGIN FOR emp_record IN (SELECT ename,hiredate,rownum FROM emp ORDER BY hiredate) LOOP dbms_output.put_line('姓名:'||emp_record.ename ||',工作日期:'||emp_record.hiredate); EXIT WHEN emp_record.rownum=&n; END LOOP; END; / 15-6:参数游标 DECLARE CURSOR emp_cursor(dno NUMBER) IS SELECT ename,job FROM emp WHERE deptno=dno; BEGIN FOR emp_record IN emp_cursor(&dno) LOOP dbms_output.put_line('姓名:'||emp_record.ename ||',岗位:'||emp_record.job); END LOOP; END; / 15-7:更新游标行 DECLARE CURSOR emp_cursor IS SELECT ename,sal,deptno FROM emp FOR UPDATE; dno INT:=&no; BEGIN FOR emp_record IN emp_cursor LOOP IF emp_record.deptno=dno THEN dbms_output.put_line('姓名:'||emp_record.ename ||',原工资:'||emp_record.sal); UPDATE emp SET sal=sal*1.1 WHERE CURRENT OF emp_cursor; END IF; END LOOP; END; / 15-8:删除游标行 DECLARE CURSOR emp_cursor IS SELECT ename FROM emp FOR UPDATE; name VARCHAR2(10):=lower('&name'); BEGIN FOR emp_record IN emp_cursor LOOP IF lower(emp_record.ename)=name THEN DELETE FROM emp WHERE CURRENT OF emp_cursor; ELSE dbms_output.put_line('姓名:'||emp_record.ename); END IF; END LOOP; END; / 15-9:使用of子句在特定表上加行共享锁. DECLARE CURSOR emp_cursor IS SELECT a.dname,b.ename FROM dept a JOIN emp b ON a.deptno=b.deptno FOR UPDATE OF b.deptno; name VARCHAR2(10):=LOWER('&name'); BEGIN FOR emp_record IN emp_cursor LOOP IF LOWER(emp_record.dname)=name THEN dbms_output.put_line('姓名:'||emp_record.ename); DELETE FROM emp WHERE CURRENT OF emp_cursor; END IF; END LOOP; END; / 15-10:使用无返回类型的游标变量 DECLARE TYPE ref_cursor_type IS REF CURSOR; ref_cursor ref_cursor_type; v1 NUMBER(6); v2 VARCHAR2(10); BEGIN OPEN ref_cursor FOR SELECT &col1 col1,&col2 col2 FROM &table WHERE &cond; LOOP FETCH ref_cursor INTO v1,v2; EXIT WHEN ref_cursor%NOTFOUND; dbms_output.put_line('col1='||v1||',col2='||v2); END LOOP; CLOSE ref_cursor; END; / 15-11:使用有返回类型的游标变量 DECLARE TYPE emp_cursor_type IS REF CURSOR RETURN emp%ROWTYPE; emp_cursor emp_cursor_type; emp_record emp%ROWTYPE; BEGIN OPEN emp_cursor FOR SELECT * FROM emp WHERE deptno=&dno; LOOP FETCH emp_cursor INTO emp_record; EXIT WHEN emp_cursor%NOTFOUND; dbms_output.put_line('姓名:'||emp_record.ename|| ',工资:'||emp_record.sal); END LOOP; CLOSE emp_cursor; END; / 15-12:使用fetch...bulk collect提取所有数据 DECLARE CURSOR emp_cursor IS SELECT * FROM emp WHERE LOWER(job)=LOWER('&job'); TYPE emp_table_type IS TABLE OF emp%ROWTYPE; emp_table emp_table_type; BEGIN OPEN emp_cursor; FETCH emp_cursor BULK COLLECT INTO emp_table; CLOSE emp_cursor; FOR i IN 1.. emp_table.COUNT LOOP dbms_output.put_line('姓名:'||emp_table(i).ename ||',工资:'||emp_table(i).sal); END LOOP; END; / 15-13:使用limit子句限制提取行数 DECLARE CURSOR emp_cursor IS SELECT * FROM emp; TYPE emp_array_type IS VARRAY(5) OF emp%ROWTYPE; emp_array emp_array_type; BEGIN OPEN emp_cursor; LOOP FETCH emp_cursor BULK COLLECT INTO emp_array LIMIT &rows; FOR i IN 1..emp_array.COUNT LOOP dbms_output.put_line('姓名:'||emp_array(i).ename ||',工资:'||emp_array(i).sal); END LOOP; EXIT WHEN emp_cursor%NOTFOUND; END LOOP; CLOSE emp_cursor; END; / 15-14:使用cursor表达式 DECLARE CURSOR dept_cursor(no NUMBER) IS SELECT a.dname,CURSOR(SELECT * FROM emp WHERE deptno=a.deptno) FROM dept a WHERE a.deptno=no; TYPE ref_cursor_type IS REF CURSOR; emp_cursor ref_cursor_type; emp_record emp%ROWTYPE; v_dname dept.dname%TYPE; BEGIN OPEN dept_cursor(&dno); LOOP FETCH dept_cursor INTO v_dname,emp_cursor; EXIT WHEN dept_cursor%NOTFOUND; dbms_output.put_line('部门名:'||v_dname); LOOP FETCH emp_cursor INTO emp_record; EXIT WHEN emp_cursor%NOTFOUND; dbms_output.put_line('----雇员名:'||emp_record.ename ||',岗位:'||emp_record.job); END LOOP; END LOOP; CLOSE dept_cursor; END; / 声明:ITeye文章版权属于作者,受法律保护。没有作者书面许可不得转载。
推荐链接
|
|
返回顶楼 | |