Ilmar Kerm

Oracle, databases, Linux and maybe more

We have hundreds of developers who need access hundreds of application schemas, deployed to multiple locations. Data is sensitive and there is a requirement that each human access must be done via a personal database account that has access to only allowed application schemas. That has always been a struggle for me how to manage all these access privileges in a nice and easy way. Since many many many different databases are involved, database itself cannot be the source of truth for the access privileges and so far we have just synchronised the access privileges from the source of truth system to all individual databases.

I think there is a better way now – Secure Application Roles.

The idea behind them is very flexible – there is no need to grant the individual roles to database users, the users need to execute a procedure (which will do all necessary validations) and then enable the role(s) for the user session.

Lets first set up a common SECURITY_MANAGER schema, that will contain all our security related code and logging.

create user security_manager no authentication
  default tablespace users
  quota 1g on users;

grant create table, create procedure to security_manager;

create table security_manager.allowed_grants (
    db_username varchar2(128) not null,
    db_role varchar2(128) not null,
    primary key (db_username,db_role)
) organization index;

create table security_manager.role_grant_log (
    grant_time timestamp default sys_extract_utc(systimestamp) not null,
    db_username varchar2(128) not null,
    granted_role varchar2(128) not null,
    is_allowed number(1) not null,
    comments varchar2(1000),
    client_host varchar2(200),
    client_ip varchar2(50),
    unified_audit_session_id varchar2(100)
);

Here are two helper programs, since ACTIVATE_ROLE procedure below will need to read and write to tables in SECURITY_MANAGER schema and I do not want to grant access to these tables to users directly.

-- The job of the following procedure is just logging the grant request
CREATE OR REPLACE PROCEDURE security_manager.log_role_grant
    (p_requested_role role_grant_log.granted_role%TYPE
      , p_is_allowed role_grant_log.is_allowed%TYPE
      , p_comments role_grant_log.comments%TYPE) 
ACCESSIBLE BY (activate_role) IS
    PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
    INSERT INTO role_grant_log
      (db_username, granted_role, is_allowed, comments
        , client_host, client_ip, unified_audit_session_id)
    VALUES 
      (SYS_CONTEXT('USERENV','SESSION_USER')
       , p_requested_role, p_is_allowed, SYS_CONTEXT('USERENV','HOST')
       , SYS_CONTEXT('USERENV','IP_ADDRESS')
       , SYS_CONTEXT('USERENV','UNIFIED_AUDIT_SESSIONID'));
    COMMIT;
END;
/

-- The following function just check the master autorisation table if
-- user is allowed to activate the role or not
CREATE OR REPLACE FUNCTION security_manager.is_role_allowed
    (p_username allowed_grants.db_username%TYPE
      , p_requested_role role_grant_log.granted_role%TYPE) RETURN boolean
ACCESSIBLE BY (activate_role) IS
    v_is_role_allowed NUMBER;
BEGIN
    SELECT COUNT(*) INTO v_is_role_allowed
    FROM allowed_grants
    WHERE db_username = p_username AND db_role = UPPER(p_requested_role);
    RETURN v_is_role_allowed = 1;
END;
/

Now the security code itself. The procedure below just checks from a simple table, if the logged in user is allowed to activate the requested role or not and also logs the request. In real life it can be much more complex – the code could make a REST call to external autorisation system and ofcourse logging should be much more detailed.

NB! The procedure must be declared AUTHID CURRENT_USER – using invokers rights.

CREATE OR REPLACE PROCEDURE security_manager.activate_role
    (p_requested_role allowed_grants.db_role%TYPE
    , p_comments role_grant_log.comments%TYPE)
AUTHID CURRENT_USER IS
    v_activated_roles VARCHAR2(4000);
