清理统一审计 AUD$UNIFIED
清理统一审计 AUD$UNIFIED 基表部份数据
清除统一统计信息, 统计审计不支持直接drop 基表, 但是可以drop partition
SYS@ORCLCDB> alter table AUDSYS.AUD$UNIFIED drop partition AUD_UNIFIED_P0 ;
alter table AUDSYS.AUD$UNIFIED drop partition AUD_UNIFIED_P0
*
ERROR at line 1:
ORA-46385: DML and DDL operations are not allowed on table "AUDSYS"."AUD$UNIFIED".
可以DROP AUD$UNIFIED 的分区
BEGIN
DBMS_AUDIT_MGMT.ALTER_PARTITION_INTERVAL(
interval_number => 1,
interval_frequency => 'DAY');
END;
/
col PARTITION_NAME for a15
col HIGH_VALUE for a40
select partition_name,INTERVAL,HIGH_VALUE from dba_tab_partitions where table_name='AUD$UNIFIED';
alter session set tracefile_identifier='10046';
alter session set max_dump_file_size = UNLIMITED;
alter session set timed_statistics=true;
alter session set events '10046 trace name context forever, level 12';
BEGIN
DBMS_AUDIT_MGMT.CLEAN_AUDIT_TRAIL(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,
use_last_arch_timestamp => TRUE);
END;
/
alter session set events '10046 trace name context off';
select * from v$diag_info where name like 'Default Trace File%';
select partition_name,INTERVAL,HIGH_VALUE from dba_tab_partitions where table_name='AUD$UNIFIED';
grep DROP /refresh/home/app/12.2.0.1/oracle/diag/rdbms/orcl12201/orcl12201/trace/orcl12201_ora_6340_10046.trc
[root@elk-master ~]# grep DROP /opt/oracle/diag/rdbms/orclcdb/ORCLCDB/trace/ORCLCDB_ora_183361_10046.trc
CALL DBMS_PDB_EXEC_SQL('ALTER TABLE AUDSYS.AUD$UNIFIED DROP PARTITION SYS_P181')
ALTER TABLE AUDSYS.AUD$UNIFIED DROP PARTITION SYS_P181
设置清除归档时间戳记 :
BEGIN
DBMS_AUDIT_MGMT.SET_LAST_ARCHIVE_TIMESTAMP(
AUDIT_TRAIL_TYPE => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,
LAST_ARCHIVE_TIME => '11-MAY-2020 06:30:00.00',
RAC_INSTANCE_NUMBER => 1,
CONTAINER => DBMS_AUDIT_MGMT.CONTAINER_CURRENT);
END;
/
参数说明:
AUDIT_TRAIL_TYPE指定审核跟踪类型。DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED将其设置为统一审核跟踪。 <-------------
DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD用于传统的标准审计跟踪表AUD$。(此设置不适用于只读数据库。)
DBMS_AUDIT_MGMT.AUDIT_TRAIL_FGA_STD用于传统的细粒度审核跟踪表FGA_LOG$。(此设置不适用于只读数据库。)
DBMS_AUDIT_MGMT.AUDIT_TRAIL_OS用于带有.aud扩展名的传统操作系统审核跟踪文件。(此设置不适用于Windows事件日志条目。)
DBMS_AUDIT_MGMT.AUDIT_TRAIL_XML 用于XML传统操作系统审核跟踪文件。
LAST_ARCHIVE_TIME指定时间戳YYYY-MM-DD HH:MI:SS.FFUTC格式(协调世界时)AUDIT_TRAIL_UNIFIED,AUDIT_TRAIL_AUD_STD以及AUDIT_TRAIL_FGA_STD,并在当地时区AUDIT_TRAIL_OS和AUDIT_TRAIL_XML。
注意: 时间好像是12小时制 ,上午 '12-OCT-2019 12:00:00.00 AM' 即24小时至的00:00:00
下午 '12-OCT-2019 12:59:59.00 PM' 即24小时至的23:59:59
例:
12小时制当天0晨 SELECT To_date(To_char(Trunc(SYSDATE), 'yyyy/mm/dd hh12:mi:ss'), 'yyyy/mm/dd hh12:mi:ss') FROM dual ;
24小时制当天0晨 SELECT To_date(To_char(Trunc(SYSDATE), 'yyyy/mm/dd hh24:mi:ss'), 'yyyy/mm/dd hh24:mi:ss') FROM dual ;
RAC_INSTANCE_NUMBER指定Oracle RAC安装的实例号。此设置与单实例数据库无关。
如果指定DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD或DBMS_AUDIT_MGMT.AUDIT_TRAIL_FGA_STD审计跟踪类型,则可以省略该RAC_INSTANCE_NUMBER参数。
这是因为,即使对于Oracle RAC安装,也只有一个AUD$或一个FGA_LOG$表。默认值为NULL。
您可以通过SHOW PARAMETER INSTANCE_NUMBER在SQL * Plus中发出命令来找到当前实例的实例号。
CONTAINER将时间戳应用于多租户环境。DBMS_AUDIT_MGMT.CONTAINER_CURRENT指定当前的PDB;DBMS_AUDIT_MGMT.CONTAINER_ALL适用于多租户环境中的所有PDB。
请注意,您可以从CDBK 设置CONTAINER到DBMS_MGMT.CONTAINER_ALL ,或 在PDB中设置 DBMS_MGMT.CONTAINER_CURRENT 。
select to_char(last_archive_ts, 'yyyy/mm/dd hh24:mi:ss.ff6 TZR TZD') time from dba_audit_mgmt_last_arch_ts;
2019/10/12 06:30:00.000000 +00:00
删除归档时间戳记 :
BEGIN
DBMS_AUDIT_MGMT.CLEAR_LAST_ARCHIVE_TIMESTAMP(
AUDIT_TRAIL_TYPE => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,
CONTAINER => DBMS_AUDIT_MGMT.CONTAINER_CURRENT);
END;
/
通常,设置时间戳后,可以使用DBMS_AUDIT_MGMT.CLEAN_AUDIT_TRAIL PL / SQL过程删除在时间戳日期之前创建的审核记录。
统计删之用前有多少行,对是清理后是否 为0
select count(*) from UNIFIED_AUDIT_TRAIL where EVENT_TIMESTAMP < TO_TIMESTAMP('12-OCT-2019 01:00:00','DD-MON-RRRR HH24:MI:SS') ;
执行了几次清理操作
select count(*) from UNIFIED_AUDIT_TRAIL where OBJECT_NAME='DBMS_AUDIT_MGMT' and SQL_TEXT LIKE '%DBMS_AUDIT_MGMT.CLEAN_AUDIT_TRAIL%';
手动清理:
BEGIN
DBMS_AUDIT_MGMT.CLEAN_AUDIT_TRAIL(
AUDIT_TRAIL_TYPE => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,
USE_LAST_ARCH_TIMESTAMP => TRUE,
CONTAINER => DBMS_AUDIT_MGMT.CONTAINER_CURRENT );
END;
/
查看历史清理记录
select * from UNIFIED_AUDIT_TRAIL where OBJECT_NAME='DBMS_AUDIT_MGMT' and OBJECT_SCHEMA='SYS' AND SQL_TEXT LIKE '%DBMS_AUDIT_MGMT.CLEAN_AUDIT_TRAIL%';
自动清理:
通过DBMS_AUDIT_MGMT 创建JOB实现
BEGIN
DBMS_AUDIT_MGMT.CREATE_PURGE_JOB (
AUDIT_TRAIL_TYPE => DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,
AUDIT_TRAIL_PURGE_INTERVAL => 12,
AUDIT_TRAIL_PURGE_NAME => 'Audit_Trail_PJ',
USE_LAST_ARCH_TIMESTAMP => TRUE,
CONTAINER => DBMS_AUDIT_MGMT.CONTAINER_CURRENT);
END;
/
AUDIT_TRAIL_PURGE_INTERVAL 指定运行此清除作业的每小时间隔。计时从您运行该DBMS_AUDIT_MGMT.CREATE_PURGE_JOB过程时开始,在这种情况下,是在您运行此过程后12个小时。
要启用或禁用审核跟踪清除作业:
BEGIN
DBMS_AUDIT_MGMT.SET_PURGE_JOB_STATUS(
AUDIT_TRAIL_PURGE_NAME => 'Audit_Trail_PJ',
AUDIT_TRAIL_STATUS_VALUE => DBMS_AUDIT_MGMT.PURGE_JOB_ENABLE);
END;
/
--DBMS_AUDIT_MGMT.PURGE_JOB_ENABLE 启用
--DBMS_AUDIT_MGMT.PURGE_JOB_DISABLE 禁用
设置间隔时间
BEGIN
DBMS_AUDIT_MGMT.SET_PURGE_JOB_INTERVAL(
AUDIT_TRAIL_PURGE_NAME => 'Audit_Trail_PJ',
AUDIT_TRAIL_INTERVAL_VALUE => 24);
END;
/
删除清理任务
BEGIN
DBMS_AUDIT_MGMT.DROP_PURGE_JOB(
AUDIT_TRAIL_PURGE_NAME => 'Audit_Trail_PJ');
END;
/
相关视图:
DBA_AUDIT_MGMT_CLEAN_EVENTS 显示传统(即非统一)审计跟踪的清除事件的历史记录
统计审计的清除记录 select * from UNIFIED_AUDIT_TRAIL
where OBJECT_NAME='DBMS_AUDIT_MGMT' and OBJECT_SCHEMA='SYS' AND SQL_TEXT LIKE '%DBMS_AUDIT_MGMT.CLEAN_AUDIT_TRAIL%';
DBA_AUDIT_MGMT_CLEANUP_JOBS 显示当前配置的审核跟踪清除作业
DBA_AUDIT_MGMT_CONFIG_PARAMS 显示DBMS_AUDIT_MGMTPL / SQL程序包 使用的当前配置的审核跟踪属性
DBA_AUDIT_MGMT_LAST_ARCH_TS 显示为审计跟踪清除设置的最后一个归档时间戳记
评论已关闭