%TYPE attribute in variable declarations (PL/SQL)
The %TYPE attribute, used in PL/SQL variable and parameter declarations, is supported by the data server. Use of this attribute ensures that type compatibility between table columns and PL/SQL variables is maintained.
A qualified column name in dot notation or the name of a previously declared variable must be specified as a prefix to the %TYPE attribute. The data type of this column or variable is assigned to the variable being declared. If the data type of the column or variable changes, there is no need to modify the declaration code.
The %TYPE attribute can also be used with formal parameter declarations.
Syntax
Description
- name
- Specifies an identifier for the variable or formal parameter that is being declared.
- table
- Specifies an identifier for the table whose column is to be referenced.
- view
- Specifies an identifier for the view whose column is to be referenced.
- column
- Specifies an identifier for the table or view column that is to be referenced.
- variable
- Specifies an identifier for a previously declared variable that is to be referenced. The variable does not inherit any other column attributes, such as, for example, the nullability attribute.
Example
The following example shows a procedure
that queries the EMP table using an employee number, displays the
employee's data, finds the average salary of all employees in the
department to which the employee belongs, and then compares the chosen
employee's salary with the department average.
CREATE OR REPLACE PROCEDURE emp_sal_query (
p_empno IN NUMBER
)
IS
v_ename VARCHAR2(10);
v_job VARCHAR2(9);
v_hiredate DATE;
v_sal NUMBER(7,2);
v_deptno NUMBER(2);
v_avgsal NUMBER(7,2);
BEGIN
SELECT ename, job, hiredate, sal, deptno
INTO v_ename, v_job, v_hiredate, v_sal, v_deptno
FROM emp WHERE empno = p_empno;
DBMS_OUTPUT.PUT_LINE('Employee # : ' || p_empno);
DBMS_OUTPUT.PUT_LINE('Name : ' || v_ename);
DBMS_OUTPUT.PUT_LINE('Job : ' || v_job);
DBMS_OUTPUT.PUT_LINE('Hire Date : ' || v_hiredate);
DBMS_OUTPUT.PUT_LINE('Salary : ' || v_sal);
DBMS_OUTPUT.PUT_LINE('Dept # : ' || v_deptno);
SELECT AVG(sal) INTO v_avgsal
FROM emp WHERE deptno = v_deptno;
IF v_sal > v_avgsal THEN
DBMS_OUTPUT.PUT_LINE('Employee''s salary is more than the department '
|| 'average of ' || v_avgsal);
ELSE
DBMS_OUTPUT.PUT_LINE('Employee''s salary does not exceed the department '
|| 'average of ' || v_avgsal);
END IF;
END;
This procedure could be rewritten without explicitly
coding the EMP table data types in the declaration section.
CREATE OR REPLACE PROCEDURE emp_sal_query (
p_empno IN emp.empno%TYPE
)
IS
v_ename emp.ename%TYPE;
v_job emp.job%TYPE;
v_hiredate emp.hiredate%TYPE;
v_sal emp.sal%TYPE;
v_deptno emp.deptno%TYPE;
v_avgsal v_sal%TYPE;
BEGIN
SELECT ename, job, hiredate, sal, deptno
INTO v_ename, v_job, v_hiredate, v_sal, v_deptno
FROM emp WHERE empno = p_empno;
DBMS_OUTPUT.PUT_LINE('Employee # : ' || p_empno);
DBMS_OUTPUT.PUT_LINE('Name : ' || v_ename);
DBMS_OUTPUT.PUT_LINE('Job : ' || v_job);
DBMS_OUTPUT.PUT_LINE('Hire Date : ' || v_hiredate);
DBMS_OUTPUT.PUT_LINE('Salary : ' || v_sal);
DBMS_OUTPUT.PUT_LINE('Dept # : ' || v_deptno);
SELECT AVG(sal) INTO v_avgsal
FROM emp WHERE deptno = v_deptno;
IF v_sal > v_avgsal THEN
DBMS_OUTPUT.PUT_LINE('Employee''s salary is more than the department '
|| 'average of ' || v_avgsal);
ELSE
DBMS_OUTPUT.PUT_LINE('Employee''s salary does not exceed the department '
|| 'average of ' || v_avgsal);
END IF;
END;
The p_empno parameter is an example of a formal parameter
that is defined using the %TYPE attribute. The v_avgsal variable is
an example of the %TYPE attribute referring to another variable instead
of a table column.The following sample output is generated
by a call to the EMP_SAL_QUERY procedure:
CALL emp_sal_query(7698);
Employee # : 7698
Name : BLAKE
Job : MANAGER
Hire Date : 01-MAY-81 00:00:00
Salary : 2850.00
Dept # : 30
Employee's salary is more than the department average of 1566.67