How to Prove That Your SmartDB App Is Secure

If you are guarding your data behind a hard shell PL/SQL API as Bryn Llewellyn, Toon Koppelaars and others recommend, then it should be quite easy to prove, that your PL/SQL application is secured against SQL injection attacks. The basic idea is 1) that you do not expose data via tables nor views to Oracle users used in the middle-tier, by end-users and in the GUI; and 2) that you use only static SQL within PL/SQL packages. By following these two rules, you ensure that only SQL statements with bind variables are used in your application, making the injection of unwanted SQL fragments impossible. In this blog post, I show how to check if an application is complying with these two rules.

Demo Applications

I’ve prepared three tiny demo applications to visualise what guarding data behind a hard shell PL/SQL API means and how static and dynamic SQL can be used within Oracle Database 12c Release 2 (12.2). You may install these applications using this script.

The Good

blank
blank

The table T is stored in the schema THE_GOOD_DATA and grants SELECT, INSERT, UPDATE and DELETE privileges to the schema  THE_GOOD_API. This schema owns the PL/SQL package PKG, which implements the data access to table T via static SQL to eliminate the risk of SQL injection. The EXECUTE right on PKG is granted to THE_GOOD_USER. This user has the CONNECT role only and can be safely configured in the connection pool of the middle-tier application.

The Good Data Access
CREATE OR REPLACE PACKAGE BODY 
   the_good_api.pkg 
AS
   FUNCTION f2 (
      p_c2 IN VARCHAR2
   ) RETURN CLOB IS
      l_result CLOB;
      l_c2 the_good_data.t.c2%TYPE;
   BEGIN
      l_c2 := p_c2;
      SELECT JSON_ARRAYAGG (
                JSON_OBJECT (
                   'c1' value c1,
                   'c2' value c2
                ) 
                RETURNING CLOB
             )
        INTO l_result
        FROM the_good_data.t
       WHERE lower(c2) LIKE '%' 
             || lower(l_c2) || '%';
      RETURN l_result;
   END f2;
END pkg;

The Bad

blank
blank

This application looks very similar to “The Good”. One difference is, that the access to table T is implemented through dynamic SQL. There is also a private PL/SQL package named PKG2 which does a series of bad things with dynamic SQL. The implementation of all dynamic SQL is safe, there is no SQL injection possible. However, it is difficult to come to this conclusion by static code analysis and since the use of dynamic SQL is not necessary, this application is considered bad.

The Bad Data Access
CREATE OR REPLACE PACKAGE BODY 
   the_bad_api.pkg 
AS
   FUNCTION f2 (
      p_c2 IN VARCHAR2
   ) RETURN CLOB IS
      co_sql_template CONSTANT CLOB
         := q'[
   SELECT JSON_ARRAYAGG (
             JSON_OBJECT (
                'c1' value c1, 
                'c2' value c2
             ) 
             RETURNING CLOB
          )
     FROM the_bad_data.t
    WHERE lower(c2) LIKE '%' 
          || lower(:c2_bind) || '%'
         ]';     
      l_result CLOB;
      l_c2 the_bad_data.t.c2%TYPE;
   BEGIN
      l_c2 := p_c2;
      EXECUTE IMMEDIATE 
              co_sql_template 
         INTO l_result USING l_c2;
      RETURN l_result;
   END f2;
END pkg;

The Ugly

blank
blank

The table T is stored in the schema THE_UGLY_DATA and grants SELECT, INSERT, UPDATE and DELETE privileges to THE_UGLY_USER. This user has the CONNECT role only. This is good and prohibits schema extensions. But without a PL/SQL API layer, there is no way to prevent SQL injection in the database. This is now becoming a responsibility of the middle-tier application along with other duties such as data consistency and efficient data processing.

The Ugly Data Access
/* not available
 *
 * Query is crafted in 
 * the middle tier application
 */
Example result of a PKG.F2(‘SQL’) call
[
   {
      "c1": 2,
      "c2": "I like SQL."
   },
   {
      "c1": 3,
      "c2": "And JSON is part of SQL and PL/SQL."
   }
]

