1. 创建监控用户

create user hodba
  identified by ""
  default tablespace USER_DATA
  temporary tablespace TEMPORARY_DATA
  profile suser
  quota 1024m on user_data;
grant select on DBA_DATA_FILES to HODBA;
grant select on DBA_FREE_SPACE to HODBA;
grant select on DBA_USERS to HODBA;
grant select on V_$PROCESS to HODBA;
grant select on V_$SESSION to HODBA;
grant select on V_$SESSION_WAIT to HODBA;
grant select on V_$SGASTAT to HODBA;
grant select on V_$SQL to HODBA;
grant select on V_$SQLTEXT to HODBA;
grant select on V_$SYSSTAT to HODBA;
grant select on V_$SYSTEM_EVENT to HODBA;
grant connect to HODBA;
grant alter user to HODBA;
grant create procedure to HODBA;
grant select on DBA_HIST_SYSTEM_EVENT to hodba;

2. 创建监控数据表

create table hodba.TTBS_USAGE
(
  CUR_TIME   DATE,
  TBS_NAME   VARCHAR2(30),
  SUM_M      NUMBER,
  SUM_USED_M NUMBER,
  SUM_FREE_M NUMBER,
  PER_USED   NUMBER
)
/

create table hodba.TLOCK_DETAIL
(
  CUR_TIME    DATE,
  EVENT       VARCHAR2(64),
  WAIT_TIME   NUMBER,
  WAIT_SID    NUMBER,
  WAIT_USER   VARCHAR2(30),
  WAIT_SQL_ID VARCHAR2(13),
  LOCK_SID    NUMBER,
  LOCK_USER   VARCHAR2(30),
  LOCK_SQL_ID VARCHAR2(13)
)
/

create table hodba.TLOCK_SQL
(
  SQL_ID   VARCHAR2(13),
  SQL_TEXT VARCHAR2(64),
  PIECE    NUMBER
)
/

create table hodba.TSESSION_NUM
(
  GET_TIME DATE,
  NUM_SESS NUMBER,
  ACT_SESS NUMBER
)
/

CREATE TABLE HODBA.TAGENT_SESSION_NUM
(
  GET_TIME DATE,
  NUM_SESS NUMBER,
  ACT_SESS NUMBER
)
/

create table hodba.perf_log
(
rtime date,
mem_use number,
cpu_use number
)
organization external (
type oracle_loader 
default directory PERFLOGS
access parameters (
records delimited by newline 
skip 2
nobadfile
nologfile
nodiscardfile
fields
(
c1 char(1), rtime char(19) DATE_FORMAT DATE MASK "MM/DD/YYYY HH24:MI:SS", c2 char(7),
mem_use char(5), c3 char(3), cpu_use char(6)
)
) 
location ('CPU_MEM_000003.csv')
)
reject limit unlimited
/

CREATE EXTERNAL TABLE HODBA.ALERT_LOG (TEXT VARCHAR2(400)) ORGANIZATION EXTERNAL (TYPE "ORACLE_LOADER" DEFAULT DIRECTORY "BDUMP" ACCESS PARAMETERS ( records delimited by newline
nobadfile
nodiscardfile
nologfile
 ) LOCATION ( 'alert_cas.log' ) ) REJECT LIMIT UNLIMITED
/

create table hodba.full_listener_log
(
line varchar2(4000)
)
organization external (
type oracle_loader 
default directory LISTENER_LOG_DIR 
access parameters (
records delimited by newline 
nobadfile 
nologfile 
nodiscardfile 
) 
location ('listener.log')
)
reject limit unlimited
/

create table hodba.listener_log
(
log_date date, 
connect_string varchar2(300), 
protocol_info varchar2(300), 
action varchar2(15), 
service_name varchar2(15), 
return_code number(10)
)
organization external (
type oracle_loader 
default directory LISTENER_LOG_DIR 
access parameters 
(
records delimited by newline 
nobadfile 
nologfile 
nodiscardfile 
fields terminated by "*" lrtrim 
missing field values are null 
(
log_date char(30) date_format 
date mask "DD-MON-YYYY HH24:MI:SS", 
connect_string, 
protocol_info, 
action, 
service_name, 
return_code 
) 
) 
location ('listener.log')
)
reject limit unlimited
/

3. 创建监控数据抓取主程序

create or replace procedure hodba.pro_mon_stat is
begin
call pro_session_num;
call pro_lock_detail;
exception
  when others then
    rollback;
end pro_mon_stat;
/

4. 创建表空间监控程序

