rules repository

G-1120

🆓
Error

Avoid granting system privileges to connect users.

Reason

Database tables should be guarded behind an API. The connect user must not have privileges to access objects that are not part of the API, e.g. via SELECT ANY TABLE privileges or similar. As a result, the only system privilege a connect user requires is CREATE SESSION.

Example

Non-Compliant Example

grant connect, select any table to dbl_backend_role;

Compliant Solution - ★★★★★

grant create session to dbl_backend_role;

Tests

Test SQL query

with
   upriv as (
      -- system privileges granted to users
      select u.username, p.privilege as priv
        from dba_sys_privs p
       inner join dba_users u
          on u.username = p.grantee
      union all
      -- roles granted to users
      select u.username, p.granted_role as priv
        from dba_role_privs p
       inner join dba_users u
          on u.username = p.grantee
   ),
   rpriv as (
      -- roles without parent (=roots)
      select role as priv, null as parent_priv
        from dba_roles
       where role not in (
                select rrp.granted_role
                  from role_role_privs rrp
             )
      union all
      -- roles granted to roles
      select granted_role as priv,
             grantee as parent_priv
        from dba_role_privs
      union all
      -- system privileges granted to roles
      select privilege as priv,
             grantee as parent_priv
        from dba_sys_privs
       where grantee in (
                select r.role
                  from dba_roles r
             )
   ),
   rtree as (
      -- provides priv_path and is_leaf for every role/priv in the hierarchy
      select priv,
             parent_priv,
             sys_connect_by_path(priv, '/') || '/' as priv_path,
             case
                when connect_by_isleaf = '0' then
                   0
                else
                   1
             end as is_leaf
        from rpriv
     connect by prior priv = parent_priv
   ),
   rgraph as (
      -- provides per priv all its possible parent privs or in other words
      -- provides per parent priv all its possible child privs
      -- this allows to join with parent_priv to get all privs
      select priv,
             substr(priv_path, 2, instr(priv_path, '/', 2) - 2) as parent_priv,
             is_leaf
        from rtree
   ),
   ugraph as (
      -- extends the rgraph by users and their privs
      -- distinct is required since a priv can be part of multiple roles
      select distinct
             upriv.username,
             rgraph.priv,
             cast(rgraph.parent_priv as varchar2(128 byte)) as granted_priv,
             case
                when rgraph.priv = rgraph.parent_priv then
                   1
                else
                   0
             end as direct_grant,
             rgraph.is_leaf
        from upriv
        join rgraph
          on upriv.priv = rgraph.parent_priv
   )
-- main
select username || '.' || priv as identifier,
       'Connect user ' || username || ' has ' || priv || ' privilege.' as message
  from ugraph
 where username in (#ConnectUsers#)
   and priv not in (#AllowedSystemPrivileges#)
   and is_leaf = 1
 order by identifier

Test results

IdentifierMessageMigration
DBL_BACKEND.SELECT ANY TABLEConnect user DBL_BACKEND has SELECT ANY TABLE privilege.-
DBL_BACKEND.SET CONTAINERConnect user DBL_BACKEND has SET CONTAINER privilege.-

Parameters

Use parameters to customize the rule to your needs.

ParameterDescriptionDefault Value
ConnectUsersComma separated list of technical users connecting to the database. These users do not own database objects such as tables.dbl_gui, dbl_backend
AllowedSystemPrivilegesComma separated list of allowed system privileges for connect users.create session

References