Rule 1) Do not expose data via tables nor views

The idea behind a hard shell PL/SQL is to expose data through PL/SQL units only. Direct access to tables or views is unwanted. The Oracle users configured in the connection pool of the middle tier, need the CONNECT role and EXECUTE rights on the PL/SQL API only. These rights may be granted directly or indirectly via various levels of Oracle roles.

The following query shows if an Oracle database user is ready to be used in the middle-tier application. Oracle users maintained by Oracle itself, such as SYS, SYSTEM, SYSAUX, etc. are excluded along with some other users which grant objects to PUBLIC (see lines 35 to 38). To execute this query you need the SELECT_CATALOG_ROLE.

Users ready to be used in the middle tier
WITH
   -- roles as recursive structure
   role_base AS (
      -- roles without parent (=roots)
      SELECT r.role, NULL AS parent_role
        FROM dba_roles r
       WHERE r.role NOT IN (
                SELECT p.granted_role
                  FROM role_role_privs p
             )
      UNION ALL
      -- roles with parent (=children)
      SELECT granted_role AS role, role AS parent_role
        FROM role_role_privs
   ),
   -- roles tree, calculate role_path for every hierarchy level
   role_tree AS (
      SELECT role,
             parent_role,
             sys_connect_by_path(ROLE, '/') AS role_path
        FROM role_base
      CONNECT BY PRIOR role = parent_role
   ),
   -- roles graph, child added to all ancestors including self
   -- allows simple join to parent_role to find all descendants
   role_graph AS (
      SELECT DISTINCT
             role,
             regexp_substr(role_path, '(/)(\w+)', 1, 1, 'i', 2) AS parent_role
        FROM role_tree
   ),
   -- application users in scope of the analysis
   -- other users are treated as if they were not istalled
   app_user AS (
      SELECT username
        FROM dba_users
       WHERE oracle_maintained = 'N' -- SYS, SYSTEM, SYSAUX, ...
         AND username NOT IN ('FTLDB', 'PLSCOPE')
   ),
   -- user system privileges
   sys_priv AS (
      -- system privileges granted directly to users
      SELECT u.username, p.privilege
        FROM dba_sys_privs p
        JOIN app_user u ON u.username = p.grantee
      UNION
      -- system privileges granted directly to PUBLIC
      SELECT u.username, p.privilege
        FROM dba_sys_privs p
       CROSS JOIN app_user u
       WHERE p.grantee = 'PUBLIC'
         AND p.privilege NOT IN (
                SELECT r.role
                  FROM dba_roles r
             )
      UNION
      -- system privileges granted to users via roles
      SELECT u.username, p.privilege
        FROM dba_role_privs r
        JOIN app_user u ON u.username = r.grantee
        JOIN role_graph g ON g.parent_role = r.granted_role
        JOIN dba_sys_privs p ON p.grantee = g.role
      UNION
      -- system privileges granted to PUBLIC via roles
      SELECT u.username, p.privilege
        FROM dba_role_privs r
        JOIN role_graph g ON g.parent_role = r.granted_role
        JOIN dba_sys_privs p ON p.grantee = g.role
        CROSS JOIN app_user u
       WHERE r.grantee = 'PUBLIC'
   ),
   -- user object privileges
   obj_priv AS (
      -- objects granted directly to users
      SELECT u.username, p.owner, p.type AS object_type, p.table_name AS object_name
        FROM dba_tab_privs p
        JOIN app_user u ON u.username = p.grantee
       WHERE p.owner IN (
                SELECT u2.username
                  FROM app_user u2
             )
      UNION
      -- objects granted to users via roles
      SELECT u.username, p.owner, p.type AS object_type, p.table_name AS object_name
        FROM dba_role_privs r
        JOIN app_user u ON u.username = r.grantee
        JOIN role_graph g ON g.parent_role = r.granted_role
        JOIN dba_tab_privs p ON p.grantee = g.role
       WHERE p.owner IN (
                SELECT u2.username
                  FROM app_user u2
             )
      -- objects granted to PUBLIC
      UNION
      SELECT u.username, p.owner, p.type AS object_type, p.table_name AS object_name
        FROM dba_tab_privs p
       CROSS JOIN app_user u
       WHERE p.owner IN (
                SELECT u2.username
                  FROM app_user u2
             )
         AND p.grantee = 'PUBLIC'
   ),
   -- issues if user is configured in the connection pool of a middle tier
   issues AS (
      -- privileges not part of CONNECT role
      SELECT username,
             'SYS' AS owner,
             'PRIVILEGE' AS object_type,
             privilege AS object_name,
             'Privilege is not part of the CONNECT role' AS issue
        FROM sys_priv
       WHERE privilege NOT IN ('CREATE SESSION', 'SET CONTAINER')
      UNION ALL
      -- access to non PL/SQL units
      SELECT username,
             owner,
             object_type,
             object_name,
             'Access to non-PL/SQL unit'
        FROM obj_priv
       WHERE object_type NOT IN ('PACKAGE', 'TYPE', 'FUNCTION', 'PROCEDURE')
      -- own objects
      UNION ALL
      SELECT u.username,
             o.owner,
             o.object_type,
             o.object_name,
             'Connect user must not own any object'
        FROM app_user u
        JOIN dba_objects o ON o.owner = u.username
      -- missing CREATE SESSION privilege
      UNION ALL
      SELECT u.username,
             'SYS',
             'PRIVILEGE',
             'CREATE SESSION',
             'Privilege is missing, but required'
        FROM app_user u
       WHERE u.username NOT IN (
                SELECT username
                  FROM sys_priv
                 WHERE privilege = 'CREATE SESSION' 
             )
   ),
   -- aggregate issues per user
   issue_aggr AS (
      SELECT u.username, COUNT(i.username) issue_count
        FROM app_user u
        LEFT JOIN issues i ON i.username = u.username
       GROUP BY u.username
   ),
   -- user summary (calculate is_connect_user_ready)
   summary AS (
      SELECT username,
             CASE
                WHEN issue_count = 0 THEN
                   'YES'
                ELSE
                   'NO'
             END AS is_connect_user_ready,
             issue_count
        FROM issue_aggr
       ORDER BY is_connect_user_ready DESC, username
   )