create or replace procedure hodba.pro_tbs_usage is
begin
  INSERT INTO ttbs_usage
    SELECT sysdate cur_time,
           tablespace_name tbs_name,
           round(sum_m, 2) sum_m,
           round(sum_m - sum_free_m, 2) sum_used_m,
           round(sum_free_m, 2) sum_free_m,
           round(100 * (1 - sum_free_m / sum_m), 2) per_used
      FROM (SELECT tablespace_name, sum(bytes) / 1024 / 1024 sum_m
              FROM dba_data_files
             GROUP BY tablespace_name),
           (SELECT tablespace_name AS fs_ts_name,
                   sum(bytes / 1024 / 1024) AS sum_free_m
              FROM dba_free_space
             GROUP BY tablespace_name)
     WHERE tablespace_name = fs_ts_name;
  commit;
exception
  when others then
    rollback;
end pro_tbs_usage;
/

5. 创建session监控程序

create or replace procedure hodba.pro_session_num is
  num_sess number;
  act_sess number;
begin
  select count(1) into num_sess from sys.v_$session;
  select count(1) into act_sess from sys.v_$session where status = 'ACTIVE';
  execute immediate 'insert into tsession_num values (sysdate,' ||
                    num_sess || ',' || act_sess || ')';
  commit;
exception
  when others then
    null;
end pro_session_num;
/

6. 创建LOCK的监控程序

create or replace procedure hodba.pro_lock_detail is
wsid number;
wevent varchar2(64);
lsid number;
--wsql varchar2(64);
--lsql varchar2(64);
wuser varchar2(30);
luser varchar2(30);
wtime number;
wsqlid varchar2(13);
lsqlid varchar2(13);
icount number;
cursor cur1 is select sid,username,event,blocking_session,seconds_in_wait,nvl(sql_id,prev_sql_id) from v$session where event like 'enq:%';
begin
insert into hodba.tlock_detail_new select sysdate,a.event,a.seconds_in_wait,a.sid,a.username,a.sql_id,a.prev_sql_id,b.sid,b.username,b.sql_id,b.prev_sql_id from v$session a, v$session b where a.event like 'enq:%' and b.sid = a.blocking_session;
open cur1;
loop
fetch cur1 into wsid,wuser,wevent,lsid,wtime,wsqlid;
icount:=0;
exit when cur1%notfound;
select username,nvl(sql_id,prev_sql_id) into luser,lsqlid from v$session where sid=lsid;
--select sql_text into wsql from v$sqltext where sql_id=(select sql_id from v$session where sid=wsid);
--select sql_text into lsql from v$sqltext where sql_id=(select nvl(sql_id,prev_sql_id) from v$session where sid=lsid);
insert into tlock_detail values (sysdate,wevent,wtime,wsid,wuser,wsqlid,lsid,luser,lsqlid);
select count(1) into icount from tlock_sql where sql_id=wsqlid;
if icount=0 then
insert into tlock_sql select sql_id,sql_text,piece from v$sqltext where sql_id=wsqlid;
end if;
select count(1) into icount from tlock_sql where sql_id=lsqlid;
if icount=0 then
insert into tlock_sql select sql_id,sql_text,piece from v$sqltext where sql_id=lsqlid;
end if;
end loop;
close cur1;
commit;
exception
when others then
	close cur1;
	rollback;
end pro_lock_detail;
/

7. 创建监听分析函数

create or replace function hodba.parse_listener_log_line
( 
p_in varchar2, --要求查询的字段
p_param in varchar2 --要求查询的关键字
) 
return varchar2 
as 
l_begin number(3); 
l_end number(3); 
l_val varchar2(2000); 
begin 
--枚举相关字段可能的值
--防止空值溢出
if p_param not in ( 
'SID', 
'SERVICE_NAME', 
'PROGRAM', 
'SERVICE', 
'HOST', 
'USER', 
'PROTOCOL', 
'TYPE', 
'METHOD', 
'RETRIES', 
'DELAY', 
'PORT', 
'COMMAND' 
) then 
raise_application_error (-20001,'Invalid Parameter Value '||p_param); 
end if; 
--You search for the presence of this parameter, note the position of the parentheses and the equality sign, and determine the position of the value of the paramet
l_begin := instr (upper(p_in), '('||p_param||'='); 
l_begin := instr (upper(p_in), '=', l_begin); 
l_end := instr (upper(p_in), ')', l_begin); 
l_val := substr (p_in, l_begin+1, l_end - l_begin - 1); 
return l_val; 
end;
/

8. 创建TOP等待事件的抓取程序

create or replace procedure hodba.pro_top_wait(pbid number,
                                               peid number,
                                               pnum number) is
  cursor cur1 is
    select *
      from (select wait_class,
                   event_name,
                   max(total_waits) - min(total_waits) "WAITS",
                   trunc((max(time_waited_micro) - min(time_waited_micro)) /
                         1000000) "WAIT_TIME"
              from DBA_HIST_SYSTEM_EVENT
             where wait_class <> 'Idle' and (event_name not like 'SQL%' and event_name not like 'rdbms%')
               and snap_id in (pbid, peid)
             group by wait_class, event_name
             order by 4 desc)
     where rownum <= pnum;
  rs cur1%rowtype;
