Quick and dirty script for making cold backups of KVM Virtual Machines

Note that this depends on “virsh”, the libvirt client, and “bzip2″.

Basically, what this script does is send a shutdown signal to each of the specified nodes, back up the disk images, and then bzip them in the background while it restarts the node. So having said this, you’ll want to make sure your services on your VM’s are set to shut down and start up gracefully when the OS is shut down / restarted.



#!/bin/bash

#
# This is who we'll back up
#
machines="Dev Test Foobar"

#
# Keep the house clean
#
days_to_keep="7"

#
# Store backups here. NFS to another machine would make sense. 
# so that your backups are not local.
#
backup_dir="/VirtualMachines/KVM/backups"

#
# Logs go here.
#
log_dir="/VirtualMachines/KVM/backups/logs"

#
# End parameters
#
#=================================================================

#
# Timestamp for the log file
#
right_now=`date '+%m%d%Y_%H%M%p'`

exec 1>/${log_dir}/backup_vms.${right_now}.log 2>&1

print_date() {
   date '+%m%d%Y_%H%M%p'
}

for machine in $machines
do
   if [[ ! -d ${backup_dir}/${machine} ]];
   then
      mkdir -p ${backup_dir}/${machine}
   fi

   echo "Backing up VM configuration"
   virsh dumpxml $machine > ${backup_dir}/${machine}/${machine}.xml

   echo "Sending shutdown signal to $machine"
   virsh shutdown $machine
   echo "   Return code: $?"
   
   echo -n "Waiting for machine to shut down "
   for i in 1 2 3 4 5
   do
      echo -n "."
      virsh list | grep -v "^$" | grep -v "^ Id" | grep -v "\-\-\-\-\-" | awk '{print $2" "$3}' | grep $machine | while read name state
      do
         if [[ $state -eq "running" ]]
         then
            sleep 60
         fi
      done
   done

   echo "Copying disk(s)"
   virsh domblklist $machine | grep -v "^$" | grep -v "^Target" | grep -v "\-\-\-\-\-" | awk '{print $2}' | while read disk
   do
      echo "   $disk ..."
      copy_disk="${backup_dir}/${machine}/`basename ${disk}`.`print_date`"
      echo "   Copying $disk to $copy_disk"
      fuser $disk 1>/dev/null 2>&1
      if (( $? == 0 ))
      then
         echo "   Disk $disk is still in use! "
      else
         echo "   Copy started at `print_date`"
         cp $disk $copy_disk
         echo "   Return code: $?"
         echo "   Copy ended at `print_date`"
         echo "   Backgrounding bzip of $copy_disk"
         nohup bzip2 $copy_disk &
      fi
   done

   echo "Starting machine $machine"
   virsh start $machine
   echo "   Return code: $?"
   echo

done

   echo "Removing old backups."
   find $backup_dir -type f -mtime +$days_to_keep -ls
   find $backup_dir -type f -mtime +$days_to_keep -exec rm -f {} \;

Oracletool v3.0.0 released!

News
=====

Just a reminder that I no longer test Oracletool with Oracle versions < 11.1.

All of the legacy HTML tags have been changed to use CSS rather than specifying style data using the old format. The size of the oracletool.pl executable has decreased dramatically, and it looks better. Let me know if there are any pages that are formatted incorrectly, it’s entirely possible that I’ve missed something.

***************
* IMPORTANT!! *
***************

There are changes to the themes variables in the oracletool.sam file that need to be copied into your oracletool.ini file, or you can create a new one from the supplied oracletool.ini. If you don’t do this, your fonts may look very small.

If you have a problem with font rendering, such as your fonts look very small, you may need to remove a browser cookie called “OracletoolProps”. Also, make sure you’ve made the changes to the themes in the oracletol.ini file.

Enhancements
============

Added a mechanism to search for the oracletool.ini config file on IIS web servers if it’s not in the same directory as Oracletool itself. Thanks to Praveen Hombaiah for the code change.

Added an interface for viewing the alert log, under the DB Admin section (Finally!). This requires the creation of a procedure under the “SYS” schema. Please see the file get_alertlog_lines.sql under /sql for more information. This also checks for “ORA-” messages in the lines displayed, and highlights them in a separate display.

Added a preference setting for the number of lines of the alert log to display.

Changed the displays of generated DDL to use textareas with scroll bars rather than just displaying the code. Much better for cutting and pasting.

Bug fixes
=========

Fixed a bug where when you select Session Info / Active and hit the refresh button, it would show all of the sessions. Thanks to Bryce Tutt for pointing it out.

Scrape a value from a web page from within Oracle using utl_http

Let’s say I want to get the current available version of Oracletool..


Create or replace procedure get_ot_version

as

   req                  UTL_HTTP.REQ;
   resp                 UTL_HTTP.RESP;
   matchcount           number;
   string               varchar2(1024);
   version              varchar2(20);
   errmsg               varchar2(1000);

Begin
 
   --
   -- Set the proxy server, if needed.
   -- 
   --utl_http.set_proxy('http://192.168.1.10:8080');
   --
   -- Make the HTTP request
   --
   req := utl_http.begin_request('http://www.oracletool.com');
   utl_http.set_header(req, 'User-Agent', 'Mozilla/4.0');
   --
   -- Loop through the response pieces
   --
   resp := utl_http.get_response(req);
   loop
      utl_http.read_line(resp, string, TRUE);
      --
      -- Look for a line with "Latest version is" in it, and parse out the version string.
      --
      Select instr(string,'Latest version is') into matchcount from dual;
      if (matchcount > 0) then
         Select regexp_replace(string,'.*Latest version is&nbsp;&nbsp;','') into string from dual;
         Select regexp_replace(string,' - Released.*','') into version from dual;
         dbms_output.put_line('Version: '||version);
      end if;
   end loop;
Exception
   when utl_http.end_of_body then
      utl_http.end_response(resp);
   when others then
      errmsg := substr(sqlerrm,1,1000);
      dbms_output.put_line('Exception raised during page scrape! '||errmsg);
