Ilmar Kerm

Oracle, databases, Linux and maybe more

We have hundreds of developers who need access to production database for incident management purposes. But we don’t want to use shared accounts to access the database, each user has their own access to the database that is audited and has privileges according to the users access level.
Managing all these users manually on Oracle Database side is just too much, especially that all their access details are already described in Active Directory. Wouldn’t it be nice if we can just syncronise the AD users to the database side? Luckily we have an Ansible module for this task.

First, on the database side need to create a dedicated profile for the syncronised users:

CREATE PROFILE ldap_user LIMIT password_life_time UNLIMITED;

I assume you are already familiary with Ansible, so I’ll go straight to the point.
First you need to clone the ansible-oracle-modules to your playbook directory:

git clone https://github.com/oravirt/ansible-oracle-modules library

This contains, among other goodies, a module that does exactly what is required 🙂 The module is called oracle_ldapuser.
This module requires extra python-ldap module to be installed. Install it using yum, not pip. Pip will install wrong version.

yum install python-ldap

The playbook looks like this:

Remember that it is a syncronisation, so new users are created and removed when the playbook is run.

My use case for this: one big database, where applications have some shemas. But also, quite a lot of developers need access to the database, to see the production data and security requires each user to have his/her own personal account and of course also requires password expiration and complexity. Authenticating database users against organizations central Active Directory would be just perfect for this case.

Oracle offers this solution for Enterprise Edition, but its an extra cost option – Oracle Advanced Security. If these are not an option for you, then its also possible to achieve the same task, in its simplest form, using user profile password verification function and database logon trigger.

Update: Thanks to Job Miller for pointing out that password authentication does not require licensing ASO option anymore, but requires licensing Oracle Internet Directory: Link to 10.2 Oracle® Database Licensing Information – 2 Options and Packs

Basically, the procedure works as follows:

  • Create a new profile for AD-authenticated users with password verification function.
  • Assign this new profile to a database user.
  • When the database user changes password, the password verification function will try to connect to AD with the user specified password, if AD authentication is successful, then the password is correct and can be changed and stored by Oracle.
  • Every time the user connects to the database, after logon trigger will query AD for the user status: does the user still exist, is the user disabled or expired, when did the user last change password. If the user status is changed in AD, the trigger will lock or expire the database user accordingly.

The code

My solution consists of a PL/SQL package, that I create under my database administration account, named DBAUSER. The package will be called from password verification function and the logon trigger. The DBAUSER account needs network ACLs to permit it to connect to the AD server (11g+!) and the following system privileges:

GRANT create job TO dbauser;
GRANT alter user TO dbauser;
GRANT select ON sys.user$ TO dbauser;

Now the package:

NB! Look into the package body script! There are configuration parameters on top, that you MUST look over and change!

Now, create the password verification function under SYS schema, that will only call out the created package:

CREATE OR REPLACE FUNCTION sys.ad_profile_verify_function
  (username varchar2, password varchar2, old_password varchar2)
  RETURN boolean IS
BEGIN
  RETURN DBAUSER.PROFILE_AD_AUTH.VERIFY_PASSWORD(username, password);
END;
/

Next, create a new profile setting the password verification function and also would be good to set parameter PASSWORD_LIFE_TIME to the same value AD has for password expiration. An example profile:

CREATE PROFILE ad_user LIMIT 
SESSIONS_PER_USER 2 
FAILED_LOGIN_ATTEMPTS 4
PASSWORD_LIFE_TIME 90
PASSWORD_VERIFY_FUNCTION ad_profile_verify_function;

And finally the logon trigger, that will fire the user verification function for all users having the ad_user profile. Modify it for your own needs before executing. The following procedure also needs SELECT privilege on SYS.DBA_USERS granted to SYSTEM.

GRANT execute ON dbauser.profile_ad_auth TO system;

CREATE OR REPLACE TRIGGER system.AD_USER_LOGON AFTER LOGON ON DATABASE
DECLARE
  i NUMBER;
BEGIN
  IF user NOT IN ('SYS','SYSTEM','APPUSER1','APPUSER2') and sys_context('USERENV','AUTHENTICATION_METHOD') = 'PASSWORD' THEN
    -- Check if user belongs to a specific profile
    SELECT count(*) INTO i 
    FROM sys.dba_users
    WHERE username = user AND profile = 'AD_USER';
    -- Execute verification procedure
    IF i > 0 THEN
      dbauser.profile_ad_auth.verify_user(user);
    END IF;
  END IF;
END;
/

To create a user that will be authenticated from AD, first create a regular user with a temporary password, then issue ALTER USER to set the profile. This is needed because if profile is set in CREATE USER command, then the initial password will also be validated with the verification function.

CREATE USER ilmar IDENTIFIED BY test123;
ALTER USER ilmar PROFILE ad_user PASSWORD EXPIRE;

NB! 10g passwords are not case sensitive, so subsequent logins will be allowed with passwords using the wrong case. In 11g, be sure to enable initialization parameter SEC_CASE_SENSITIVE_LOGON, to benefit from case sensitive passwords.

I have not yet used it in production, so all feedback is welcome! I’ve tested the code on 10.2 EE and 11.2 EE, should work on standard edition also.

Update: Take a look at Oracle-L mailing list thread about the same subject: Click here.

Update: SQL Developer supports changing password when OCI/Thick driver is used. To make it easier for users, set g_expired_password parameter to not null value. In this case users do not need to remember their previous password and could use a known preset password.

Update: Due to differences in 11gR2 and 10g dbms_scheduler, I added ” and sys_context(‘USERENV’,’AUTHENTICATION_METHOD’) = ‘PASSWORD'” to logon trigger. So that the trigger is only executed when user is authenticated with password, not session created by scheduler.