Oracle – Security Setup
I had a client ask me last week to change up all the oracle – security setup in their production Oracle Database. The cleanup was relatively straightforward because we only use the basic accounts for the PeopleSoft environment and all the passwords had been changed since going live so there was very little risk to the environment, but they wanted to be safe so:
PeopleSoft Default Accounts: Access-Id, this account is typically by default sysadm, however you can define this account to be pretty much any name, it just needs to ensure that it is an 8-digit id and even though Oracle says the password can be greater, I highly recommend the password be 8 digits and make sure not to include any funky characters (we have seen all sorts of issues with this password being anything special). The next account we need to ensure it is working correctly is the Connect-Id, this account is used for authentication purposes with PeopleSoft. This account has a base of 3 tables it can select data from, PSOPRDEFN, PSACCESSPRFL, PSSTATUS. As of PeopleTools 8.55, an additional grant for select is on table PSACCESSPROFILE which basically replaces PSACCESSPRFL and supposedly supports passwords up to 30 characters. The next account you will see is the PS account, this account is created when the environment is built and contains an table PS.PSDBOWNER that shows the database name with the schema owner for that database. The PS account is not allowed to be connected to. The last two accounts you should have be default are SYS & SYSTEM, neither of which should be accessed by anybody expect your DBA.
The first major item is that they wanted the dba’s to have dedicated accounts instead of using the sysadm account. So to do this:
In SQL*Plus:
create user dbauser1 identified by dbapassword1 ;
grant create session, grant any privilege to dbauser1;
grant connect, resource, dba to dbauser1;
grant unlimited tablespace to dbauser1;
All the work the dbauser1 needs to do is in the sysadm schema, but when it logs in it will default to the schema dbauser1. So to fix this, we build a trigger to execute a call to switch the current schema on login:
In SQL*Plus:
CREATE OR REPLACE TRIGGER LOGIN_SCHEMA
AFTER LOGON ON DATABASE WHEN (USER in (‘DBAUSER1′,’DBAUSER2’))
DECLARE
exsql VARCHAR2(100);
BEGIN
exsql := ‘ALTER SESSION SET CURRENT_SCHEMA = SYSADM’;
EXECUTE IMMEDIATE exsql;
END;
/
In order to troubleshoot the environment we had created a sysadm_read account which had the role sysadm_read_only, which has select access to all PS tables in the SYSADM schema. This account was shared by multiple users for data validation. It was determined that they wanted to have dedicated accounts for each user and they wanted to have a higher level of password security so this is where things go creative.
The first element that I want to enable is a better level of password security. Oracle has delivered password verify functions which can be applied to the environment quickly and easily. You will want to modify the script to ensure that it affects the correct profile for your environment. The script is: utlpwdmg.sql which for Oracle 12c introduced two functions ora12c_verify_function and ora12c_strong_verify_function. For my example I went with the ora12c_verify_function that more than meets the minimum requirements for the client. So now we create a new profile for the database users:
In SQL*Plus:
create profile sysadm_read_only limit
failed_login_attempts 3
password_lock_time 1
password_life_time 90
password_reuse_max 3
PASSWORD_VERIFY_FUNCTION ora12c_verify_function ;
This creates a new profile that allows for only 3 failed login attempts, if the user fails all 3 times the account is locked out for 1 day. Password is valid for 90 days, and can only be used every 4th time it is changed, and the password verification as at least 8 characters, at least 1 letter, at least 1 digit, must not contain database name, must not contain user name or reverse user name, must not contain oracle, must not be too simple like welcome1, and must differ by at least 3 characters from the old password (ora12c_verify_function).
Now we just need to create the new users with the sysadm_read_role:
In SQL*Plus:
create user readuser1 identified by readpassword password expire profile sysadm_read_only;
grant sysadm_read_role to readuser1;
grant connect to readuser1;
Now when the user logs into the environment they will be required to change their password and they will have read only access to the sysadm schema. We have stored procedure that is scheduled to run nightly that grants select access to all PS tables in the sysadm schema and creates public synonyms for each one so that the read only users can select from the PS tables. The grants are done to the sysadm_read_role Role.