End;
/

And then..

SQL> Set serveroutput on;
SQL> Exec get_ot_version;
Version: 2.3.3

PL/SQL procedure successfully completed.

:)

Procedure to get the alert log from within the database

Here’s a quick and easy procedure (if you’re on Oracle 11), to get the alert log from within the database. Because the alert log table (X$DBGALERTEXT) is an “X$”, you need to be SYSDBA in order to access it. So the best way to allow “normal” users access to it is to create a procedure. This will return a CLOB containing the lines of the alert log. This functionality will be included in Oracletool 2.3.4, btw.


Create or replace procedure get_alertlog_lines (num_lines in number, alertlog out clob)
/*
   This procedure should be owned by SYS, and you should grant
   execute privileges on it to whatever user you connect to your
   database as within Oracletool.

   Oracletool will not display the alertlog menu item unless this
   procedure exists.
*/

as

   v_alertlog clob;

Begin

   For i in (
      Select
         indx,
         to_char(originating_timestamp,'MM/DD/YYYY HH24:MI:SS') as timestamp,
         message_text as text
      from X$DBGALERTEXT
         where indx > (Select max(indx)-num_lines from X$DBGALERTEXT) order by indx asc)
   loop
      v_alertlog := v_alertlog||i.timestamp||': '||i.text;
   end loop;

   alertlog := v_alertlog;

End get_alertlog_lines;
/

--
-- Example grant
--
Grant execute on get_alertlog_lines to ADAM;

That’s it! let’s try it out via SQL*Plus! First thing I’m going to do is create a synonym for the procedure.


[oracle@mastiff /home/oracle] [DEMO]$ sqlplus adam/<password>

SQL*Plus: Release 11.2.0.3.0 Production on Thu Mar 22 09:25:30 2012
Copyright (c) 1982, 2011, Oracle.  All rights reserved.

Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

09:25:30 SQL> Set serveroutput on;
09:25:35 SQL> Create synonym get_alertlog_lines for sys.get_alertlog_lines;

Synonym created.

09:25:43 SQL> Declare
09:25:54 SQL> alertlog_lines clob;
09:26:10 SQL> Begin
09:26:14 SQL>    get_alertlog_lines(25,alertlog_lines);
09:26:38 SQL>    dbms_output.put_line(alertlog_lines);
09:26:54 SQL> End;
09:26:55 SQL> /
03/22/2012 03:51:08: Private strand flush not complete
03/22/2012 03:51:08: Current log# 2 seq# 3512 mem# 0:/apps/oracle/oradata/RMAN/onlinelog/o1_mf_2_5rg7qlfr_.log
03/22/2012 03:51:08: Current log# 2 seq# 3512 mem# 1:/apps/oracle/backup/flash_recovery_area/RMAN/onlinelog/o1_mf_2_5rg7qp8t_.log
03/22/2012 03:51:12: Thread 1 advanced to log sequence 3513 (LGWR switch)
03/22/2012 03:51:12:   Current log# 3 seq# 3513 mem# 0: /apps/oracle/oradata/RMAN/onlinelog/o1_mf_3_5rg7qsmw_.log
03/22/2012 03:51:12: Current log# 3 seq# 3513 mem# 1: /apps/oracle/backup/flash_recovery_area/RMAN/onlinelog/o1_mf_3_5rg7qwm0_.log
03/22/2012 03:51:18: Archived Log entry 3470 added for thread 1 sequence 3512 ID 0x5f45a87f dest 1:
03/22/2012 08:50:07: ALTER SYSTEM ARCHIVE LOG
03/22/2012 08:50:07: Thread 1 cannot allocate new log, sequence 3514
03/22/2012 08:50:07: Private strand flush not complete
03/22/2012 08:50:07:   Current log# 3 seq# 3513 mem# 0: /apps/oracle/oradata/RMAN/onlinelog/o1_mf_3_5rg7qsmw_.log
03/22/2012 08:50:07: Current log# 3 seq# 3513 mem# 1: /apps/oracle/backup/flash_recovery_area/RMAN/onlinelog/o1_mf_3_5rg7qwm0_.log
03/22/2012 08:50:09: Thread 1 advanced to log sequence 3514 (LGWR switch)
03/22/2012 08:50:09:   Current log# 1 seq# 3514 mem# 0: /apps/oracle/oradata/RMAN/onlinelog/o1_mf_1_5rg7q7wc_.log
03/22/2012 08:50:09: Current log# 1 seq# 3514 mem# 1: /apps/oracle/backup/flash_recovery_area/RMAN/onlinelog/o1_mf_1_5rg7qfn0_.log
03/22/2012 08:50:14: Archived Log entry 3471 added for thread 1 sequence 3513 ID 0x5f45a87f dest 1:
03/22/2012 08:50:19: ALTER SYSTEM ARCHIVE LOG
03/22/2012 08:50:20: Thread 1 cannot allocate new log, sequence 3515
03/22/2012 08:50:20: Private strand flush not complete
03/22/2012 08:50:20:   Current log# 1 seq# 3514 mem# 0: /apps/oracle/oradata/RMAN/onlinelog/o1_mf_1_5rg7q7wc_.log
03/22/2012 08:50:20: Current log# 1 seq# 3514 mem# 1: /apps/oracle/backup/flash_recovery_area/RMAN/onlinelog/o1_mf_1_5rg7qfn0_.log
03/22/2012 08:50:22: Thread 1 advanced to log sequence 3515 (LGWR switch)
03/22/2012 08:50:22:   Current log# 2 seq# 3515 mem# 0: /apps/oracle/oradata/RMAN/onlinelog/o1_mf_2_5rg7qlfr_.log
03/22/2012 08:50:22: Current log# 2 seq# 3515 mem# 1: /apps/oracle/backup/flash_recovery_area/RMAN/onlinelog/o1_mf_2_5rg7qp8t_.log
03/22/2012 08:50:24: Archived Log entry 3472 added for thread 1 sequence 3514 ID 0x5f45a87f dest 1:

