INSERT v12
The INSERT
command available in the SQL language can also be used in SPL programs.
An expression in the SPL language can be used wherever an expression is allowed in the SQL INSERT
command. Thus, SPL variables and parameters can be used to supply values to the insert operation.
The following is an example of a procedure that performs an insert of a new employee using data passed from a calling program.
CREATE OR REPLACE PROCEDURE emp_insert ( p_empno IN emp.empno%TYPE, p_ename IN emp.ename%TYPE, p_job IN emp.job%TYPE, p_mgr IN emp.mgr%TYPE, p_hiredate IN emp.hiredate%TYPE, p_sal IN emp.sal%TYPE, p_comm IN emp.comm%TYPE, p_deptno IN emp.deptno%TYPE ) IS BEGIN INSERT INTO emp VALUES ( p_empno, p_ename, p_job, p_mgr, p_hiredate, p_sal, p_comm, p_deptno); DBMS_OUTPUT.PUT_LINE('Added employee...'); DBMS_OUTPUT.PUT_LINE('Employee # : ' || p_empno); DBMS_OUTPUT.PUT_LINE('Name : ' || p_ename); DBMS_OUTPUT.PUT_LINE('Job : ' || p_job); DBMS_OUTPUT.PUT_LINE('Manager : ' || p_mgr); DBMS_OUTPUT.PUT_LINE('Hire Date : ' || p_hiredate); DBMS_OUTPUT.PUT_LINE('Salary : ' || p_sal); DBMS_OUTPUT.PUT_LINE('Commission : ' || p_comm); DBMS_OUTPUT.PUT_LINE('Dept # : ' || p_deptno); DBMS_OUTPUT.PUT_LINE('----------------------'); EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('OTHERS exception on INSERT of employee # ' || p_empno); DBMS_OUTPUT.PUT_LINE('SQLCODE : ' || SQLCODE); DBMS_OUTPUT.PUT_LINE('SQLERRM : ' || SQLERRM); END;
If an exception occurs all database changes made in the procedure are automatically rolled back. In this example the EXCEPTION
section with the WHEN OTHERS
clause catches all exceptions. Two variables are displayed. SQLCODE
is a number that identifies the specific exception that occurred. SQLERRM
is a text message explaining the error. See Exception Handling for more information on exception handling.
The following shows the output when this procedure is executed.
EXEC emp_insert(9503,'PETERSON','ANALYST',7902,'31-MAR-05',5000,NULL,40); Added employee... Employee # : 9503 Name : PETERSON Job : ANALYST Manager : 7902 Hire Date : 31-MAR-05 00:00:00 Salary : 5000 Dept # : 40 ---------------------- SELECT * FROM emp WHERE empno = 9503; empno | ename | job | mgr | hiredate | sal | comm | deptno -------+--------+--------+------+-------------------+---------+------+------- 9503 |PETERSON| ANALYST| 7902 | 31-MAR-05 00:00:00| 5000.00 | | 40 (1 row)
Note
The INSERT
command can be included in a FORALL
statement. A FORALL
statement allows a single INSERT
command to insert multiple rows from values supplied in one or more collections. See Using the FORALL Statement for more information on the FORALL
statement.