-- main
SELECT * 
  FROM summary
 WHERE username LIKE 'THE%';
 
USERNAME      IS_CONNECT_USER_READY ISSUE_COUNT
------------- --------------------- -----------
THE_BAD_USER  YES                             0
THE_GOOD_USER YES                             0
THE_BAD_API   NO                              9
THE_BAD_DATA  NO                              3
THE_GOOD_API  NO                              4
THE_GOOD_DATA NO                              3
THE_UGLY_DATA NO                             10
THE_UGLY_USER NO                              1
 
8 rows selected.

Just THE_GOOD_USER and THE_BAD_USER are ready to be used in the middle tier. To see the issues of all other users you may simply change the main part of the query as follows:

All rule 1 issues
-- main
SELECT * 
  FROM issues
 WHERE username LIKE 'THE%'
 ORDER BY username, owner, object_type, object_name;

USERNAME      OWNER         OBJECT_TYPE  OBJECT_NAME          ISSUE                                    
------------- ------------- ------------ -------------------- -----------------------------------------
THE_BAD_API   SYS           PRIVILEGE    CREATE DATABASE LINK Privilege is not part of the CONNECT role
THE_BAD_API   SYS           PRIVILEGE    CREATE PROCEDURE     Privilege is not part of the CONNECT role
THE_BAD_API   THE_BAD_API   JAVA CLASS   C                    Connect user must not own any object     
THE_BAD_API   THE_BAD_API   JAVA SOURCE  C                    Connect user must not own any object     
THE_BAD_API   THE_BAD_API   PACKAGE      PKG                  Connect user must not own any object     
THE_BAD_API   THE_BAD_API   PACKAGE      PKG2                 Connect user must not own any object     
THE_BAD_API   THE_BAD_API   PACKAGE BODY PKG                  Connect user must not own any object     
THE_BAD_API   THE_BAD_API   PACKAGE BODY PKG2                 Connect user must not own any object     
THE_BAD_API   THE_BAD_DATA  TABLE        T                    Access to non-PL/SQL unit                
THE_BAD_DATA  SYS           PRIVILEGE    CREATE TABLE         Privilege is not part of the CONNECT role
THE_BAD_DATA  THE_BAD_DATA  INDEX        SYS_C0012875         Connect user must not own any object     
THE_BAD_DATA  THE_BAD_DATA  TABLE        T                    Connect user must not own any object     
THE_GOOD_API  SYS           PRIVILEGE    CREATE PROCEDURE     Privilege is not part of the CONNECT role
THE_GOOD_API  THE_GOOD_API  PACKAGE      PKG                  Connect user must not own any object     
THE_GOOD_API  THE_GOOD_API  PACKAGE BODY PKG                  Connect user must not own any object     
THE_GOOD_API  THE_GOOD_DATA TABLE        T                    Access to non-PL/SQL unit                
THE_GOOD_DATA SYS           PRIVILEGE    CREATE TABLE         Privilege is not part of the CONNECT role
THE_GOOD_DATA THE_GOOD_DATA INDEX        SYS_C0012873         Connect user must not own any object     
THE_GOOD_DATA THE_GOOD_DATA TABLE        T                    Connect user must not own any object     
THE_UGLY_DATA SYS           PRIVILEGE    CREATE CLUSTER       Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE INDEXTYPE     Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE OPERATOR      Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE PROCEDURE     Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE SEQUENCE      Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE TABLE         Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE TRIGGER       Privilege is not part of the CONNECT role
THE_UGLY_DATA SYS           PRIVILEGE    CREATE TYPE          Privilege is not part of the CONNECT role
THE_UGLY_DATA THE_UGLY_DATA INDEX        SYS_C0012877         Connect user must not own any object     
THE_UGLY_DATA THE_UGLY_DATA TABLE        T                    Connect user must not own any object     
THE_UGLY_USER THE_UGLY_DATA TABLE        T                    Access to non-PL/SQL unit                