PL/SQL procedure successfully completed.

:)

Sending email from PL/SQL, with multiple attachments

Want to be able to send email from within Oracle, to multiple recipients, and with attachments? Well, allrightythen. The attachments will be taken from the OS, but this could be easily modified to take them from an Oracle table of your choosing. Some of this code I gathered from other places, and a bunch of it is mine. In the end, this is the most complete PL/SQL email sending package that I know of. When we’re done, we’ll have a package that looks like below, and we’ll execute it as so..


Begin
   send_email.send(
   ToList=>             'adam@oracletool.com',
   Subject=>            'Test email with attachments',
   Body=>               'Here is the body',
   FromEmail=>          'Adam@Oracletool.com',
   FromHost=>           'Oracletool.com',
   SMTPServer=>         'localhost',
   AttachList=>         'send_email.sql,login.sql',
   Directory=>          'ATTACHMENTS');
End;
/

08:25:52 DEMO (ADAM) > Desc send_email;
FUNCTION GET_MIME_TYPE RETURNS VARCHAR2
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 FILENAME                       VARCHAR2                IN
PROCEDURE SEND
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 TOLIST                         VARCHAR2                IN
 SUBJECT                        VARCHAR2                IN
 BODY                           VARCHAR2                IN
 FROMEMAIL                      VARCHAR2                IN     DEFAULT
 FROMHOST                       VARCHAR2                IN     DEFAULT
 SMTPSERVER                     VARCHAR2                IN     DEFAULT
 ATTACHLIST                     VARCHAR2                IN     DEFAULT
 DIRECTORY                      VARCHAR2                IN     DEFAULT
FUNCTION SPLIT RETURNS SPLIT_TBL
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 P_LIST                         VARCHAR2                IN
 P_DEL                          VARCHAR2                IN     DEFAULT

Couple of prerequisites here. First of all, if you want to send attachments from the OS, you’ll need to create an Oracle DIRECTORY object to point to the OS directory. Here’s an example.


Create or replace directory ATTACHMENTS as '/home/oracle/attachments';

You’ll then reference that directory from the send_email package.

Next, we need to allow our user to contact the email server, in this case, localhost, as I’ve got a local email server running that allows connections locally. If you’re running Oracle 11.1.0.6 or greater, you’ll need to create an ACL for the user, and we’re going to use a great procedure I found for this called, you guessed it, create_acl from Metalink note# 557070.1. If you don’t add an ACL, you’ll be getting to know an error like “ORA-24247: network access denied by access control list (ACL)”

This would be run as the “SYS” user, by the way.


create or replace procedure create_acl(
  aacl       varchar2,
  acomment   varchar2,
  aprincipal varchar2,
  aisgrant   boolean,
  aprivilege varchar2,
  aserver    varchar2,
  aport      number)
is
begin  
  begin
    DBMS_NETWORK_ACL_ADMIN.DROP_ACL(aacl);
     dbms_output.put_line('ACL dropped.....'); 
  exception
    when others then
      dbms_output.put_line('Error dropping ACL: '||aacl);
      dbms_output.put_line(sqlerrm);
  end;
  begin
    DBMS_NETWORK_ACL_ADMIN.CREATE_ACL(aacl,acomment,aprincipal,aisgrant,aprivilege);
    dbms_output.put_line('ACL created.....'); 
  exception
    when others then
      dbms_output.put_line('Error creating ACL: '||aacl);
      dbms_output.put_line(sqlerrm);
  end;  
  begin
    DBMS_NETWORK_ACL_ADMIN.ASSIGN_ACL(aacl,aserver,aport);
    dbms_output.put_line('ACL assigned.....');         
  exception
    when others then
      dbms_output.put_line('Error assigning ACL: '||aacl);
      dbms_output.put_line(sqlerrm);
  end;   
  commit;
  dbms_output.put_line('ACL commited.....'); 
end;
/
show error

And then it’s executed via the following. This example gives the user ADAM privileges to make an outbound connection to port 25 on any server.


begin
  create_acl(
    'adam_smtp_acl.xml',
    'ACL for ADAM to allow SMTP outbound',
    'ADAM',
    TRUE,
    'connect',
    '*',
    25);
end;
/

We need to create a type to support the below package


Create or replace TYPE "SPLIT_TBL"  AS TABLE OF VARCHAR2(32767);
/

OK then, let’s create the send_email package!


CREATE OR REPLACE package send_email as

   Function get_mime_type
   (
      FileName          in      varchar2
   ) return varchar2;

   Function split
   (
      p_list            in      varchar2,
      p_del             in      varchar2 := ','
   ) return split_tbl pipelined;

   Procedure send (
      Tolist            in      varchar2,
      Subject           in      varchar2,
      Body              in      varchar2,
      FromEmail         in      varchar2 default 'DoNotReply@Nowhere.Com',
      FromHost          in      varchar2 default utl_inaddr.get_host_name,
      SmtpServer        in      varchar2 default 'localhost',
      AttachList        in      varchar2 default null,
      Directory         in      varchar2 default null
   );

End send_email;
/

Show error;

