SQL> set serveroutput on;SQL> begin sayHello; end;/
(2)带参数的存储过程:
给指定的员工涨100元工资,并且打印涨前和涨后的薪水:
1 2 3
create or replace procedure addSal(pempno in emp.empno%type)as pename emp.ename%type; beforesal emp.sal%type; aftersal emp.sal%type;begin select ename,sal into pename,beforesal from emp where empno=pempno; aftersal:=beforesal+100; update emp set sal=aftersal where empno=pempno; dbms_output.put_line('姓名: '||pename||' 涨前工资:'||beforesal||'涨后工资:'||aftersal);end;/
create [or replace] function 函数名(参数列表)return 函数值类型 asPLSQL子程序体;
注意事项:
- 1. 与存储过程注意事项类似,不同的是,必须有个返回值;
- 1. 参数列表可以有,也可以没有.当没有时,函数名后面不要带括号.
1 2 3 4
create or replace function queryempannal(pempno in number) return number as psal emp.sal%type; pcomm emp.comm%type;begin select sal,comm into psal,pcomm from emp where empno=pempno; return psal*12+nvl(pcomm,0);end;
create or replace procedure queryempinform(eno in number, pename out varchar2, psal out number, pjob out varchar2 )asbegin select ename,sal,job into pename,psal,pjob from emp where empno=eno;end;/
五. 案例
blob类型转换成clob类型
存储函数
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15
CREATEOR REPLACE FUNCTION blob_to_clob2 (blob_in INBLOB) RETURN CLOBAS v_clob CLOB; v_varchar VARCHAR2(32767); v_start PLS_INTEGER :=1; v_buffer PLS_INTEGER :=32767; BEGIN DBMS_LOB.CREATETEMPORARY(v_clob, TRUE); if DBMS_LOB.GETLENGTH(blob_in) isnullthenreturn empty_clob(); end if; FOR i IN1..CEIL(DBMS_LOB.GETLENGTH(blob_in) / v_buffer) LOOP v_varchar := UTL_RAW.CAST_TO_VARCHAR2(DBMS_LOB.SUBSTR(blob_in, v_buffer, v_start)); DBMS_LOB.WRITEAPPEND(v_clob, LENGTH(v_varchar), v_varchar); v_start := v_start + v_buffer; END LOOP; RETURN v_clob; END blob_to_clob2;
createor replace FUNCTION blob_to_varchar (blob_in INBLOB) RETURN VARCHAR2 IS v_varchar VARCHAR2(4000); v_start PLS_INTEGER :=1; v_buffer PLS_INTEGER :=4000; BEGIN --select userenv('LANGUAGE') into g_nls_db_char from dual; if DBMS_LOB.GETLENGTH(blob_in) is null then return empty_clob(); end if; DBMS_OUTPUT.put_line('TEST:'||CEIL(DBMS_LOB.GETLENGTH(blob_in))); --DBMS_LOB.CREATETEMPORARY(v_clob, TRUE); FOR i IN 1..CEIL(DBMS_LOB.GETLENGTH(blob_in) / v_buffer) LOOP v_varchar := UTL_RAW.CAST_TO_VARCHAR2(utl_raw.convert(DBMS_LOB.SUBSTR(blob_in, v_buffer, v_start),'SIMPLIFIED CHINESE_CHINA.ZHS16GBK', 'AMERICAN_THE NETHERLANDS.UTF8')); --DBMS_LOB.WRITEAPPEND(v_clob, LENGTH(v_varchar), v_varchar); v_start := v_start + v_buffer; END LOOP; --DBMS_OUTPUT.put_line(v_varchar); RETURN v_varchar; end blob_to_varchar;