BEGIN
    -- Check if users is allowd to activate the requested role
    IF NOT is_role_allowed(SYS_CONTEXT('USERENV','SESSION_USER'), p_requested_role) THEN
        log_role_grant(upper(p_requested_role), 0, p_comments);
        raise_application_error(-20000, 'You are not allowed to activate the requested role.');
    END IF;
    -- Query all roles that are currently active for the session and append the requested role to that list
    SELECT listagg(role, ',') WITHIN GROUP (ORDER BY role) INTO v_activated_roles FROM (
        SELECT role FROM session_roles
        UNION
        SELECT upper(p_requested_role) FROM dual
    );    
    -- Activate all roles
    log_role_grant(upper(p_requested_role), 1, p_comments);
    DBMS_SESSION.SET_ROLE(v_activated_roles);
END;
/

Now I create the role itself and grant the role read access to one application table. Here IDENTIFIED USING clause does the magic – it tells Oracle that sec_app_role_test1 role can only be enabled by security_manager.activate_role procedure.

CREATE ROLE sec_app_role_test1
    IDENTIFIED USING security_manager.activate_role;

GRANT READ ON app1.t1 TO sec_app_role_test1;

And my developer personal account is called ILMKER and this account only needs execute privileges on my security package. In real life you would grant this execute to a common role that all developers have (in my case that custom role is called PERSONAL_ACCOUNT).

GRANT execute ON security_manager.activate_role TO ilmker;

By default ILMKER user cannot access table APP1.T1.

ILMKER SQL> SELECT * FROM session_roles;

ROLE                                                                                                                            
-----------------
PERSONAL_ACCOUNT

ILMKER SQL> SELECT * FROM app1.t1;

SQL Error: ORA-00942: table or view does not exist

Lets test using my developer account ILMKER… first I try to request a role that I do not have been granted access to. No luck, I get the exception “ORA-20000: You are not allowed to activate the requested role.”

SQL> SELECT * FROM session_roles;

ROLE                
--------------------
PERSONAL_ACCOUNT

SQL> exec security_manager.activate_role('sec_app_role_test1', 'Jira ref: ABC-490');

ORA-20000: You are not allowed to activate the requested role.

SQL> SELECT * FROM session_roles;

ROLE                
--------------------
PERSONAL_ACCOUNT

SQL> SELECT * FROM app1.t1;

SQL Error: ORA-00942: table or view does not exist

After security administrator grants me the role – inserts a row to security_manager.allowed_grants table for this example and NOT executing Oracle GRANT command.

insert into security_manager.allowed_grants (db_username, db_role)
    values ('ILMKER', upper('sec_app_role_test1'));
commit;

I ask my developer to run again.

SQL> SELECT * FROM session_roles;

ROLE                
--------------------
PERSONAL_ACCOUNT

SQL> exec security_manager.activate_role('sec_app_role_test1', 'Jira ref: ABC-490');

PL/SQL procedure successfully completed.

SQL> SELECT * FROM session_roles;

ROLE                
--------------------
PERSONAL_ACCOUNT
SEC_APP_ROLE_TEST1

SQL> SELECT * FROM app1.t1;
no rows selected

The developer is happy now! Role was activated in the developer session and developer was able to read the application table. All requests were also logged by SECURITY_MANAGER schema.

SQL> select * from security_manager.role_grant_log;

GRANT_TIME                       DB_USERNAME    GRANTED_ROLE          CLIENT_HOST         CLIENT_IP       UNIFIED_AUDIT_SESSION_ID    IS_ALLOWED    COMMENTS             
2023-05-12 15:05:28,478732000    ILMKER         SEC_APP_ROLE_TEST1    STH-FVFFV04QQ05R    10.88.17.241    3428220339                              0 Jira ref: ABC-490    
2023-05-12 15:10:41,923908000    ILMKER         SEC_APP_ROLE_TEST1    STH-FVFFV04QQ05R    10.88.17.241    3428220339                              1 Jira ref: ABC-490

I think this is a powerful feature to control access to data based on much more complex criteria than just DBA executing GRANT commands. Before enabling the role code can make a REST query to external autorisation system, check the client host IP, check the client authentication method, enable detailed unified auditing policies. Possibilities are endless!