CREATE OR REPLACE package body send_email as

   Function get_mime_type
   (
      FileName          in      varchar2
   ) return varchar2
   is
      NewFileName               varchar2(250);
      type mime_type_arr        is table of varchar2(250) index by varchar2(20);
      mime_types                mime_type_arr;
      mime_type                 varchar2(250);
      extension                 varchar2(250);
      
   begin
      --
      -- Populate the mime_types array
      --
      mime_types('323')         := 'text/h323';
      mime_types('acx')         := 'application/internet-property-stream';
      mime_types('ai')          := 'application/postscript';
      mime_types('aif')         := 'audio/x-aiff';
      mime_types('aifc')        := 'audio/x-aiff';
      mime_types('aiff')        := 'audio/x-aiff';
      mime_types('asf')         := 'video/x-ms-asf';
      mime_types('asr')         := 'video/x-ms-asf';
      mime_types('asx')         := 'video/x-ms-asf';
      mime_types('au')          := 'audio/basic';
      mime_types('avi')         := 'video/x-msvideo';
      mime_types('axs')         := 'application/olescript';
      mime_types('bas')         := 'text/plain';
      mime_types('bcpio')       := 'application/x-bcpio';
      mime_types('bin')         := 'application/octet-stream';
      mime_types('bmp')         := 'image/bmp';
      mime_types('c')           := 'text/plain';
      mime_types('cat')         := 'application/vnd.ms-pkiseccat';
      mime_types('cdf')         := 'application/x-cdf';
      mime_types('cer')         := 'application/x-x509-ca-cert';
      mime_types('class')       := 'application/octet-stream';
      mime_types('clp')         := 'application/x-msclip';
      mime_types('cmx')         := 'image/x-cmx';
      mime_types('cod')         := 'image/cis-cod';
      mime_types('cpio')        := 'application/x-cpio';
      mime_types('crd')         := 'application/x-mscardfile';
      mime_types('crl')         := 'application/pkix-crl';
      mime_types('crt')         := 'application/x-x509-ca-cert';
      mime_types('csh')         := 'application/x-csh';
      mime_types('css')         := 'text/css';
      mime_types('dcr')         := 'application/x-director';
      mime_types('der')         := 'application/x-x509-ca-cert';
      mime_types('dir')         := 'application/x-director';
      mime_types('dll')         := 'application/x-msdownload';
      mime_types('dms')         := 'application/octet-stream';
      mime_types('doc')         := 'application/msword';
      mime_types('dot')         := 'application/msword';
      mime_types('dvi')         := 'application/x-dvi';
      mime_types('dxr')         := 'application/x-director';
      mime_types('eps')         := 'application/postscript';
      mime_types('etx')         := 'text/x-setext';
      mime_types('evy')         := 'application/envoy';
      mime_types('exe')         := 'application/octet-stream';
      mime_types('fif')         := 'application/fractals';
      mime_types('flr')         := 'x-world/x-vrml';
      mime_types('gif')         := 'image/gif';
      mime_types('gtar')        := 'application/x-gtar';
      mime_types('gz')          := 'application/x-gzip';
      mime_types('h')           := 'text/plain';
      mime_types('hdf')         := 'application/x-hdf';
      mime_types('hlp')         := 'application/winhlp';
      mime_types('hqx')         := 'application/mac-binhex40';
      mime_types('hta')         := 'application/hta';
      mime_types('htc')         := 'text/x-component';
      mime_types('htm')         := 'text/html';
      mime_types('html')        := 'text/html';
      mime_types('htt')         := 'text/webviewhtml';
      mime_types('ico')         := 'image/x-icon';
      mime_types('ief')         := 'image/ief';
      mime_types('iii')         := 'application/x-iphone';
      mime_types('ins')         := 'application/x-internet-signup';
      mime_types('isp')         := 'application/x-internet-signup';
      mime_types('jfif')        := 'image/pipeg';
      mime_types('jpe')         := 'image/jpeg';
      mime_types('jpeg')        := 'image/jpeg';
      mime_types('jpg')         := 'image/jpeg';
      mime_types('js')          := 'application/x-javascript';
      mime_types('latex')       := 'application/x-latex';
      mime_types('lha')         := 'application/octet-stream';
      mime_types('lsf')         := 'video/x-la-asf';
      mime_types('lsx')         := 'video/x-la-asf';
      mime_types('lzh')         := 'application/octet-stream';
      mime_types('m13')         := 'application/x-msmediaview';
      mime_types('m14')         := 'application/x-msmediaview';
      mime_types('m3u')         := 'audio/x-mpegurl';
      mime_types('man')         := 'application/x-troff-man';
      mime_types('mdb')         := 'application/x-msaccess';
      mime_types('me')          := 'application/x-troff-me';
      mime_types('mht')         := 'message/rfc822';
      mime_types('mhtml')       := 'message/rfc822';
      mime_types('mid')         := 'audio/mid';
      mime_types('mny')         := 'application/x-msmoney';
      mime_types('mov')         := 'video/quicktime';
      mime_types('movie')       := 'video/x-sgi-movie';
      mime_types('mp2')         := 'video/mpeg';
      mime_types('mp3')         := 'audio/mpeg';
      mime_types('mpa')         := 'video/mpeg';
      mime_types('mpe')         := 'video/mpeg';
      mime_types('mpeg')        := 'video/mpeg';
      mime_types('mpg')         := 'video/mpeg';
      mime_types('mpp')         := 'application/vnd.ms-project';
      mime_types('mpv2')        := 'video/mpeg';
      mime_types('ms')          := 'application/x-troff-ms';
      mime_types('mvb')         := 'application/x-msmediaview';
      mime_types('nws')         := 'message/rfc822';
      mime_types('oda')         := 'application/oda';
      mime_types('p10')         := 'application/pkcs10';
      mime_types('p12')         := 'application/x-pkcs12';
      mime_types('p7b')         := 'application/x-pkcs7-certificates';
      mime_types('p7c')         := 'application/x-pkcs7-mime';
      mime_types('p7m')         := 'application/x-pkcs7-mime';
      mime_types('p7r')         := 'application/x-pkcs7-certreqresp';
      mime_types('p7s')         := 'application/x-pkcs7-signature';
      mime_types('pbm')         := 'image/x-portable-bitmap';
      mime_types('pdf')         := 'application/pdf';
      mime_types('pfx')         := 'application/x-pkcs12';
      mime_types('pgm')         := 'image/x-portable-graymap';
      mime_types('pko')         := 'application/ynd.ms-pkipko';
      mime_types('pma')         := 'application/x-perfmon';
      mime_types('pmc')         := 'application/x-perfmon';
      mime_types('pml')         := 'application/x-perfmon';
      mime_types('pmr')         := 'application/x-perfmon';
      mime_types('pmw')         := 'application/x-perfmon';
      mime_types('pnm')         := 'image/x-portable-anymap';
      mime_types('pot,')        := 'application/vnd.ms-powerpoint';
      mime_types('ppm')         := 'image/x-portable-pixmap';
      mime_types('pps')         := 'application/vnd.ms-powerpoint';
      mime_types('ppt')         := 'application/vnd.ms-powerpoint';
      mime_types('prf')         := 'application/pics-rules';
      mime_types('ps')          := 'application/postscript';
      mime_types('pub')         := 'application/x-mspublisher';
      mime_types('qt')          := 'video/quicktime';
      mime_types('ra')          := 'audio/x-pn-realaudio';
      mime_types('ram')         := 'audio/x-pn-realaudio';
      mime_types('ras')         := 'image/x-cmu-raster';
      mime_types('rgb')         := 'image/x-rgb';
      mime_types('rmi')         := 'audio/mid';
      mime_types('roff')        := 'application/x-troff';
      mime_types('rtf')         := 'application/rtf';
      mime_types('rtx')         := 'text/richtext';
      mime_types('scd')         := 'application/x-msschedule';
      mime_types('sct')         := 'text/scriptlet';
      mime_types('setpay')      := 'application/set-payment-initiation';
      mime_types('setreg')      := 'application/set-registration-initiation';
      mime_types('sh')          := 'application/x-sh';
      mime_types('shar')        := 'application/x-shar';
      mime_types('sit')         := 'application/x-stuffit';
      mime_types('snd')         := 'audio/basic';
      mime_types('spc')         := 'application/x-pkcs7-certificates';
      mime_types('spl')         := 'application/futuresplash';
      mime_types('src')         := 'application/x-wais-source';
      mime_types('sst')         := 'application/vnd.ms-pkicertstore';
      mime_types('stl')         := 'application/vnd.ms-pkistl';
      mime_types('stm')         := 'text/html';
      mime_types('svg')         := 'image/svg+xml';
      mime_types('sv4cpio')     := 'application/x-sv4cpio';
      mime_types('sv4crc')      := 'application/x-sv4crc';
      mime_types('swf')         := 'application/x-shockwave-flash';
      mime_types('t')           := 'application/x-troff';
      mime_types('tar')         := 'application/x-tar';
      mime_types('tcl')         := 'application/x-tcl';
      mime_types('tex')         := 'application/x-tex';
      mime_types('texi')        := 'application/x-texinfo';
      mime_types('texinfo')     := 'application/x-texinfo';
      mime_types('tgz')         := 'application/x-compressed';
      mime_types('tif')         := 'image/tiff';
      mime_types('tiff')        := 'image/tiff';
      mime_types('tr')          := 'application/x-troff';
      mime_types('trm')         := 'application/x-msterminal';
      mime_types('tsv')         := 'text/tab-separated-values';
      mime_types('txt')         := 'text/plain';
      mime_types('uls')         := 'text/iuls';
      mime_types('ustar')       := 'application/x-ustar';
      mime_types('vcf')         := 'text/x-vcard';
      mime_types('vrml')        := 'x-world/x-vrml';
      mime_types('wav')         := 'audio/x-wav';
      mime_types('wcm')         := 'application/vnd.ms-works';
      mime_types('wdb')         := 'application/vnd.ms-works';
      mime_types('wks')         := 'application/vnd.ms-works';
      mime_types('wmf')         := 'application/x-msmetafile';
      mime_types('wps')         := 'application/vnd.ms-works';
      mime_types('wri')         := 'application/x-mswrite';
      mime_types('wrl')         := 'x-world/x-vrml';
      mime_types('wrz')         := 'x-world/x-vrml';
      mime_types('xaf')         := 'x-world/x-vrml';
      mime_types('xbm')         := 'image/x-xbitmap';
      mime_types('xla')         := 'application/vnd.ms-excel';
      mime_types('xlc')         := 'application/vnd.ms-excel';
      mime_types('xlm')         := 'application/vnd.ms-excel';
      mime_types('xls')         := 'application/vnd.ms-excel';
      mime_types('xlt')         := 'application/vnd.ms-excel';
      mime_types('xlw')         := 'application/vnd.ms-excel';
      mime_types('xof')         := 'x-world/x-vrml';
      mime_types('xpm')         := 'image/x-xpixmap';
      mime_types('xwd')         := 'image/x-xwindowdump';
      mime_types('z')           := 'application/x-compress';
      mime_types('zip')         := 'application/zip';
      --
      -- Determine the file extension
      --
      dbms_output.put_line('Splitting file '||FileName||' to get extension.');
      for i in (Select column_value as extension from table(split(FileName,'.'))) loop
         extension := i.extension;
      end loop;
      --
      -- use the extension to determine the MIME type
      --
      if mime_types.exists(extension) then
         mime_type := mime_types(extension);
      else
         --
         -- Default to 'text/plain' if not found
         --
         mime_type := 'text/plain';
      end if;

      dbms_output.put_line('Extension is '||extension);
      dbms_output.put_line('mime_type is '||mime_type);
        
      return mime_type;

   end get_mime_type;

   Function split
   (
      p_list varchar2,
      p_del varchar2 := ','
   ) return split_tbl pipelined
   is
      l_idx    pls_integer;
      l_list    varchar2(32767) := p_list;
      l_value    varchar2(32767);
   begin
      loop
         l_idx := instr(l_list,p_del);
         if l_idx > 0 then
            pipe row(substr(l_list,1,l_idx-1));
            l_list := substr(l_list,l_idx+length(p_del));
         else
            pipe row(l_list);
            exit;
         end if;
      end loop;
      return;
   end split;

   Procedure send (
      ToList            in      varchar2,
      Subject           in      varchar2,
      Body              in      varchar2,
      FromEmail         in      varchar2 default 'DoNotReply@Nowhere.Com',
      SmtpServer        in      varchar2 default 'localhost',
      AttachList        in      varchar2 default null,
      Directory         in      varchar2 default null
    ) is

      smtp            utl_smtp.CONNECTION;
      reply           utl_smtp.REPLY;
      file_handle     bfile;
      file_exists     boolean;
      block_size      number;
      file_len        number;
      pos             number;
      total           number;
      read_bytes      number;
      data            raw(200);
      my_code         number;
      my_errm         varchar2(32767);
      mime_type       varchar2(50);
      myhostname      varchar2(255);
      att_table       dbms_utility.uncl_array;
      att_count       number;
      tablen          binary_integer;
      loopcount       number;

       Procedure WriteLine(
          line          in      varchar2 default null
       ) is

       Begin
          utl_smtp.Write_Data( smtp, line||utl_tcp.CRLF );
       End;

    Begin

      Select sys_context('USERENV','SERVER_HOST') into myhostname from dual;

      dbms_output.put_line('ToList:     '||ToList);
      dbms_output.put_line('Subject:    '||Subject);
      dbms_output.put_line('Body:       '||Body);
      dbms_output.put_line('FromEmail:  '||FromEmail);
      dbms_output.put_line('SmtpServer: '||SmtpServer);
      dbms_output.put_line('AttachList: '||AttachList);
      dbms_output.put_line('Directory:  '||Directory);
      dbms_output.put_line('ToList:     '||ToList);
      dbms_output.put_line('myhostname: '||myhostname);

      dbms_output.put_line('Opening connection to '||SmtpServer);
      smtp := utl_smtp.OPEN_CONNECTION( SmtpServer, 25 );
      reply := utl_smtp.HELO( smtp, myhostname);
      reply := utl_smtp.MAIL( smtp, FromEmail );

      --
      -- Split up the recipient list
      --
      for i in (Select column_value as recipient from table(split(ToList))) loop
         dbms_output.put_line('Recipient: '||i.recipient);
         reply := utl_smtp.RCPT( smtp, i.recipient);
      end loop;

      reply := utl_smtp.open_data( smtp );

      WriteLine( 'From: '||FromEmail);

      --
      -- Split up the recipient list (again)
      --
      for i in (Select column_value as recipient from table(split(ToList))) loop
         WriteLine( 'To: '||i.recipient);
      end loop;

      WriteLine( 'Subject: '||Subject );
      WriteLine( 'Content-Type: multipart/mixed; boundary="gc0p4Jq0M2Yt08jU534c0p"' );
      WriteLine( 'MIME-Version: 1.0' );
      WriteLine;

      -- start of boundary payloads
      WriteLine( '--gc0p4Jq0M2Yt08jU534c0p' );
      WriteLine( 'Content-Type: text/plain' );
      WriteLine;
      WriteLine(  Body );
      WriteLine;
      WriteLine( '--gc0p4Jq0M2Yt08jU534c0p' );

      dbms_output.put_line('Starting attachment segment');
      dbms_output.put_line('Directory: '||Directory);
      dbms_output.put_line('AttachList: '||AttachList);

      --
      -- Split up the attachment list
      --
      loopcount := 0; 
      Select count(*) into att_count from table(split(AttachList));
      if AttachList is not null and Directory is not null then
         for i in (Select ltrim(rtrim(column_value)) as attachment from table(split(AttachList))) loop
            loopcount := loopcount +1;
            dbms_output.put_line('Attaching: '||Directory||'/'||i.attachment);
            utl_file.fgetattr(Directory, i.attachment, file_exists, file_len, block_size);
            if file_exists then
               dbms_output.put_line('Getting mime_type for the attachment');
               Select get_mime_type(i.attachment) into mime_type from dual;
               WriteLine( 'Content-Type: '||mime_type );
               WriteLine( 'Content-Transfer-Encoding: base64');
               WriteLine( 'Content-Disposition: attachment; filename="'||i.attachment||'"' );
               WriteLine;
               file_handle := bfilename(Directory,i.attachment);
               pos := 1;
               total := 0;
               file_len := dbms_lob.getlength(file_handle);
               dbms_lob.open(file_handle,dbms_lob.lob_readonly);

               loop
                  if pos + 57 - 1 > file_len then
                     read_bytes := file_len - pos + 1;
                     --dbms_output.put_line('Last read - Start: '||pos);
                  else
                     --dbms_output.put_line('Reading - Start: '||pos);
                     read_bytes := 57;
                  end if;
                  total := total + read_bytes;
                  dbms_lob.read(file_handle,read_bytes,pos,data);
                  utl_smtp.write_raw_data(smtp,utl_encode.base64_encode(data));
                  --utl_smtp.write_raw_data(smtp,data);
                  pos := pos + 57;
                  if pos > file_len then
                     exit;
                  end if;
               end loop;
               dbms_output.put_line('Length was '||file_len);
               dbms_lob.close(file_handle);
               if (loopcount < att_count) then
                  WriteLine;
                  WriteLine( '--gc0p4Jq0M2Yt08jU534c0p' );
                else
                  WriteLine;
                  WriteLine( '--gc0p4Jq0M2Yt08jU534c0p--' );
                  dbms_output.put_line('Writing end boundary');
                end if;
            else
               dbms_output.put_line('Skipping: '||Directory||'/'||i.attachment||'Does not exist.');
            end if;
         end loop;
      end if;

      reply := utl_smtp.close_data( smtp );
      reply := utl_smtp.quit( smtp );

   exception
      when others then
         my_code := sqlcode;
         my_errm := sqlerrm;
         dbms_output.put_line('Error code ' || my_code || ': ' || my_errm);
  end;

