Column Name Precedence
If a SQL statement references a name that belongs to both a column and either a local variable or formal parameter, then the column name takes precedence.
Caution:
When a variable or parameter name is interpreted as a column name, data can be deleted, changed, or inserted unintentionally.
In Example B-2, the name last_name belongs to both a local variable and a column (names are not case-sensitive). Therefore, in the WHERE clause, both references to last_name resolve to the column, and all rows are deleted.
Example B-3 solves the problem in Example B-2 by giving the variable a different name.
Example B-4 solves the problem in Example B-2 by labeling the block and qualifying the variable name with the block name.
In Example B-5, the function dept_name has a formal parameter and a local variable whose names are those of columns of the table DEPARTMENTS. The parameter and variable name are qualified with the function name to distinguish them from the column names.
Example B-2 Variable Name Interpreted as Column Name Causes Unintended Result
DROP TABLE employees2;
CREATE TABLE employees2 AS
SELECT LAST_NAME FROM employees;
DECLARE
last_name VARCHAR2(10) := 'King';
BEGIN
DELETE FROM employees2 WHERE LAST_NAME = last_name;
DBMS_OUTPUT.PUT_LINE('Deleted ' || SQL%ROWCOUNT || ' rows.');
END;
/
Result:
Deleted 107 rows.
Example B-3 Fixing Example B-2 with Different Variable Name
DROP TABLE employees2;
CREATE TABLE employees2 AS
SELECT LAST_NAME FROM employees;
DECLARE
v_last_name VARCHAR2(10) := 'King';
BEGIN
DELETE FROM employees2 WHERE LAST_NAME = v_last_name;
DBMS_OUTPUT.PUT_LINE('Deleted ' || SQL%ROWCOUNT || ' rows.');
END;
/
Result:
Deleted 2 rows.
Example B-4 Fixing Example B-2 with Block Label
DROP TABLE employees2;
CREATE TABLE employees2 AS
SELECT LAST_NAME FROM employees;
<<main>>
DECLARE
last_name VARCHAR2(10) := 'King';
BEGIN
DELETE FROM employees2 WHERE last_name = main.last_name;
DBMS_OUTPUT.PUT_LINE('Deleted ' || SQL%ROWCOUNT || ' rows.');
END;
/
Result:
Deleted 2 rows.
Example B-5 Subprogram Name for Name Resolution
DECLARE
FUNCTION dept_name (department_id IN NUMBER)
RETURN departments.department_name%TYPE
IS
department_name departments.department_name%TYPE;
BEGIN
SELECT department_name INTO dept_name.department_name
-- ^column ^local variable
FROM departments
WHERE department_id = dept_name.department_id;
-- ^column ^formal parameter
RETURN department_name;
END dept_name;
BEGIN
FOR item IN (
SELECT department_id
FROM departments
ORDER BY department_name) LOOP
DBMS_OUTPUT.PUT_LINE ('Department: ' || dept_name(item.department_id));
END LOOP;
END;
/
Result:
Department: Accounting
Department: Administration
Department: Benefits
Department: Construction
Department: Contracting
Department: Control And Credit
Department: Corporate Tax
Department: Executive
Department: Finance
Department: Government Sales
Department: Human Resources
Department: IT
Department: IT Helpdesk
Department: IT Support
Department: Manufacturing
Department: Marketing
Department: NOC
Department: Operations
Department: Payroll
Department: Public Relations
Department: Purchasing
Department: Recruiting
Department: Retail Sales
Department: Sales
Department: Shareholder Services
Department: Shipping
Department: Treasury