30 rows selected.

THE_UGLY_USER has access to table T owned by THE_UGLY_DATA. This violates rule 1.

However, it is important to note, that we have excluded all Oracle maintained users from the analysis. So let’s have a look at all the tables and views granted to PUBLIC by the Oracle-maintained users.

Privileges on tables and views granted to PUBLIC
WITH
   public_privs AS (
      SELECT p.owner, 
             p.type       AS object_type, 
             p.privilege, 
             count(*)     AS priv_count
        FROM dba_tab_privs p
       WHERE p.grantee = 'PUBLIC'
         AND p.type IN ('VIEW', 'TABLE')
         AND p.owner IN (
                SELECT u2.username 
                  FROM dba_users u2 
                 WHERE u2.oracle_maintained = 'Y'
             )
       GROUP BY p.owner, p.type, p.privilege  
   ),
   public_privs_pivot AS (
      SELECT owner,
             object_type,
             insert_priv,
             update_priv,
             delete_priv,
             select_priv, -- allows SELECT ... FOR UPDATE ...
             read_priv,   -- does not allow SELECT ... FOR UPDATE ...
             flashback_priv,
             nvl(insert_priv,0) + nvl(update_priv,0) + nvl(delete_priv,0) 
             + nvl(select_priv,0) + nvl(read_priv,0) 
             + nvl(flashback_priv,0) AS total_priv
        FROM public_privs
       PIVOT (
                sum(priv_count) FOR privilege IN (
                   'INSERT'    AS insert_priv, 
                   'UPDATE'    AS update_priv, 
                   'DELETE'    AS delete_priv, 
                   'SELECT'    AS select_priv, 
                   'READ'      AS read_priv, 
                   'FLASHBACK' AS flashback_priv
                )
             )
       ORDER BY owner
   ),
   public_privs_report AS (
      SELECT owner,
             object_type,
             sum(insert_priv)    AS "INSERT",
             sum(update_priv)    AS "UPDATE",
             sum(delete_priv)    AS "DELETE",
             sum(select_priv)    AS "SELECT",
             sum(read_priv)      AS "READ",
             sum(flashback_priv) AS "FLASHBACK",
             sum(total_priv)     AS "TOTAL"
        FROM public_privs_pivot
       GROUP BY ROLLUP(owner, object_type)
      HAVING (GROUPING(owner), GROUPING(object_type)) IN ((0,0), (1,1))
       ORDER BY owner, object_type
   )