end send_email;
/

Once you’ve created the send_email package, and added an ACL for your user (if necessary), you should be ready to fire off an email. :)

How to read xml files from the OS, parse them, and load the data into Oracle

Want to read xml files from the OS, parse them, and load the data into Oracle, all from PL/SQL (and a small Java stored procedure :) )? Well allrightythen!

* This will all be done from within the database.

* The OS directories will be referenced only by Oracle directory name, not actual directory name.

Disclaimer: This code is not all mine. I’ve collected snippets from several different places, and wrote a bunch of my own as well. The goal was to take it all and put it into one post so that you can go from start to finish in one place.

We’ll be doing the following in this post

1) List the source directory
2) Loop through the file names
3) Parse the XML files
4) Insert the data (not the XML file) into a table
5) Move the file to a destination directory

Source directory: /tmp/xml_inbound
Destination directory: /tmp/xml_archive

Example XML file


<?xml version="1.0" encoding="UTF-8"?>
<Data>
   <Header>
      <ID>Batch 1</ID>
      <AnimalCount>2</AnimalCount>
      <BreedCount>6</BreedCount>
   </Header>
   <Animals>
      <Animal>
         <ID>1</ID>
         <Type>Dog</Type>
         <BreedList>
               <Breed>Bullmastiff</Breed>
               <Breed>Dalmation</Breed>
               <Breed>American Bulldog</Breed>
         </BreedList>
      </Animal>
      <Animal>
         <ID>2</ID>
         <Type>Cat</Type>
         <BreedList>
            <Breed>Tabby</Breed>
            <Breed>Manx</Breed>
            <Breed>Savannah</Breed>
         </BreedList>
      </Animal>
   </Animals>
