Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

Oracle audit command tips

Oracle security Tips by Donald Burleson

Question:  Can I use the Oracle audit command to audit updates to an Oracle database?  What alternative are there for the Oracle audit table command?  Which audit tool is best?

Answer:  First, see my notes on the different types of Oracle auditing especially Oracle fine-grained auditing (FGA) and Oracle LogMiner.  For complete details on Oracle auditing, see my my book "Oracle Privacy Security Auditing", and you can buy Oracle at this link and get instant access to Oracle auditing scripts.

Also see my notes on auditing Oracle DML for selected tables.

Oracle auditing setup & configuration

The Oracle audit command is used to to create specific audit trails for Oracle tables.  to enable Oracle auditing you must set the initialization parameter "audit_trail = true" and run the cataudit.sql scripts (as SYS).

Also see ORA-01400: cannot insert NULL into ("SYS"."AUDIT_DDL"."DICT_OBJ_TYPE") tips

Auditing is a method of recording database activity as part of database security. It allows the DBA to track user activity within the database. The audit records will provide information on who performed what database operation and when it was performed. Records are written to a SYS-owned table named AUD$. The SYS.AUD$ (dba_audit_trail) and dba_fga_audit_trail) are commonly referred to as the audit trail.

It is advisable to copy the AUD$ table into a separate tablespace from other SYS-owned objects. In some cases, the AUD$ table should be owned by a user other than SYS. There are three reasons for these two statements:

* The AUD$ table, if auditing is used, may grow to a very large size, depending on the audit options selected.

* In some situations, you may want to add a trigger to the AUD$ table to count logins, monitor for specific actions (prior to 8i), or perform other security-related functions (such as implement password-checking functionality prior to version 8). Remember, you can't add triggers to catalog objects owned by SYS.

* Since the table will grow and shrink and be high activity, it is advisable to move it from the SYSTEM tablespace to avoid fragmentation.

Auditing information is not collected without some impact on performance and database resources. How much of an impact auditing will have on your system depends largely on the type of auditing you enable. For example, setting high-level auditing such as connection activity will not have as much of a performance impact as tracking all SQL statements issued by all users. It is best to start out with high-level auditing and then refine additional auditing as needed.

You can audit all users with the exception of SYS and CONNECT INTERNAL. Auditing can only be performed for users connected directly to the database, not for actions on a remote database.

Auditing should be enabled if the following types of questionable activities are noted:

* Unexplained changes in passwords, tablespace settings, or quotas appear.

* Excessive deadlocks are encountered.

* Records are being read, deleted, or changed without authorization.

There are three types of auditing:

* Statement auditing

* Privilege auditing

* Object auditing

Enabling and Disabling Auditing

The database initialization parameter AUDIT_TRAIL controls the enabling and disabling of auditing. The default setting for this parameter is NONE, which means that no auditing will be performed, regardless of whether or not AUDIT commands are issued. It is important to remember that any auditing statements issued will not be performed if AUDIT_TRAIL=NONE. Unless auditing is enabled in the database parameter initialization file, any auditing options that have been turned on will not create records in the audit trail. Auditing is not completely disabled unless it is set to NONE in the database parameter initialization file.

You must set the database initialization parameter AUDIT_TRAIL to DB or OS in order to enable auditing. The DB setting means the audit trail records are stored in the database in the SYS.AUD$ table. OS will send the audit trail records to an operating system file. The OS setting is operating system-dependent and is not supported on all operating systems.

 

Managing Oracle audit trails

The Oracle audit command write the audit information to specific data dictionary views.

BEWARE: These audit trail rows can quickly fill-up your SYSTEM tablespace, and special care needs to be taken to ensure that you do not "lock-up" your database, by filling the SYSTEM tablespace.  Check these tables:

  • dba_audit_exists

  • dba_audit_object

  • dba_audit_session

  • dba_audit_statement

  • dba_audit_trail

We also have these metadata views for Oracle auditing options:

  • dba_obj_audit_opts

  • dba_priv_audit_opts

  • dba_stmt_audit_opts

Auditing the audit trail

Today, we need to audit the audit trail itself to prevent "inside jobs" and this Oracle command will record all changes to the audit trail.  See my notes on the types of "inside jobs" and Oracle hackers horror stories:

   audit
      delete table,
      insert table,
      update table
   on
      mytable
   by access;

Auditing user activity with the Oracle audit command

Oracle has syntax for auditing specific user activity.  To audit the activity of user FRED we could issue these audit commands:

Audit all Oracle user activity. 

This audits everything including DDL (create table), DML (inserts, updates, deletes) and login/logoff events:

     audit all by FRED by access;

Audit all Oracle user viewing activity:

   audit select table by FRED by access;

Audit all Oracle user data change activity:

   audit update table, delete table,
      insert table by FRED by access;

Audit all Oracle user viewing activity:

   audit execute procedure by FRED by access;