-- main
SELECT * FROM public_privs_report;

OWNER             OBJECT_TYPE     INSERT     UPDATE     DELETE     SELECT       READ  FLASHBACK      TOTAL
----------------- ----------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
APEX_050100       VIEW                 1          1          4          5        192                   203
CTXSYS            TABLE                                                 1          4                     5
CTXSYS            VIEW                11          5          8         12         51                    87
GSMADMIN_INTERNAL VIEW                                                             3                     3
LBACSYS           VIEW                                                            18                    18
MDSYS             TABLE               21         14         19         21         36                   111
MDSYS             VIEW                27         26         26         26         68                   173
OLAPSYS           VIEW                                                            18                    18
ORDDATA           VIEW                                       1                     5                     6
ORDSYS            VIEW                                                             5                     5
ORDS_METADATA     VIEW                                                 20                               20
SYS               TABLE               21         10         16         30         12                    89
SYS               VIEW                                                  1       1717          2       1720
SYSTEM            TABLE                3          3          3          4                               13
SYSTEM            VIEW                                                  1                                1
WMSYS             VIEW                                                            40                    40
XDB               TABLE                8          6          8          8         14                    44
XDB               VIEW                 2          2          2          2          3                    11
                                      94         67         87        131       2186          2       2567

19 rows selected.

Even THE_GOOD_USER has access to 2317 views and tables. To reduce this number we have to uninstall some components, but that’s just a drop in the ocean. There is currently no way to create an Oracle user without access to views and tables. Hence we just have to focus on our application and our data.

Rule 2) Use only static SQL within PL/SQL

If you use just static SQL in your PL/SQL units, then no SQL injection is possible. The absence of dynamic SQL proves that your application is secured against SQL injection attacks. Of course, there are good reasons for dynamic SQL. However, proving that a dynamic SQL is not injectable is difficult. Checking for the absence of dynamic SQL is the simpler approach, even if it is not as easy as I initially thought.

In How to write SQL injection proof PL/SQL the following ways are mentioned to implement dynamic SQL:

  • native dynamic SQL (EXECUTE IMMEDIATE)
  • DBMS_SQL.EXECUTE
  • DBMS_SQL.PARSE
  • DBMS_UTILITY.EXEC_DDL_STATEMENT
  • DBMS_DDL.CREATE_WRAPPED
  • DBMS_HS_PASSTHROUGH.EXECUTE_IMMEDIATE
  • DBMS_HS_PASSTHROUGH.PARSE
  • OWA_UTIL.BIND_VARIABLES
  • OWA_UTIL.LISTPRINT
  • OWA_UTIL.TABLEPRINT

But there are more ways to execute dynamic SQL, such as:

  • Open-For Statement
  • Java Stored Procedure
  • DBMS_SYS_SQL.EXECUTE
  • DBMS_SYS_SQL.PARSE
  • DBMS_SYS_SQL.PARSE_AS_USER

It’s difficult to get a complete list because the Oracle-supplied subprograms are wrapped and often the SQL statement is hidden behind a C API. That leaves us with two options

  1. Use a list of Oracle-supplied packages and/or subprograms to identify dynamic SQL, even if the list might be incomplete
  2. Suspect that any Oracle-supplied subprogram may contain dynamic SQL, except some trusted packages such as “DBMS_STANDARD” and “STANDARD”