</Data>

Let’s do a little OS level setup, as the “oracle” user


# mkdir /tmp/xml_inbound
# mkdir /tmp/xml_archive

Copy the above XML into a file called /tmp/xml_inbound/<anything>.xml 

And database level – Note that I’m granting privileges to “ADAM”.
That might not be you..


sqlplus "/ as sysdba"

11:08:35 DEMO (SYS) > Create directory xml_inbound as '/tmp/xml_inbound';
11:08:43 DEMO (SYS) > Create directory xml_archive as '/tmp/xml_archive';
11:08:51 DEMO (SYS) > Grant read,write on directory xml_inbound to ADAM;
11:08:58 DEMO (SYS) > Grant read,write on directory xml_archive to ADAM;
--
-- This is for the Java stored procedure we'll create below. 
-- It's only used for reading the directory contents.
--
11:09:03 DEMO (SYS) > Exec dbms_java.grant_permission( 'ADAM','SYS:java.io.FilePermission','/tmp/xml_inbound', 'read');

First, we need to be able to get a directory listing from the OS. We’ll use Java for this. One procedure will populate the DIR_LIST global temporary table with the file names. The table will be cleared when we do a commit. The other two procedures are for bringing the data in as a variable, and renaming (moving) the OS file.

As your non-SYS database user from now on.. For me it’s “ADAM”