We can also query the dba_audit_trail view.  Here are the column descriptions from the Oracle documentation:

 
Column Datatype NULL Description
OS_USERNAME VARCHAR2(255)   Operating system login username of the user whose actions were audited
USERNAME VARCHAR2(30)   Name (not ID number) of the user whose actions were audited
USERHOST VARCHAR2(128)   Client host machine name
TERMINAL VARCHAR2(255)   Identifier of the user's terminal
TIMESTAMP DATE   Date and time of the creation of the audit trail entry (date and time of user login for entries created by AUDIT SESSION) in the local database session time zone
OWNER VARCHAR2(30)   Creator of the object affected by the action
OBJ_NAME VARCHAR2(128)   Name of the object affected by the action
ACTION NUMBER NOT NULL Numeric action type code. The corresponding name of the action type is in the ACTION_NAME column.
ACTION_NAME VARCHAR2(28)   Name of the action type corresponding to the numeric code in the ACTION column
NEW_OWNER VARCHAR2(30)   Owner of the object named in the NEW_NAME column
NEW_NAME VARCHAR2(128)   New name of the object after a RENAME or the name of the underlying object
OBJ_PRIVILEGE VARCHAR2(16)   Object privileges granted or revoked by a GRANT or REVOKE statement
SYS_PRIVILEGE VARCHAR2(40)   System privileges granted or revoked by a GRANT or REVOKE statement
ADMIN_OPTION VARCHAR2(1)   Indicates whether the role or system privilege was granted with the ADMIN option
GRANTEE VARCHAR2(30)   Name of the grantee specified in a GRANT or REVOKE statement
AUDIT_OPTION VARCHAR2(40)   Auditing option set with the AUDIT statement
SES_ACTIONS VARCHAR2(19)   Session summary (a string of 16 characters, one for each action type in the order ALTER, AUDIT, COMMENT, DELETE, GRANT, INDEX, INSERT, LOCK, RENAME, SELECT, UPDATE, REFERENCES, and EXECUTE. Positions 14, 15, and 16 are reserved for future use. The characters are:
  • - - None
  • S - Success
  • F - Failure
  • B - Both
LOGOFF_TIME DATE   Date and time of user log off
LOGOFF_LREAD NUMBER   Logical reads for the session
LOGOFF_PREAD NUMBER   Physical reads for the session
LOGOFF_LWRITE NUMBER   Logical writes for the session
LOGOFF_DLOCK VARCHAR2(40)   Deadlocks detected during the session
COMMENT_TEXT VARCHAR2(4000)   Text comment on the audit trail entry, providing more information about the statement audited

Also indicates how the user was authenticated. The method can be one of the following:

  • DATABASE - Authentication was done by password
  • NETWORK - Authentication was done by Oracle Net Services or the Advanced Security option
  • PROXY - Client was authenticated by another user; the name of the proxy user follows the method type
SESSIONID NUMBER NOT NULL Numeric ID for each Oracle session
ENTRYID NUMBER NOT NULL Numeric ID for each audit trail entry in the session
STATEMENTID NUMBER NOT NULL Numeric ID for each statement run
RETURNCODE NUMBER NOT NULL Oracle error code generated by the action. Some useful values:
  • 0 - Action succeeded
  • 2004 - Security violation
PRIV_USED VARCHAR2(40)   System privilege used to execute the action
CLIENT_ID VARCHAR2(64)   Client identifier in each Oracle session
SESSION_CPU NUMBER   Amount of CPU time used by each Oracle session
EXTENDED_TIMESTAMP TIMESTAMP(6) WITH TIME ZONE   Timestamp of the creation of the audit trail entry (timestamp of user login for entries created by AUDIT SESSION) in UTC (Coordinated Universal Time) time zone
PROXY_SESSIONID NUMBER   Proxy session serial number, if an enterprise user has logged in through the proxy mechanism
GLOBAL_UID VARCHAR2(32)   Global user identifier for the user, if the user has logged in as an enterprise user
INSTANCE_NUMBER NUMBER   Instance number as specified by the INSTANCE_NUMBER initialization parameter
OS_PROCESS VARCHAR2(16)   Operating System process identifier of the Oracle process
TRANSACTIONID RAW(8)   Transaction identifier of the transaction in which the object is accessed or modified
SCN NUMBER   System change number (SCN) of the query
SQL_BIND NVARCHAR2(2000)   Bind variable data of the query
SQL_TEXT NVARCHAR2(2000)   SQL text of the query

This query by Arup Nanda, co-author of "Oracle Privacy Security Auditing", shows a sample query against dba_audit_trail for standard Oracle auditing.  You can download his complete set of auditing scripts when you buy his book.

select 'standard audit', sessionid,
    proxy_sessionid, statementid, entryid, extended_timestamp, global_uid,
    username, client_id, null, os_username, userhost, os_process, terminal,
    instance_number, owner, obj_name, null, new_owner,
    new_name, action, action_name, audit_option, transactionid, returncode,
    scn, comment_text, sql_bind, sql_text,
    obj_privilege, sys_privilege, admin_option, grantee, priv_used,
    ses_actions, logoff_time, logoff_lread, logoff_pread, logoff_lwrite,
    logoff_dlock, session_cpu
  from 
  dba_audit_trail;

This is just a tiny sample of the Oracle audit functionality and see the book "Oracle Privacy Security Auditing", for details and working scripts for Oracle auditing.
 

If you like Oracle tuning, see the book "Oracle Tuning: The Definitive Reference", with 950 pages of tuning tips and scripts. 

You can buy it direct from the publisher for 30%-off and get instant access to the code depot of Oracle tuning scripts.


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.