Thursday, February 14, 2013
job OS audit files maintaince
For Oracle on unix .aud files are created whether you have auditing enabled or not. They record sys operations. If you've got a lot of shell scripts that connect / as sysdba you are going to get a lot of .aud files. (In windows they are written to the event viewer)
They will go to where you set audit_file_dest (aka adump) to be. If you don't set adump the first default value is ORACLE_BASE/admin/ORACLE_SID/adump. If this doesn't exist then they will go in ORACLE_HOME/rdbms/audit
If you didn't know about this they tend to raise their heads when $ORACLE_HOME fills up and you wonder why.
Please be clear, I am talking about the OS .aud files. This process will not touch $aud in your database.
Oracle at 11.2 provide a way to manage these .aud OS files using the audit management package DBMS_AUDIT_MGMT
Here's how:
Initialize DBMS_AUDIT_MGMT
Call just once the initialization procedure INIT_CLEANUP to set up the audit management infrastructure.
BEGIN
DBMS_AUDIT_MGMT.INIT_CLEANUP(
AUDIT_TRAIL_TYPE => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS,
DEFAULT_CLEANUP_INTERVAL => 24 );
END;
/
Create the Procedure to delete files (over a year old) for a single instance
CREATE OR REPLACE procedure SYS.delete_OSaud_files
is
ThisProc VARCHAR2(30) := 'delete_OSaud_files';
ThisAppErr NUMBER := -20000;
BEGIN
DBMS_AUDIT_MGMT.set_last_archive_timestamp(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS,
last_archive_time => SYSTIMESTAMP-366);
dbms_audit_mgmt.clean_audit_trail(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS,
use_last_arch_timestamp => TRUE
);
EXCEPTION
WHEN OTHERS THEN
dbms_output.put_line(ThisProc||' - '||SQLERRM);
ROLLBACK;
RAISE_APPLICATION_ERROR(ThisAppErr, ThisProc);
END;
/
Create the Procedure to delete files (over a year old) for RAC
CREATE OR REPLACE procedure SYS.delete_OSaud_files
is
ThisProc VARCHAR2(30) := 'delete_OSaud_files';
ThisAppErr NUMBER := -20000;
BEGIN
DBMS_AUDIT_MGMT.set_last_archive_timestamp(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS,
last_archive_time => SYSTIMESTAMP-366,
rac_instance_number => 1);
DBMS_AUDIT_MGMT.set_last_archive_timestamp(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS,
last_archive_time => SYSTIMESTAMP-366,
rac_instance_number => 2);
dbms_audit_mgmt.clean_audit_trail(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS,
use_last_arch_timestamp => TRUE);
EXCEPTION
WHEN OTHERS THEN
dbms_output.put_line(ThisProc||' - '||SQLERRM);
ROLLBACK;
RAISE_APPLICATION_ERROR(ThisAppErr, ThisProc);
END;
/
If you don't need to keep a years worth, just change SYSTIMESTAMP-366
Feel free to moan at me about 'when others then' and post a better procedure in the comments - I'll readily admit my plsql is not what it should be and I'm happy to be corrected.
Create a Schedule
(I like this type of thing to run when I'm actually working so I don't get called out of hours if something goes wrong)
Begin
DBMS_SCHEDULER.CREATE_SCHEDULE (
schedule_name => 'DELETE_OSAUD_FILES_SCHED',
repeat_interval =>'FREQ=DAILY; BYDAY=MON,TUE,WED,THU,FRI; BYHOUR=10;',
comments => 'Delete adump files');
END;
/
Schedule the Job
BEGIN
dbms_scheduler.create_job (
job_name =>'DELETE_OSAUD_FILES_JOB',
job_type =>'STORED_PROCEDURE',
job_action => 'SYS.delete_OSaud_files',
enabled => TRUE,
auto_drop => false,
schedule_name => 'DELETE_OSAUD_FILES_SCHED',
comments => 'Remove aud files from adump');
END;
/
Set up mail notifications
(I like to know when my jobs error)
BEGIN
DBMS_SCHEDULER.set_scheduler_attribute('email_server', 'smtp.mycompany.com:25');
DBMS_SCHEDULER.set_scheduler_attribute('email_sender', 'do_not_reply@mydatabase');
END;
/
Create the events that I want mailing about
to test notifications work first set up events for everything
BEGIN
DBMS_SCHEDULER.add_job_email_notification (
job_name => 'DELETE_OSAUD_FILES_JOB',
recipients => 'me@mycompany.com',
events => 'job_all_events');
END;
/
run your job
BEGIN
dbms_scheduler.run_job (
job_name =>'DELETE_OSAUD_FILES_JOB');
END;
/
You should get an email saying it ran.
But you don't want an 'I ran' mail every day, I only want to know if it's failed so:
BEGIN
DBMS_SCHEDULER.remove_job_email_notification (
job_name => 'DELETE_OSAUD_DATA_JOB',
recipients => 'me@mycompany.com',
events => 'job_succeeded');
END;
/
BEGIN
DBMS_SCHEDULER.remove_job_email_notification (
job_name => 'DELETE_OSAUD_DATA_JOB',
recipients => 'me@mycompany.com',
events => 'job_started');
END;
/
BEGIN
DBMS_SCHEDULER.remove_job_email_notification (
job_name => 'DELETE_OSAUD_DATA_JOB',
recipients => 'me@mycompany.com',
events => 'job_completed');
END;
/
Which is the equivalent of :
BEGIN
DBMS_SCHEDULER.add_job_email_notification (
job_name => 'DELETE_OSAUD_DATA_JOB',
recipients => 'me@mycompany.com',
events => 'job_broken,job_chain_stalled,job_completed,job_disabled,job_failed,
job_over_max_dur,job_sch_lim_reached,job_stopped');
END;
/
So now your .aud files will be kept in check for you.
Subscribe to:
Post Comments (Atom)
No comments:
Post a Comment