begin
  dbms_output.enable(99999);
  dbms_output.put_line(rpad('WAIT_CLASS', 20, ' ') ||
                       rpad('EVENT_NAME', 40, ' ') ||
                       lpad('WAITS', 10, ' ') ||
                       lpad('WAIT_TIME', 10, ' '));
  dbms_output.put_line(rpad('-', 19, '-') || ' ' || rpad('-', 39, '-') || ' ' ||
                       lpad('-', 10, '-') || ' ' || lpad('-', 10, '-'));
  open cur1;
  loop
    fetch cur1
      into rs;
    exit when cur1%notfound;
    dbms_output.put_line(rpad(rs.wait_class, 20, ' ') ||
                         rpad(rs.event_name, 40, ' ') ||
                         lpad(rs.WAITS, 10, ' ') ||
                         lpad(rs.wait_time, 10, ' '));
  end loop;
  close cur1;
exception
  when others then
    null;
end pro_top_wait;
/

9. 创建邮件发送程序

CREATE OR REPLACE PROCEDURE HODBA.PRO_SEND_EMAIL(P_TXT       VARCHAR2,
                                          P_SUB       VARCHAR2,
                                          P_SENDOR    VARCHAR2,
                                          P_RECEIVER  VARCHAR2,
                                          P_SERVER    VARCHAR2,
                                          P_PORT      NUMBER DEFAULT 25,
                                          P_NEED_SMTP INT DEFAULT 0,
                                          P_USER      VARCHAR2 DEFAULT NULL,
                                          P_PASS      VARCHAR2 DEFAULT NULL,
                                          P_FILENAME  VARCHAR2 DEFAULT NULL,
                                          P_ENCODE    VARCHAR2 DEFAULT 'bit 7')
  AUTHID CURRENT_USER IS
  /*
  作用:用oracle发送邮件
  主要功能:1、支持多收件人。
            2、支持中文
            3、支持抄送人
            4、支持大于32K的附件
            5、支持多行正文
            6、支持多附件
            7、支持文本附件和二进制附件
            8、支持HTML格式
            8、支持
  参数说明:
            p_txt :邮件正文
            p_sub: 邮件标题
            p_SendorAddress : 发送人邮件地址
            p_ReceiverAddress : 接收地址,可以同时发送到多个地址上,地址之间用","或者";"隔开
            p_EmailServer : 邮件服务器地址,可以是域名或者IP
            p_Port :邮件服务器端口
            p_need_smtp:是否需要smtp认证,0表示不需要,1表示需要
            p_user:smtp验证需要的用户名
            p_pass:smtp验证需要的密码
            p_filename:附件名称,必须包含完整的路径,如"d:\temp\a.txt"。
                        可以有多个附件,附件名称只见用逗号或者分号分隔
            p_encode:附件编码转换格式,其中 p_encode='bit 7' 表示文本类型附件
                                             p_encode='base64' 表示二进制类型附件
  注意:
        1、对于文本类型的附件,不能用base64的方式发送,否则出错
        2、对于多个附件只能用同一种格式发送
  */

  L_CRLF VARCHAR2(2) := UTL_TCP.CRLF;
  L_SENDORADDRESS VARCHAR2(4000);
  L_SPLITE        VARCHAR2(10) := '++';
  BOUNDARY            CONSTANT VARCHAR2(256) := '-----BYSUK';
  FIRST_BOUNDARY      CONSTANT VARCHAR2(256) := '--' || BOUNDARY || L_CRLF;
  LAST_BOUNDARY       CONSTANT VARCHAR2(256) := '--' || BOUNDARY || '--' ||
                                                L_CRLF;
  MULTIPART_MIME_TYPE CONSTANT VARCHAR2(256) := 'multipart/mixed; boundary="' ||
                                                BOUNDARY || '"';
  /* 以下部分是发送大二进制附件时用到的变量 */
  L_FIL                 BFILE;
  L_FILE_LEN            NUMBER;
  L_MODULO              NUMBER;
  L_PIECES              NUMBER;
  L_FILE_HANDLE         UTL_FILE.FILE_TYPE;
  L_AMT                 BINARY_INTEGER := 672 * 3; /* ensures proper format;  2016 */
  L_FILEPOS             PLS_INTEGER := 1; /* pointer for the file */
  L_CHUNKS              NUMBER;
  L_BUF                 RAW(2100);
  L_DATA                RAW(2100);
  L_MAX_LINE_WIDTH      NUMBER := 54;
  L_DIRECTORY_BASE_NAME VARCHAR2(100) := 'DIR_FOR_SEND_MAIL';
  L_LINE                VARCHAR2(1000);
  L_MESG                VARCHAR2(32767);
  /* 以上部分是发送大二进制附件时用到的变量 */

  TYPE ADDRESS_LIST IS TABLE OF VARCHAR2(100) INDEX BY BINARY_INTEGER;
  MY_ADDRESS_LIST ADDRESS_LIST;
  TYPE ACCT_LIST IS TABLE OF VARCHAR2(100) INDEX BY BINARY_INTEGER;
  MY_ACCT_LIST ACCT_LIST;
  -------------------------------------返回附件源文件所在目录或者名称--------------------------------------
  FUNCTION GET_FILE(P_FILE VARCHAR2,
                    P_GET  INT) RETURN VARCHAR2 IS
    --p_get=1 表示返回目录
    --p_get=2 表示返回文件名
    L_FILE VARCHAR2(1000);
  BEGIN
    IF INSTR(P_FILE, '\') > 0 THEN
      --windows
      IF P_GET = 1 THEN
        L_FILE := SUBSTR(P_FILE, 1, INSTR(P_FILE, '\', -1) - 1);
      ELSIF P_GET = 2 THEN
        L_FILE := SUBSTR(P_FILE, - (LENGTH(P_FILE) - INSTR(P_FILE, '\', -1)));
      END IF;
    ELSIF INSTR(P_FILE, '/') > 0 THEN
      --linux/unix
      IF P_GET = 1 THEN
        L_FILE := SUBSTR(P_FILE, 1, INSTR(P_FILE, '/', -1) - 1);
      ELSIF P_GET = 2 THEN
        L_FILE := SUBSTR(P_FILE, - (LENGTH(P_FILE) - INSTR(P_FILE, '/', -1)));
      END IF;
    END IF;
    RETURN L_FILE;
  END;
  ---------------------------------------------删除directory------------------------------------
  PROCEDURE DROP_DIRECTORY(P_DIRECTORY_NAME VARCHAR2) IS
  BEGIN
    EXECUTE IMMEDIATE 'drop directory ' || P_DIRECTORY_NAME;
  EXCEPTION
    WHEN OTHERS THEN
      NULL;
  END;
  --------------------------------------------------创建directory-----------------------------------------
  PROCEDURE CREATE_DIRECTORY(P_DIRECTORY_NAME VARCHAR2,
                             P_DIR            VARCHAR2) IS
  BEGIN
    EXECUTE IMMEDIATE 'create directory ' || P_DIRECTORY_NAME || ' as ''' ||
                      P_DIR || '''';
    EXECUTE IMMEDIATE 'grant read,write on directory ' || P_DIRECTORY_NAME ||
                      ' to public';
    EXCEPTION
    WHEN OTHERS THEN
      RAISE;
  END;
  --------------------------------------------分割邮件地址或者附件地址-----------------------------------
  PROCEDURE P_SPLITE_STR(P_STR         VARCHAR2,
                         P_SPLITE_FLAG INT DEFAULT 1) IS
    L_ADDR VARCHAR2(254) := '';
    L_LEN  INT;
    L_STR  VARCHAR2(4000);
    J      INT := 0; --表示邮件地址或者附件的个数
  BEGIN
    /*处理接收邮件地址列表,包括去空格、将;转换为,等*/
    L_STR := TRIM(RTRIM(REPLACE(REPLACE(P_STR, ';', ','), ' ', ''), ','));
    L_LEN := LENGTH(L_STR);
    FOR I IN 1 .. L_LEN LOOP
      IF SUBSTR(L_STR, I, 1) <> ',' THEN
        L_ADDR := L_ADDR || SUBSTR(L_STR, I, 1);
      ELSE
        J := J + 1;
        IF P_SPLITE_FLAG = 1 THEN --表示处理邮件地址
          --前后需要加上'<>',否则很多邮箱将不能发送邮件
          L_ADDR := '<' || L_ADDR || '>';
          --调用邮件发送过程
          MY_ADDRESS_LIST(J) := L_ADDR;
        ELSIF P_SPLITE_FLAG = 2 THEN --表示处理附件名称
          MY_ACCT_LIST(J) := L_ADDR;
        END IF;
        L_ADDR := '';
      END IF;
      IF I = L_LEN THEN
        J := J + 1;
        IF P_SPLITE_FLAG = 1 THEN
          --调用邮件发送过程
          L_ADDR := '<' || L_ADDR || '>';
          MY_ADDRESS_LIST(J) := L_ADDR;
        ELSIF P_SPLITE_FLAG = 2 THEN
          MY_ACCT_LIST(J) := L_ADDR;
        END IF;
      END IF;
    END LOOP;
  END;
  ------------------------------------------------写邮件头和邮件内容------------------------------------------
  PROCEDURE WRITE_DATA(P_CONN   IN OUT NOCOPY UTL_SMTP.CONNECTION,
                       P_NAME   IN VARCHAR2,
                       P_VALUE  IN VARCHAR2,
                       P_SPLITE VARCHAR2 DEFAULT ':',
                       P_CRLF   VARCHAR2 DEFAULT L_CRLF) IS
  BEGIN
    /* utl_raw.cast_to_raw 对解决中文乱码问题很重要*/
    UTL_SMTP.WRITE_RAW_DATA(P_CONN, UTL_RAW.CAST_TO_RAW(CONVERT(P_NAME ||
                                                         P_SPLITE ||
                                                         P_VALUE ||
                                                         P_CRLF, 'ZHS16GBK')));
  END;
  ----------------------------------------写MIME邮件尾部-----------------------------------------------------

  PROCEDURE END_BOUNDARY(CONN IN OUT NOCOPY UTL_SMTP.CONNECTION,
                         LAST IN BOOLEAN DEFAULT FALSE) IS
  BEGIN
    UTL_SMTP.WRITE_DATA(CONN, UTL_TCP.CRLF);
    IF (LAST) THEN
      UTL_SMTP.WRITE_DATA(CONN, LAST_BOUNDARY);
    END IF;
  END;

  ----------------------------------------------发送附件----------------------------------------------------

  PROCEDURE ATTACHMENT(CONN         IN OUT NOCOPY UTL_SMTP.CONNECTION,
                       MIME_TYPE    IN VARCHAR2 DEFAULT 'text/plain',
                       INLINE       IN BOOLEAN DEFAULT TRUE,
                       FILENAME     IN VARCHAR2 DEFAULT 't.txt',
                       TRANSFER_ENC IN VARCHAR2 DEFAULT '7 bit',
                       DT_NAME      IN VARCHAR2 DEFAULT '0') IS

    L_FILENAME VARCHAR2(1000);
  BEGIN
    --写附件头
    UTL_SMTP.WRITE_DATA(CONN, FIRST_BOUNDARY);
    --设置附件格式
    WRITE_DATA(CONN, 'Content-Type', MIME_TYPE);
    --如果文件名称非空,表示有附件
    DROP_DIRECTORY(DT_NAME);
    --创建directory
    CREATE_DIRECTORY(DT_NAME, GET_FILE(FILENAME, 1));
    --得到附件文件名称
    L_FILENAME := GET_FILE(FILENAME, 2);
    IF (INLINE) THEN
      WRITE_DATA(CONN, 'Content-Disposition', 'inline; filename="' ||
                  L_FILENAME || '"');
    ELSE
      WRITE_DATA(CONN, 'Content-Disposition', 'attachment; filename="' ||
                  L_FILENAME || '"');
    END IF;

    --设置附件的转换格式
    IF (TRANSFER_ENC IS NOT NULL) THEN
      WRITE_DATA(CONN, 'Content-Transfer-Encoding', TRANSFER_ENC);
    END IF;

    UTL_SMTP.WRITE_DATA(CONN, UTL_TCP.CRLF);

    --begin 贴附件内容
    IF TRANSFER_ENC = 'bit 7' THEN
      --如果是文本类型的附件
      BEGIN
        L_FILE_HANDLE := UTL_FILE.FOPEN(DT_NAME, L_FILENAME, 'r'); --打开文件
        --把附件分成多份,这样可以发送超过32K的附件
        LOOP
          UTL_FILE.GET_LINE(L_FILE_HANDLE, L_LINE);
          L_MESG := L_LINE || L_CRLF;
          WRITE_DATA(CONN, '', L_MESG, '', '');
        END LOOP;
        UTL_FILE.FCLOSE(L_FILE_HANDLE);
        END_BOUNDARY(CONN);
      EXCEPTION
        WHEN OTHERS THEN
          UTL_FILE.FCLOSE(L_FILE_HANDLE);
          END_BOUNDARY(CONN);
          NULL;
      END; --结束文本类型附件的处理

    ELSIF TRANSFER_ENC = 'base64' THEN
      --如果是二进制类型的附件
      BEGIN
        --把附件分成多份,这样可以发送超过32K的附件
        L_FILEPOS  := 1;--重置offset,在发送多个附件时,必须重置
        L_FIL      := BFILENAME(DT_NAME, L_FILENAME);
        L_FILE_LEN := DBMS_LOB.GETLENGTH(L_FIL);
        L_MODULO   := MOD(L_FILE_LEN, L_AMT);
        L_PIECES   := TRUNC(L_FILE_LEN / L_AMT);
        IF (L_MODULO <> 0) THEN
          L_PIECES := L_PIECES + 1;
        END IF;
        DBMS_LOB.FILEOPEN(L_FIL, DBMS_LOB.FILE_READONLY);
        DBMS_LOB.READ(L_FIL, L_AMT, L_FILEPOS, L_BUF);
        L_DATA := NULL;
        FOR I IN 1 .. L_PIECES LOOP
          L_FILEPOS  := I * L_AMT + 1;
          L_FILE_LEN := L_FILE_LEN - L_AMT;
          L_DATA     := UTL_RAW.CONCAT(L_DATA, L_BUF);
          L_CHUNKS   := TRUNC(UTL_RAW.LENGTH(L_DATA) / L_MAX_LINE_WIDTH);
          IF (I <> L_PIECES) THEN
            L_CHUNKS := L_CHUNKS - 1;
          END IF;
          UTL_SMTP.WRITE_RAW_DATA(CONN, UTL_ENCODE.BASE64_ENCODE(L_DATA));
          L_DATA := NULL;
          IF (L_FILE_LEN < L_AMT AND L_FILE_LEN > 0) THEN
            L_AMT := L_FILE_LEN;
          END IF;
          DBMS_LOB.READ(L_FIL, L_AMT, L_FILEPOS, L_BUF);
        END LOOP;
        DBMS_LOB.FILECLOSE(L_FIL);
        END_BOUNDARY(CONN);
      EXCEPTION
        WHEN OTHERS THEN
          DBMS_LOB.FILECLOSE(L_FIL);
          END_BOUNDARY(CONN);
          RAISE;
      END; --结束处理二进制附件

    END IF; --结束处理附件内容
    DROP_DIRECTORY(DT_NAME);
  END; --结束过程ATTACHMENT

  ---------------------------------------------真正发送邮件的过程--------------------------------------------
  PROCEDURE P_EMAIL(P_SENDORADDRESS2   VARCHAR2, --发送地址
                    P_RECEIVERADDRESS2 VARCHAR2) --接受地址
   IS
    L_CONN UTL_SMTP.CONNECTION; --定义连接
  BEGIN
    /*初始化邮件服务器信息,连接邮件服务器*/
    L_CONN := UTL_SMTP.OPEN_CONNECTION(P_SERVER, P_PORT);
    UTL_SMTP.HELO(L_CONN, P_SERVER);
    /* smtp服务器登录校验 */
    IF P_NEED_SMTP = 1 THEN
      UTL_SMTP.COMMAND(L_CONN, 'AUTH LOGIN', '');
      UTL_SMTP.COMMAND(L_CONN, UTL_RAW.CAST_TO_VARCHAR2(UTL_ENCODE.BASE64_ENCODE(UTL_RAW.CAST_TO_RAW(P_USER))));
      UTL_SMTP.COMMAND(L_CONN, UTL_RAW.CAST_TO_VARCHAR2(UTL_ENCODE.BASE64_ENCODE(UTL_RAW.CAST_TO_RAW(P_PASS))));
    END IF;

    /*设置发送地址和接收地址*/
    UTL_SMTP.MAIL(L_CONN, P_SENDORADDRESS2);
    UTL_SMTP.RCPT(L_CONN, P_RECEIVERADDRESS2);

    /*设置邮件头*/
    UTL_SMTP.OPEN_DATA(L_CONN);

    WRITE_DATA(L_CONN, 'Date', TO_CHAR(SYSDATE, 'yyyy-mm-dd hh24:mi:ss'));
    /*设置发送人*/
    WRITE_DATA(L_CONN, 'From', P_SENDOR);
    /*设置接收人*/
    WRITE_DATA(L_CONN, 'To', P_RECEIVER);
    /*设置邮件主题*/
    WRITE_DATA(L_CONN, 'Subject', P_SUB);

    WRITE_DATA(L_CONN, 'Content-Type', MULTIPART_MIME_TYPE);
    UTL_SMTP.WRITE_DATA(L_CONN, UTL_TCP.CRLF);
    UTL_SMTP.WRITE_DATA(L_CONN, FIRST_BOUNDARY);
    WRITE_DATA(L_CONN, 'Content-Type', 'text/plain;charset=gb2312');
    --单独空一行,否则,正文内容不显示
    UTL_SMTP.WRITE_DATA(L_CONN, UTL_TCP.CRLF);
    /* 设置邮件正文
      把分隔符还原成chr(10)。这主要是为了shell中调用该过程,如果有多行,则先把多行的内容合并成一行,并用 l_splite分隔
      然后用 l_crlf替换chr(10)。这一步是必须的,否则将不能发送邮件正文有多行的邮件
    */
    WRITE_DATA(L_CONN, '', REPLACE(REPLACE(P_TXT, L_SPLITE, CHR(10)), CHR(10), L_CRLF), '', '');
    END_BOUNDARY(L_CONN);

  --如果文件名称不为空,则发送附件
    IF (P_FILENAME IS NOT NULL) THEN
      --根据逗号或者分号拆分附件地址
      P_SPLITE_STR(P_FILENAME, 2);
      --循环发送附件(在同一个邮件中)
      FOR K IN 1 .. MY_ACCT_LIST.COUNT LOOP
        ATTACHMENT(CONN => L_CONN, FILENAME => MY_ACCT_LIST(K), TRANSFER_ENC => P_ENCODE, DT_NAME => L_DIRECTORY_BASE_NAME ||
                               TO_CHAR(K));
      END LOOP;
    END IF;

    /*关闭数据写入*/
    UTL_SMTP.CLOSE_DATA(L_CONN);
    /*关闭连接*/
    UTL_SMTP.QUIT(L_CONN);

    /*异常处理*/
  EXCEPTION
    WHEN OTHERS THEN
      NULL;
      RAISE;

  END;

  ---------------------------------------------------主过程-----------------------------------------------------

BEGIN
  L_SENDORADDRESS := '<' || P_SENDOR || '>';
  P_SPLITE_STR(P_RECEIVER);--处理邮件地址
  FOR K IN 1 .. MY_ADDRESS_LIST.COUNT LOOP
    P_EMAIL(L_SENDORADDRESS, MY_ADDRESS_LIST(K));
  END LOOP;
  /*处理邮件地址,根据逗号分割邮件*/

EXCEPTION
  WHEN OTHERS THEN
    RAISE;
END;
/

10.创建日报生成脚本

set lines 1000
set trim on
set trims on
set echo off
set feedback off
set serveroutp on
set pagesize 100

alter session set nls_language=american;

col td noprint new_value today
select to_char(sysdate,'yyyy-mm-dd') td from dual;

spool Z:\dbashell\monitor\daily_rep_&&today..log

pro DATABASE CHECK REPORT (Date: &&today)
pro ============================================
pro
pro
pro
pro ***************************************** CPU and Memory *****************************************
col TIME for a15
col Average_CPU(%) for a15
col Max_CPU(%) for a10
select to_char(rtime, 'yyyy/mm/dd:hh24') "TIME",
       trunc(avg(42 * 1024 - mem_use) / 1024) "Average_Memory(G)",
       trunc(avg(cpu_use), 2) || '%' "Average_CPU(%)",
       trunc(max(42 * 1024 - mem_use) / 1024) "Max_Memory(G)",
       trunc(max(cpu_use), 2) || '%' "Max_CPU(%)"
  from hodba.perf_log
 where rtime > trunc(sysdate - 1)
   and rtime < trunc(sysdate)
 group by to_char(rtime, 'yyyy/mm/dd:hh24')
 order by 1;


pro
pro
pro
pro ***************************************** Backgroup Process *****************************************
col DESCRIPTION for a40
col error for a10
select paddr,pserial#,name,description,to_char(error) error from v$bgprocess where paddr<>'00';


pro
pro
pro
pro ***************************************** Redo Log Size *****************************************
col TIME for a15
select a.f_time "TIME",
       ceil(sum(a.blocks * a.block_size) / 1024 / 1024) "REDO_LOG(M/H)"
  from (select distinct sequence#,
                        thread#,
                        blocks,
                        block_size,
                        to_char(first_time, 'yyyy/mm/dd:hh24') f_time
          from v$archived_log
         where first_time > trunc(sysdate - 1)
           and first_time < trunc(sysdate)) a
 group by a.f_time
 order by 1;


pro
pro
pro
pro ***************************************** DB Sessions *****************************************
col TIME for a15
select to_char(get_time, 'yyyy/mm/dd:hh24') "TIME",
       max(num_sess) "Max_sessions(H)",
       max(act_sess) "Max_actives(H)",
       trunc(avg(num_sess)) "average_sessions(H)",
       trunc(avg(act_sess)) "average_actives(H)"
  from hodba.tsession_num
 where get_time between trunc(sysdate - 1) and trunc(sysdate)
 group by to_char(get_time, 'yyyy/mm/dd:hh24')
 order by 1;


pro
pro
pro
pro ***************************************** Enq Wait Event *****************************************
col TIME for a20
select to_char(cur_time,'yyyy/mm/dd hh24:mi:ss') "TIME",
       count(event) "Enq_Wait_Count",
       sum(wait_time) "Enq_Wait_Time"
  from hodba.tlock_detail
 where cur_time between trunc(sysdate - 1) and trunc(sysdate)
 group by cur_time
 order by 1;


pro
pro
pro
pro ***************************************** Tablespace Size *****************************************
col status for a10
col tablespace_name for a20
col contents for a10
col "size(M)" for a15
col used for a15
col pct for a10
select  d.status, d.tablespace_name, 
        TO_CHAR(NVL(a.bytes / 1024 /1024, 0),'99G999G990') "size(M)",
        TO_CHAR(NVL(a.bytes - NVL(f.bytes, 0),0)/1024/1024, '99G999G990D00')  used,
        TO_CHAR(NVL((a.bytes - NVL(f.bytes, 0)) / a.bytes * 100, 0), '990D00')||'%' pct
FROM sys.dba_tablespaces d,
        (select tablespace_name, sum(bytes) bytes from dba_data_files group by tablespace_name) a,
        (select tablespace_name, sum(bytes) bytes from dba_free_space group by tablespace_name) f
WHERE d.tablespace_name = a.tablespace_name(+) 
AND d.tablespace_name = f.tablespace_name(+)
order by pct;


pro
pro
pro
pro ***************************************** Alert Log Error *****************************************
declare
  cursor cur1 is
    select text from hodba.alert_log;
  tmptext varchar2(400);
  tmp1    number;
begin
  tmp1 := 0;
  dbms_output.enable(999999);
  open cur1;
  loop
    fetch cur1
      into tmptext;
    exit when cur1%notfound;
    if instr(tmptext, to_char(sysdate - 1, 'Mon dd')) > 0 then
      tmp1 := 1;
    end if;
    if tmp1 = 1 then
      if instr(tmptext, 'ORA-') > 0 or instr(tmptext, 'err') > 0 or
         instr(tmptext, 'Err') > 0 then
        dbms_output.put_line(tmptext);
      end if;
    end if;
  end loop;
  close cur1;
end;
/


pro
pro
pro
pro ***************************************** Audit privilege Connect *****************************************
column os_username format a22
column username format a12
column terminal format a20
column status format a15
column Login_Time format  a22
column Logoff_Time format a22
select os_username, 
	username, 
	terminal, 
	decode (returncode,'0','Connected','1005','FailedNull','1017','Failed',Returncode) status,
to_char(timestamp,'yyyy/mm/dd HH24:MI:SS') Login_Time,
to_char(logoff_time,'yyyy/mm/dd HH24:MI:SS') Logoff_Time
from dba_audit_session
where to_char(timestamp,'yyyy/mm/dd') =to_char(sysdate-1,'yyyy/mm/dd')
and ( username in ('CAS','SYSTEM','SYS','EDPDSH'));


pro
pro
pro
pro ***************************************** Standby Path *****************************************
col dest_name for a20
select dest_name,status,error from v$archive_dest;


pro
pro
pro
pro ***************************************** Standby Gap *****************************************
SELECT THREAD#, LOW_SEQUENCE#, HIGH_SEQUENCE# FROM V$ARCHIVE_GAP;


pro
pro
pro
pro ***************************************** Standby Log *****************************************
col archived for a10
col applied for a8
col completion_time for a25
col first_time for a25
select creator,
       sequence#,
       to_char(first_time, 'yyyy/mm/dd hh24:mi:ss') first_time,
       archived,
       applied,
       to_char(completion_time, 'yyyy/mm/dd hh24:mi:ss') completion_time
  from v$archived_log
 where name = 'CASDG01'
   and (first_time > sysdate - 1 or applied <> 'YES')
 order by sequence# desc;


pro
pro
pro
pro ***************************************** Full Alert Log *****************************************
declare
  cursor cur1 is
    select text from hodba.alert_log;
  tmptext varchar2(400);
  tmp1    number;
begin
  tmp1 := 0;
  dbms_output.enable(99999);
  open cur1;
  loop
    fetch cur1
      into tmptext;
    exit when cur1%notfound;
    if instr(tmptext, to_char(sysdate - 1, 'Mon dd')) > 0 then
      tmp1 := 1;
    end if;
    if tmp1 = 1 then
      dbms_output.put_line(tmptext);
    end if;
  end loop;
  close cur1;
end;
/


pro
pro
pro
pro ***************************************** Top 5 Events *****************************************
declare
  cursor cur1 is
    select snap_id, to_char(begin_interval_time, 'hh24')
      from dba_hist_snapshot
     where begin_interval_time between trunc(sysdate - 1) and
           trunc(sysdate)
     order by snap_id;
  bid  number;
  eid  number;
  fid  number;
  btmp varchar2(2);
  etmp varchar2(2);
begin
  bid := 0;
  eid := 0;
  dbms_output.enable(99999);
  open cur1;
  loop
    fetch cur1
      into eid, etmp;
    exit when cur1%notfound;
    if bid <> 0 then
      dbms_output.put_line('<' || to_char(sysdate - 1, 'yyyy/mm/dd') || ' ' || btmp || '-' || etmp || '>');
      hodba.pro_top_wait(bid, eid, 5);
      dbms_output.put_line('');
    else
      fid := eid;
    end if;
    bid  := eid;
    btmp := etmp;
  end loop;
  close cur1;
  dbms_output.put_line('<' || to_char(sysdate - 1, 'yyyy/mm/dd') || '>');
  hodba.pro_top_wait(fid, eid, 5);
end;
/

spool off;


begin
  hodba.pro_send_email(P_TXT      => '',
                       P_SUB      => 'Oracle Database Healthy Report - CAS',
                       P_SENDOR   => 'alex_hou@163.com',
                       P_RECEIVER => 'alex_hou@163.com',
                       P_SERVER   => '127.0.0.1',
                       P_FILENAME => 'Z:\dbashell\monitor\daily_rep_&&today..log');
end;
/

exit;
Trackback

no comment untill now

Add your comment now

切换到手机版