SQL Injection
SQL injection maliciously exploits applications that use client-supplied data in SQL statements, thereby gaining unauthorized access to a database to view or manipulate restricted data.
This section describes SQL injection vulnerabilities in PL/SQL and explains how to guard against them.
Topics
Example 8-15 Setup for SQL Injection Examples
To try the examples, run these statements.
Live SQL:
You can view and run this example on Oracle Live SQL at SQL Injection Demo
DROP TABLE secret_records; CREATE TABLE secret_records ( user_name VARCHAR2(9), service_type VARCHAR2(12), value VARCHAR2(30), date_created DATE ); INSERT INTO secret_records ( user_name, service_type, value, date_created ) VALUES ('Andy', 'Waiter', 'Serve dinner at Cafe Pete', SYSDATE); INSERT INTO secret_records ( user_name, service_type, value, date_created ) VALUES ('Chuck', 'Merger', 'Buy company XYZ', SYSDATE);
SQL Injection Techniques
All SQL injection techniques exploit a single vulnerability: String input is not correctly validated and is concatenated into a dynamic SQL statement.
Topics
Statement Modification
Statement modification means deliberately altering a dynamic SQL statement so that it runs in a way unintended by the application developer.
Typically, the user retrieves unauthorized data by changing the WHERE
clause of a SELECT
statement or by inserting a UNION
ALL
clause. The classic example of this technique is bypassing password authentication by making a WHERE
clause always TRUE
.
Example 8-16 Procedure Vulnerable to Statement Modification
This example creates a procedure that is vulnerable to statement modification and then invokes that procedure with and without statement modification. With statement modification, the procedure returns a supposedly secret record.
Live SQL:
You can view and run this example on Oracle Live SQL at SQL Injection Demo
Create vulnerable procedure:
CREATE OR REPLACE PROCEDURE get_record ( user_name IN VARCHAR2, service_type IN VARCHAR2, rec OUT VARCHAR2 ) AUTHID DEFINER IS query VARCHAR2(4000); BEGIN -- Following SELECT statement is vulnerable to modification -- because it uses concatenation to build WHERE clause. query := 'SELECT value FROM secret_records WHERE user_name=''' || user_name || ''' AND service_type=''' || service_type || ''''; DBMS_OUTPUT.PUT_LINE('Query: ' || query); EXECUTE IMMEDIATE query INTO rec ; DBMS_OUTPUT.PUT_LINE('Rec: ' || rec ); END; /
Demonstrate procedure without SQL injection:
SET SERVEROUTPUT ON; DECLARE record_value VARCHAR2(4000); BEGIN get_record('Andy', 'Waiter', record_value); END; /
Result:
Query: SELECT value FROM secret_records WHERE user_name='Andy' AND service_type='Waiter' Rec: Serve dinner at Cafe Pete
Example of statement modification:
DECLARE
record_value VARCHAR2(4000);
BEGIN
get_record(
'Anybody '' OR service_type=''Merger''--',
'Anything',
record_value);
END;
/
Result:
Query: SELECT value FROM secret_records WHERE user_name='Anybody ' OR service_type='Merger'--' AND service_type='Anything' Rec: Buy company XYZ PL/SQL procedure successfully completed.
Statement Injection
Statement injection means that a user appends one or more SQL statements to a dynamic SQL statement.
Anonymous PL/SQL blocks are vulnerable to this technique.
Example 8-17 Procedure Vulnerable to Statement Injection
This example creates a procedure that is vulnerable to statement injection and then invokes that procedure with and without statement injection. With statement injection, the procedure deletes the supposedly secret record exposed in Example 8-16.
Live SQL:
You can view and run this example on Oracle Live SQL at SQL Injection Demo
Create vulnerable procedure:
CREATE OR REPLACE PROCEDURE p ( user_name IN VARCHAR2, service_type IN VARCHAR2 ) AUTHID DEFINER IS block1 VARCHAR2(4000); BEGIN -- Following block is vulnerable to statement injection -- because it is built by concatenation. block1 := 'BEGIN DBMS_OUTPUT.PUT_LINE(''user_name: ' || user_name || ''');' || 'DBMS_OUTPUT.PUT_LINE(''service_type: ' || service_type || '''); END;'; DBMS_OUTPUT.PUT_LINE('Block1: ' || block1); EXECUTE IMMEDIATE block1; END; /
Demonstrate procedure without SQL injection:
SET SERVEROUTPUT ON; BEGIN p('Andy', 'Waiter'); END; /
Result:
Block1: BEGIN DBMS_OUTPUT.PUT_LINE('user_name: Andy'); DBMS_OUTPUT.PUT_LINE('service_type: Waiter'); END; user_name: Andy service_type: Waiter
SQL*Plus formatting command:
COLUMN date_created FORMAT A12;
Query:
SELECT * FROM secret_records ORDER BY user_name;
Result:
USER_NAME SERVICE_TYPE VALUE DATE_CREATED --------- ------------ ------------------------------ ------------ Andy Waiter Serve dinner at Cafe Pete 28-APR-10 Chuck Merger Buy company XYZ 28-APR-10
Example of statement modification:
BEGIN p('Anybody', 'Anything''); DELETE FROM secret_records WHERE service_type=INITCAP(''Merger'); END; /
Result:
Block1: BEGIN DBMS_OUTPUT.PUT_LINE('user_name: Anybody'); DBMS_OUTPUT.PUT_LINE('service_type: Anything'); DELETE FROM secret_records WHERE service_type=INITCAP('Merger'); END; user_name: Anybody service_type: Anything PL/SQL procedure successfully completed.
Query:
SELECT * FROM secret_records;
Result:
USER_NAME SERVICE_TYPE VALUE DATE_CREATED
--------- ------------ ------------------------------ ------------
Andy Waiter Serve dinner at Cafe Pete 18-MAR-09
1 row selected.
Data Type Conversion
A less known SQL injection technique uses NLS session parameters to modify or inject SQL statements.
A datetime or numeric value that is concatenated into the text of a dynamic SQL statement must be converted to the VARCHAR2
data type. The conversion can be either implicit (when the value is an operand of the concatenation operator) or explicit (when the value is the argument of the TO_CHAR
function). This data type conversion depends on the NLS settings of the database session that runs the dynamic SQL statement. The conversion of datetime values uses format models specified in the parameters NLS_DATE_FORMAT
, NLS_TIMESTAMP_FORMAT
, or NLS_TIMESTAMP_TZ_FORMAT
, depending on the particular datetime data type. The conversion of numeric values applies decimal and group separators specified in the parameter NLS_NUMERIC_CHARACTERS
.
One datetime format model is "
text
"
. The text
is copied into the conversion result. For example, if the value of NLS_DATE_FORMAT
is '"Month:" Month'
, then in June, TO_CHAR(SYSDATE)
returns 'Month: June'
. The datetime format model can be abused as shown in Example 8-18.
Example 8-18 Procedure Vulnerable to SQL Injection Through Data Type Conversion
SELECT * FROM secret_records;
Result:
USER_NAME SERVICE_TYPE VALUE DATE_CREATE --------- ------------ ------------------------------ ----------- Andy Waiter Serve dinner at Cafe Pete 28-APR-2010 Chuck Merger Buy company XYZ 28-APR-2010
Create vulnerable procedure:
-- Return records not older than a month CREATE OR REPLACE PROCEDURE get_recent_record ( user_name IN VARCHAR2, service_type IN VARCHAR2, rec OUT VARCHAR2 ) AUTHID DEFINER IS query VARCHAR2(4000); BEGIN /* Following SELECT statement is vulnerable to modification because it uses concatenation to build WHERE clause and because SYSDATE depends on the value of NLS_DATE_FORMAT. */ query := 'SELECT value FROM secret_records WHERE user_name=''' || user_name || ''' AND service_type=''' || service_type || ''' AND date_created>''' || (SYSDATE - 30) || ''''; DBMS_OUTPUT.PUT_LINE('Query: ' || query); EXECUTE IMMEDIATE query INTO rec; DBMS_OUTPUT.PUT_LINE('Rec: ' || rec); END; /
Demonstrate procedure without SQL injection:
SET SERVEROUTPUT ON;
ALTER SESSION SET NLS_DATE_FORMAT='DD-MON-YYYY';
DECLARE
record_value VARCHAR2(4000);
BEGIN
get_recent_record('Andy', 'Waiter', record_value);
END;
/
Result:
Query: SELECT value FROM secret_records WHERE user_name='Andy' AND service_type='Waiter' AND date_created>'29-MAR-2010' Rec: Serve dinner at Cafe Pete
Example of statement modification:
ALTER SESSION SET NLS_DATE_FORMAT='"'' OR service_type=''Merger"';
DECLARE
record_value VARCHAR2(4000);
BEGIN
get_recent_record('Anybody', 'Anything', record_value);
END;
/
Result:
Query: SELECT value FROM secret_records WHERE user_name='Anybody' AND service_type='Anything' AND date_created>'' OR service_type='Merger' Rec: Buy company XYZ PL/SQL procedure successfully completed.
Guards Against SQL Injection
If you use dynamic SQL in your PL/SQL applications, you must check the input text to ensure that it is exactly what you expected.
You can use the following techniques:
Bind Variables
The most effective way to make your PL/SQL code invulnerable to SQL injection attacks is to use bind variables.
The database uses the values of bind variables exclusively and does not interpret their contents in any way. (Bind variables also improve performance.)
Example 8-19 Bind Variables Guarding Against SQL Injection
The procedure in this example is invulnerable to SQL injection because it builds the dynamic SQL statement with bind variables (not by concatenation as in the vulnerable procedure in Example 8-16). The same binding technique fixes the vulnerable procedure shown in Example 8-17.
Create invulnerable procedure:
CREATE OR REPLACE PROCEDURE get_record_2 ( user_name IN VARCHAR2, service_type IN VARCHAR2, rec OUT VARCHAR2 ) AUTHID DEFINER IS query VARCHAR2(4000); BEGIN query := 'SELECT value FROM secret_records WHERE user_name=:a AND service_type=:b'; DBMS_OUTPUT.PUT_LINE('Query: ' || query); EXECUTE IMMEDIATE query INTO rec USING user_name, service_type; DBMS_OUTPUT.PUT_LINE('Rec: ' || rec); END; /
Demonstrate procedure without SQL injection:
SET SERVEROUTPUT ON; DECLARE record_value VARCHAR2(4000); BEGIN get_record_2('Andy', 'Waiter', record_value); END; /
Result:
Query: SELECT value FROM secret_records WHERE user_name=:a AND service_type=:b Rec: Serve dinner at Cafe Pete PL/SQL procedure successfully completed.
Try statement modification:
DECLARE record_value VARCHAR2(4000); BEGIN get_record_2('Anybody '' OR service_type=''Merger''--', 'Anything', record_value); END; /
Result:
Query: SELECT value FROM secret_records WHERE user_name=:a AND service_type=:b DECLARE * ERROR at line 1: ORA-01403: no data found ORA-06512: at "HR.GET_RECORD_2", line 15 ORA-06512: at line 4
Validation Checks
Always have your program validate user input to ensure that it is what is intended.
For example, if the user is passing a department number for a DELETE
statement, check the validity of this department number by selecting from the departments
table. Similarly, if a user enters the name of a table to be deleted, check that this table exists by selecting from the static data dictionary view ALL_TABLES
.
Caution:
When checking the validity of a user name and its password, always return the same error regardless of which item is invalid. Otherwise, a malicious user who receives the error message "invalid password" but not "invalid user name" (or the reverse) can realize that they have guessed one of these correctly.
In validation-checking code, the subprograms in the DBMS_ASSERT
package are often useful. For example, you can use the DBMS_ASSERT
.ENQUOTE_LITERAL
function to enclose a string literal in quotation marks, as Example 8-20 does. This prevents a malicious user from injecting text between an opening quotation mark and its corresponding closing quotation mark.
Caution:
Although the DBMS_ASSERT
subprograms are useful in validation code, they do not replace it. For example, an input string can be a qualified SQL name (verified by DBMS_ASSERT
.QUALIFIED_SQL_NAME
) and still be a fraudulent password.
See Also:
Oracle Database PL/SQL Packages and Types Reference for information about DBMS_ASSERT
subprograms
Example 8-20 Validation Checks Guarding Against SQL Injection
In this example, the procedure raise_emp_salary
checks the validity of the column name that was passed to it before it updates the employees
table, and then the anonymous block invokes the procedure from both a dynamic PL/SQL block and a dynamic SQL statement.
CREATE OR REPLACE PROCEDURE raise_emp_salary ( column_value NUMBER, emp_column VARCHAR2, amount NUMBER ) AUTHID DEFINER IS v_column VARCHAR2(30); sql_stmt VARCHAR2(200); BEGIN -- Check validity of column name that was given as input: SELECT column_name INTO v_column FROM USER_TAB_COLS WHERE TABLE_NAME = 'EMPLOYEES' AND COLUMN_NAME = emp_column; sql_stmt := 'UPDATE employees SET salary = salary + :1 WHERE ' || DBMS_ASSERT.ENQUOTE_NAME(v_column,FALSE) || ' = :2'; EXECUTE IMMEDIATE sql_stmt USING amount, column_value; -- If column name is valid: IF SQL%ROWCOUNT > 0 THEN DBMS_OUTPUT.PUT_LINE('Salaries were updated for: ' || emp_column || ' = ' || column_value); END IF; -- If column name is not valid: EXCEPTION WHEN NO_DATA_FOUND THEN DBMS_OUTPUT.PUT_LINE ('Invalid Column: ' || emp_column); END raise_emp_salary; / DECLARE plsql_block VARCHAR2(500); BEGIN -- Invoke raise_emp_salary from a dynamic PL/SQL block: plsql_block := 'BEGIN raise_emp_salary(:cvalue, :cname, :amt); END;'; EXECUTE IMMEDIATE plsql_block USING 110, 'DEPARTMENT_ID', 10; -- Invoke raise_emp_salary from a dynamic SQL statement: EXECUTE IMMEDIATE 'BEGIN raise_emp_salary(:cvalue, :cname, :amt); END;' USING 112, 'EMPLOYEE_ID', 10; END; /
Result:
Salaries were updated for: DEPARTMENT_ID = 110 Salaries were updated for: EMPLOYEE_ID = 112
Explicit Format Models
Using explicit locale-independent format models to construct SQL is recommended not only from a security perspective, but also to ensure that the dynamic SQL statement runs correctly in any globalization environment.
If you use datetime and numeric values that are concatenated into the text of a SQL or PL/SQL statement, and you cannot pass them as bind variables, convert them to text using explicit format models that are independent from the values of the NLS parameters of the running session. Ensure that the converted values have the format of SQL datetime or numeric literals.
Example 8-21 Explicit Format Models Guarding Against SQL Injection
This procedure is invulnerable to SQL injection because it converts the datetime parameter value, SYSDATE
-
30
, to a VARCHAR2
value explicitly, using the TO_CHAR
function and a locale-independent format model (not implicitly, as in the vulnerable procedure in Example 8-18).
Create invulnerable procedure:
-- Return records not older than a month
CREATE OR REPLACE PROCEDURE get_recent_record (
user_name IN VARCHAR2,
service_type IN VARCHAR2,
rec OUT VARCHAR2
) AUTHID DEFINER
IS
query VARCHAR2(4000);
BEGIN
/* Following SELECT statement is vulnerable to modification
because it uses concatenation to build WHERE clause. */
query := 'SELECT value FROM secret_records WHERE user_name='''
|| user_name
|| ''' AND service_type='''
|| service_type
|| ''' AND date_created> DATE '''
|| TO_CHAR(SYSDATE - 30,'YYYY-MM-DD')
|| '''';
DBMS_OUTPUT.PUT_LINE('Query: ' || query);
EXECUTE IMMEDIATE query INTO rec;
DBMS_OUTPUT.PUT_LINE('Rec: ' || rec);
END;
/
Try statement modification:
ALTER SESSION SET NLS_DATE_FORMAT='"'' OR service_type=''Merger"';
DECLARE
record_value VARCHAR2(4000);
BEGIN
get_recent_record('Anybody', 'Anything', record_value);
END;
/
Result:
Query: SELECT value FROM secret_records WHERE user_name='Anybody' AND service_type='Anything' AND date_created> DATE '2010-03-29' DECLARE * ERROR at line 1: ORA-01403: no data found ORA-06512: at "SYS.GET_RECENT_RECORD", line 21 ORA-06512: at line 4