Both options are not very appealing. But I’m in favour of option 1. At a certain point, I have to focus on my application code and assume/trust, that the Oracle-supplied packages are doing their part to reduce the risk of SQL injection.

The following object types may contain PL/SQL and have to be checked for dynamic SQL:

  • FUNCTION
  • PROCEDURE
  • PACKAGE BODY
  • TYPE BODY
  • TRIGGER

What if we call services outside of the database via REST calls or AQ messages? I think we may ignore these cases. They are not part of this application any more and even if the services call this database, they have to go through the hard shell, and these are PL/SQL units already covered.

We need PL/Scope metadata for some checks. The following anonymous PL/SQL block produces these data. Be aware that the application code and some SYS objects are compiled. Invalid, dependent objects will be recompiled at the end. Nonetheless, you should not run this code in your production environment.

Compile missing PL/Scope metadata
DECLARE
   PROCEDURE enable_plscope IS
   BEGIN
      EXECUTE IMMEDIATE q'[ALTER SESSION SET plscope_settings='IDENTIFIERS:ALL, STATEMENTS:ALL']';
   END enable_plscope;
   --
   PROCEDURE compile_defs_without_plscope IS
   BEGIN
      <<compile_definition>>
      FOR r IN (
         WITH
            -- application users in scope of the analysis
            -- other users are treated as if they were not istalled
            app_user AS (
               SELECT username
                 FROM dba_users
                WHERE oracle_maintained = 'N'
            ),
            -- objects for which PL/Scope metadata is required
            obj AS (
                SELECT o.owner, o.object_type, o.object_name
                  FROM dba_objects o
                 WHERE object_name IN ('DBMS_UTILITY', 'OWA_UTIL')
                   AND object_type IN ('PACKAGE', 'SYNONYM')
               UNION ALL
               SELECT o.owner, o.object_type, o.object_name
                 FROM dba_objects o
                 JOIN app_user u ON u.username = o.owner
                WHERE object_type IN ('PACKAGE BODY', 'TYPE BODY', 'FUNCTION', 
                         'PROCEDURE', 'TRIGGER')
            ),
            -- objects without PL/Scope metadata
            missing_plscope_obj AS (
               SELECT o.owner, o.object_type, o.object_name
                 FROM obj o
                 LEFT JOIN dba_identifiers i 
                   ON i.owner = o.owner 
                      AND i.object_type = o.object_type
                      AND i.object_name = o.object_name
                      AND i.usage_context_id = 0
                WHERE i.usage_context_id IS NULL
            ),
            -- all objects to recompile and (re)gather PL/Scope metadata
            compile_scope AS (
               SELECT o.owner, o.object_type, o.object_name
                 FROM obj o
                WHERE EXISTS (
                         SELECT 1
                           FROM missing_plscope_obj o2 
                          WHERE o2.owner = 'SYS' 
                      )
               UNION ALL
               SELECT owner, object_type, object_name
                 FROM missing_plscope_obj
                WHERE NOT EXISTS (
                         SELECT 1
                           FROM missing_plscope_obj o2 
                          WHERE o2.owner = 'SYS' 
                      )
            ),
            -- compile statement required to produce PL/Scope metadata
            compile_stmt AS (
               SELECT 'ALTER ' || replace(object_type, ' BODY') 
                      || ' "' || owner || '"."' || object_name || '" COMPILE' 
                      || CASE
                            WHEN object_type LIKE '%BODY' THEN
                               ' BODY'
                         END AS stmt
                 FROM compile_scope
            )
         -- main
         SELECT stmt
           FROM compile_stmt
      ) LOOP
         EXECUTE IMMEDIATE r.stmt;
      END LOOP compile_definition;
   END compile_defs_without_plscope;
   --
   PROCEDURE recompile_invalids IS
   BEGIN
      <<schemas_with_invalids>>
      FOR r IN (
         SELECT DISTINCT owner
           FROM dba_objects
          WHERE status != 'VALID'
          ORDER BY CASE owner
                      WHEN 'SYS' THEN
                         1
                      WHEN 'SYSTEM' THEN
                         2
                      ELSE
                         3
                   END,
                owner
      ) LOOP
         utl_recomp.recomp_serial(r.owner);
      END LOOP schemas_with_invalids;
   END recompile_invalids;
