/**配置ACL***/
begin
dbms_network_acl_admin.create_acl (
acl => ‘smtp_permissions.xml’, — or any other name
description => ‘SMTP Access’,
principal => ‘DBMGR’, — the user name trying to access the network resource
is_grant => TRUE,
privilege => ‘connect’,
start_date => null,
end_date => null
);
end;
/
commit;
begin
DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE(acl => ‘smtp_permissions.xml’,
principal => ‘DBMGR’,
is_grant => true,
privilege => ‘connect’);
end;
/
commit;
BEGIN
dbms_network_acl_admin.assign_acl (
acl => ‘smtp_permissions.xml’,
host => ‘10.10.8.1’, /*can be computer name or IP , wildcards are accepted as well for example – ‘*.us.oracle.com’*/
lower_port => 25,
upper_port => null
);
END;
/
commit;
/**创建发送邮件的存储过程***/
CREATE OR REPLACE PROCEDURE send_mail(
p_recipient VARCHAR2, — 邮件接收人
p_subject VARCHAR2, — 邮件标题
p_message VARCHAR2– 邮件正文
)
IS
–下面四个变量请根据实际邮件服务器进行赋值
v_mailhost VARCHAR2(30) := ‘10.10.8.1’; –SMTP服务器地址
v_user VARCHAR2(30) := ‘mymailuser’; –登录SMTP服务器的用户名
v_pass VARCHAR2(20) := ‘mypasswd’; –登录SMTP服务器的密码
v_sender VARCHAR2(50) := ‘mymailuser@dji.com ‘; –发送者邮箱,一般与 ps_user 对应
v_conn UTL_SMTP.connection; –到邮件服务器的连接
v_msg varchar2(4000); –邮件内容
BEGIN
v_conn := UTL_SMTP.open_connection(v_mailhost, 25);
UTL_SMTP.ehlo(v_conn, v_mailhost); –是用 ehlo() 而不是 helo() 函数
–否则会报:ORA-29279: SMTP 永久性错误: 503 5.5.2 Send hello first.
UTL_SMTP.command(v_conn, ‘AUTH LOGIN’); — smtp服务器登录校验
UTL_SMTP.command(v_conn,UTL_RAW.cast_to_varchar2(UTL_ENCODE.base64_encode(UTL_RAW.cast_to_raw(v_user))));
UTL_SMTP.command(v_conn,UTL_RAW.cast_to_varchar2(UTL_ENCODE.base64_encode(UTL_RAW.cast_to_raw(v_pass))));
UTL_SMTP.mail(v_conn, ‘<'||v_sender||'>‘); –设置发件人
UTL_SMTP.rcpt(v_conn, ‘<'||p_recipient||'>‘); –设置收件人
— 创建要发送的邮件内容 注意报头信息和邮件正文之间要空一行
v_msg :=’Date:’|| TO_CHAR(SYSDATE, ‘yyyy mm dd hh24:mi:ss’)
|| UTL_TCP.CRLF || ‘From: ‘|| v_sender || ”
|| UTL_TCP.CRLF || ‘To: ‘ || p_recipient || ”
|| UTL_TCP.CRLF || ‘Subject: ‘ || p_subject
|| UTL_TCP.CRLF || UTL_TCP.CRLF — 这前面是报头信息
|| p_message; — 这个是邮件正文
UTL_SMTP.open_data(v_conn); –打开流
UTL_SMTP.write_raw_data(v_conn, UTL_RAW.cast_to_raw(v_msg)); –这样写标题和内容都能用中文
UTL_SMTP.close_data(v_conn); –关闭流
UTL_SMTP.quit(v_conn); –关闭连接
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.put_line(DBMS_UTILITY.format_error_stack);
DBMS_OUTPUT.put_line(DBMS_UTILITY.format_call_stack);
END send_mail;
/
/**发送邮件**/
begin
send_mail(‘xxxxx@dji.com’,’Tablespace XX is full.’,’Tablespace XXX is NN full, please add more space.’);
end;
/