Create global temporary table DIR_LIST
(
   filename varchar2(255)
) on commit delete rows;

The below code will create the following procedures


dir_list                Get a listing of files from a directory
get_xml_file_from_os    Load an XML file into a variable of XMLType
move_os_file            Used to move files from inbound to archive

Create or replace
and compile java source named "DirList"
as
import java.io.*;
import java.sql.*;

public class DirList
{
   public static void getList(String oracle_directory)
                   throws SQLException
   {
      String os_directory;
      #sql {Select directory_path into :os_directory from all_directories where directory_name = upper(:oracle_directory)};

      File path = new File( os_directory );
      String[] list = path.list();
      String element;

      for(int i = 0; i < list.length; i++)
      {
         element = list[i];
         #sql { INSERT INTO DIR_LIST (FILENAME) VALUES (:element) };
      }
   }

}
/

Create or replace
procedure get_dir_list( oracle_directory in varchar2 )
   as language java
   name 'DirList.getList( java.lang.String )';
/

Create or replace procedure move_os_file
(
   source_directory     in varchar2,
   source_file          in varchar2,
   target_directory     in varchar2,
   target_file          in varchar2
)

as

   srcdir               varchar2(255) := upper(source_directory);
   tgtdir               varchar2(255) := upper(target_directory);

begin

   --
   -- NOTE: If you're getting the all-too-familiar
   -- ORA-29292: file rename operation failed
   -- and you're SURE that your directory names are correct,
   -- and you're SURE that your privileges are correct, both at the 
   -- OS level, and within the database, there's one last thing that
   -- can get you. I learned the hard way that this command will NOT
   -- work successfully renaming a file from one filesystem to another,
   -- at least when those filesystems are NFS mounted. That is all. 
   --
   utl_file.frename(srcdir,source_file,tgtdir,target_file,TRUE);

end move_os_file;
/

Create or replace procedure get_xml_file_from_os 
(
   oracle_directory     in varchar2, 
   filename             in varchar2 ,
   o_xml                out xmltype
)

as

    dest_clob           clob;
    src_clob            bfile;
    dst_offset          number := 1 ;
    src_offset          number := 1 ;
    lang_ctx            number := DBMS_LOB.DEFAULT_LANG_CTX;
    warning             number;
    os_directory        varchar2(255);
    ora_directory       varchar2(255);

begin

   ora_directory := upper(oracle_directory);

   Select directory_path 
      into os_directory 
   from all_directories
   where directory_name = ora_directory;

   dbms_lob.createtemporary(dest_clob,true);

   dbms_output.put_line('OS directory: '||os_directory);
   dbms_output.put_line('Oracle directory: '||ora_directory);
   dbms_output.put_line('File: '||filename);
   src_clob := bfilename(ora_directory, filename);

   dbms_output.put_line('Opening lob'); 
   dbms_lob.open(src_clob,DBMS_LOB.LOB_READONLY);

   dbms_output.put_line('Loading lob');
   dbms_lob.LoadCLOBFromFile(
      dest_lob     => dest_clob,
      src_bfile    => src_clob,
      amount       => DBMS_LOB.GETLENGTH(src_clob),
      dest_offset  => dst_offset,
      src_offset   => src_offset,
      bfile_csid   => DBMS_LOB.DEFAULT_CSID,
      lang_context => lang_ctx,
      warning      => warning
   );

   dbms_lob.close(src_clob);

   o_xml := xmltype(dest_clob);