BEGIN
   enable_plscope;
   compile_defs_without_plscope;
   recompile_invalids;
END;
/

Here’s the query to check application users.

Users secured against SQL injection attacks
WITH
   app_user AS (
      SELECT username
        FROM dba_users
       WHERE oracle_maintained = 'N'
   ),
   obj AS (
      SELECT o.owner, o.object_type, o.object_name
        FROM dba_objects o
        JOIN app_user u ON u.username = o.owner
       WHERE object_type IN ('PACKAGE BODY', 'TYPE BODY', 'FUNCTION', 'PROCEDURE', 'TRIGGER')
   ),
   missing_plscope_obj AS (
      SELECT o.owner, o.object_type, o.object_name
        FROM obj o
        LEFT JOIN dba_identifiers i
          ON i.owner = o.owner
             AND i.object_type = o.object_type
             AND i.object_name = o.object_name
             AND i.usage_context_id = 0
       WHERE i.usage_context_id IS NULL
   ),
   stmt AS (
      SELECT s.owner, s.object_type, s.object_name, s.type, s.line, s.col
        FROM dba_statements s
        JOIN app_user u ON u.username = s.owner
       WHERE s.type IN ('EXECUTE IMMEDIATE', 'OPEN')
   ),
   dep AS (
      SELECT d.owner, d.name as object_name, d.type as object_type, d.referenced_name
        FROM dba_dependencies d
        JOIN app_user u ON u.username = d.owner
       WHERE d.referenced_name IN (
                'DBMS_SQL', 'DBMS_DDL', 'DBMS_HS_PASSTHROUGH', 'DBMS_SYS_SQL'
             )
   ),
   issues AS (
      SELECT owner, 
             object_type, 
             object_name, 
             type AS potential_sqli_risk
        FROM stmt
       WHERE type = 'EXECUTE IMMEDIATE'
      UNION
      SELECT stmt.owner, 
             stmt.object_type, 
             stmt.object_name, 
             'OPEN-FOR WITH DYNAMIC SQL'
        FROM stmt
        JOIN dba_source src
          ON src.owner = stmt.owner
             AND src.type = stmt.object_type
             AND src.name = stmt.object_name
             AND src.line = stmt.line
       WHERE stmt.type = 'OPEN'
         AND regexp_substr(substr(src.text, stmt.col), '^open\s+', 1, 1, 'i') IS NULL
         AND regexp_substr(substr(src.text, stmt.col), '^("?\w+"?|q?'')', 1, 1, 'i') IS NOT NULL
      UNION
      SELECT owner, 
             object_type, 
             object_name, 
             referenced_name
        FROM dep
      UNION
      SELECT i.owner, 
             i.object_type, 
             i.object_name, 
             r.object_name || '.' || r.name 
        FROM dba_identifiers i
        JOIN app_user u ON u.username = i.owner
        JOIN dba_identifiers r
          ON r.signature = i.signature
             AND r.usage = 'DECLARATION'
       WHERE i.usage = 'CALL'
         AND r.owner = 'SYS'
         AND r.object_type = 'PACKAGE'
         AND (r.object_name, r.name) IN (
                ('DBMS_UTILITY', 'EXEC_DDL_STATEMENT'),
                ('OWA_UTIL', 'BIND_VARIABLES'),
                ('OWA_UTIL', 'LISTPRINT'),
                ('OWA_UTIL', 'TABLEPRINT')
             )
      UNION
      SELECT o.owner, 
             o.object_type, 
             o.object_name, 
             'SQL FROM JAVA SUSPECTED'
        FROM dba_objects o
        JOIN app_user u ON u.username = o.owner
       WHERE o.object_type = 'JAVA CLASS'
      UNION
      SELECT owner, 
             object_type, 
             object_name, 
             'PL/SCOPE METADATA MISSING'
        FROM missing_plscope_obj
   ),
   issue_aggr AS (
      SELECT u.username AS owner, COUNT(i.owner) issue_count
        FROM app_user u
        LEFT JOIN issues i ON i.owner = u.username
       GROUP BY u.username
   ),
   summary AS (
      SELECT owner,
             CASE
                WHEN issue_count = 0 THEN
                   'YES'
                ELSE
                   'NO'
             END AS is_user_sql_injection_free,
             issue_count
        FROM issue_aggr
       ORDER BY is_user_sql_injection_free DESC, owner
   )