end get_xml_file_from_os;
/

Now that we can read files from the OS, we need to parse them and insert the data. Let’s create a couple of tables to support this.


Create table ANIMALS
(
   animal_id   number,
   type        varchar2(20)
);

Create table BREEDS
(
   animal_id    number,
   breed        varchar2(255)
);

And finally, a stored procedure to pull it all together. Here’s where we’ll do the XML parsing and inserting into the database.


Create or replace procedure process_xml

as

   v_XML                                XMLType;
   v_rowcount                           number;

   --
   -- Header variables
   --
   v_BatchID                            varchar2(20);
   v_AnimalCount                        number;
   v_BreedCount                         number;

   --
   -- Animal variables
   --
   v_AnimalID                           ANIMALS.ANIMAL_ID%TYPE;
   v_AnimalType                         ANIMALS.TYPE%TYPE;

   --
   -- Breed variables
   --
   v_BreedID                            BREEDS.ANIMAL_ID%TYPE;
   v_Breed                              BREEDS.BREED%TYPE;

Begin

   dbms_output.put_line('Getting directory listing');
   --
   -- The records in the DIR_LIST table will be removed on commit!
   --
   get_dir_list('XML_INBOUND');
   for i in (select filename from dir_list where upper(filename) like '%.XML')
   loop
      v_rowcount := 0;
      dbms_output.put_line('Filename: '||i.filename);
      get_xml_file_from_os('XML_INBOUND',i.filename,v_XML);
      dbms_output.put_line('File loaded');

      --
      -- Extract the Header
      --
      dbms_output.put_line('Getting Batch ID');
      v_BatchID         := v_XML.extract('/Data/Header/ID/text()').getStringVal();
      dbms_output.put_line('Getting Animal Count');
      v_AnimalCount     := v_XML.extract('/Data/Header/AnimalCount/text()').getNumberVal();
      v_BreedCount      := v_XML.extract('/Data/Header/BreedCount/text()').getNumberVal();
      dbms_output.put_line('Batch ID: '||v_BatchID);
      dbms_output.put_line('Animal Count: '||v_AnimalCount);
      dbms_output.put_line('Breed Count: '||v_BreedCount);

      --
      -- Loop through the animals
      --
      v_AnimalCount := 1;
      While v_XML.existsNode('/Data/Animals/Animal['||v_AnimalCount||']') = 1

      --
      -- Loop through Animals
      --
      loop
         v_AnimalID     :=  v_XML.extract('/Data/Animals/Animal['||v_AnimalCount||']/ID/text()').getNumberVal();
         v_AnimalType   :=  v_XML.extract('/Data/Animals/Animal['||v_AnimalCount||']/Type/text()').getStringVal();
         dbms_output.put_line('AnimalID: '||v_AnimalID);
         dbms_output.put_line('AnimalType: '||v_AnimalType);

         Insert into ANIMALS values (v_AnimalID,v_AnimalType);

         --
         -- Loop through breeds
         --
         v_BreedCount := 1;
         While v_XML.existsNode('/Data/Animals/Animal['||v_AnimalCount||']/BreedList/Breed['||v_BreedCount||']') = 1
         loop
            v_Breed     :=  v_XML.extract('/Data/Animals/Animal['||v_AnimalCount||']/BreedList/Breed['||v_BreedCount||']/text()').getStringVal();
            dbms_output.put_line('Breed: '||v_Breed);

            Insert into BREEDS values (v_AnimalID,v_Breed);

            v_BreedCount := v_BreedCount + 1;
   
         end loop;

         v_BreedCount := 1;
         v_AnimalCount := v_AnimalCount + 1;

      end loop;

      v_AnimalCount := 1;

      dbms_output.put_line('Moving file '||i.filename);
      move_os_file('XML_INBOUND',i.filename,'XML_ARCHIVE',i.filename);

   end loop;

   Commit;

End process_xml;
/

And that’s it! Now, let’s execute it and see what happens :)
Note: My xml file is called test1.xml


10:46:41 DEMO (ADAM) > Exec process_xml;
Getting directory listing
Filename: test1.xml
OS directory: /tmp/xml_inbound
Oracle directory: XML_INBOUND
File: test1.xml
Opening lob
Loading lob
File loaded
Getting Batch ID
Getting Animal Count
Batch ID: Batch 1
Animal Count: 2
Breed Count: 6
AnimalID: 1
AnimalType: Dog
Breed: Bullmastiff
Breed: Dalmation
Breed: American Bulldog
AnimalID: 2
AnimalType: Cat
Breed: Tabby
Breed: Manx
Breed: Savannah
Moving file test1.xml

Is the data there?


10:49:03 RMAN (ADAM) > Select count(*) from animals;
         2

10:49:11 RMAN (ADAM) > Select count(*) from breeds;
         6

Yep!

And if you look at /tmp/xml_archive..


[oracle@mastiff /home/oracle] [RMAN]$ ls /tmp/xml_archive
test1.xml

The file has been moved! That’s all folks!

Oracletool v2.3.3 released!

Not a lot added to this version in terms of functionality, but lots under the covers. Much cleanup was done in terms of checking for older versions of Oracle, all the way back to version 7. Oracletool is showing her age..

No longer testing with Oracle 7 / 8 / 9 / 10, and queries no longer tailored for these versions.

Enhancements
============

Added search for constraints to search box.
Added additional info when displaying user account info

Bug fixes
=========

Fixed bug where passwords were being truncated to 20 characters in password entry box.
Thanks to Jim Bouma for pointing it out.