-- main
SELECT * 
  FROM summary
 WHERE owner LIKE 'THE%';
 
OWNER         IS_USER_SQL_INJECTION_FREE ISSUE_COUNT
------------- -------------------------- -----------
THE_BAD_DATA  YES                                  0
THE_BAD_USER  YES                                  0
THE_GOOD_API  YES                                  0
THE_GOOD_DATA YES                                  0
THE_GOOD_USER YES                                  0
THE_UGLY_DATA YES                                  0
THE_UGLY_USER YES                                  0
THE_BAD_API   NO                                   9
 
8 rows selected.

To see the issues of THE_BAD_API you may simply change the main part of the query as follows:

All rule 2 issues
-- main
SELECT * 
  FROM issues
 WHERE owner LIKE 'THE%';
 
OWNER         OBJECT_TYPE   OBJECT_NAME POTENTIAL_SQLI_RISK                     
------------- ------------- ----------- ----------------------------------------
THE_BAD_API   JAVA CLASS    C           SQL FROM JAVA SUSPECTED                 
THE_BAD_API   PACKAGE BODY  PKG         EXECUTE IMMEDIATE                       
THE_BAD_API   PACKAGE BODY  PKG2        DBMS_DDL                                
THE_BAD_API   PACKAGE BODY  PKG2        DBMS_SQL                                
THE_BAD_API   PACKAGE BODY  PKG2        DBMS_SYS_SQL                            
THE_BAD_API   PACKAGE BODY  PKG2        DBMS_UTILITY.EXEC_DDL_STATEMENT         
THE_BAD_API   PACKAGE BODY  PKG2        EXECUTE IMMEDIATE                       
THE_BAD_API   PACKAGE BODY  PKG2        OPEN-FOR WITH DYNAMIC SQL               
THE_BAD_API   PACKAGE BODY  PKG2        OWA_UTIL.LISTPRINT                      
 
9 rows selected.

To suspect that every JAVA CLASS uses SQL is not a very differentiated analysis result. Further Java-specific code analysis is necessary. However, the other results are reasonable.

Conclusion

In this blog post, I showed how to prove, that a PL/SQL application does not use dynamic SQL and therefore is secured against SQL injection attacks.

The use of dynamic SQL is automatically reduced in PL/SQL because it is easier and more efficient for a developer to deal with compile errors than runtime errors. But there are cases when static SQL is not possible or not efficient enough. In those cases, proper input validation is a necessity to mitigate the SQL injection risk (see also “Ensuring the safety of a SQL literal” in How to write SQL injection proof PL/SQL).

Views are often part of the API in applications I’m involved in. I like the power and the flexibility of these views. In fact, I’m very grateful that the Oracle database provides a view API for its data dictionary, which simplified the analysis for this blog post. But views come with a SQL injection risk. Moreover, the risk and responsibility are delegated to a certain extent to the developers using the database API. Hence, in the future, I will think twice before making views part of the API, but I will for sure not rule them out per se.

5 Comments

  1. blank Apoorv Jain says:

    Hi This is quite interesting and informative…but I am not sure how it will work with MVC architecture for ADF or other applications?

  2. […] How to Prove That Your SmartDB App Is Secure I’ve crafted a good, a bad and an ugly demo application. I installed these applications […]

Leave a Reply

Your email address will not be published. Required fields are marked *

This site uses Akismet to reduce spam. Learn how your comment data is processed.