Alert Log Oracle Perl RSS SQL

Creating a feed with ORA-00600 errors

Instead of having to look at your different alert logs for ORA-00600 errors frequently, why not have them come to you? This post will, as promised, show the Perl code needed to publish a feed with ORA-00600 errors. This is building on the previous two posts that shows how to create an external table for the alert log and how to pull out all information for an ORA-00600 so each fetch retrieves one the data you’re interested in.

The feed I’m using is a RSS 2.0 format. All feeds are fairly closely related so you can change it or provide different ones if you want to. You’ll have to look up the different formats and then make the changes you want to this code.

The script I have here is a simplified version that removes all the usual dynamic nature and flexibility with parameters I usually have. This is done for brevity and to focus the script on the task at hand – delivering the ORA-00600 errors to your newsreader soon after they occur.

The script is not pretty and it could be written much nicer with use of modules such as XML::RSS. Unfortunately that module has a chain of dependencies that I didn’t want to satisfy, so I’m creating the tags the old fashioned hard coded way. If you are to do a lot feeds with Perl, you will want to get that module installed.

!/usr/bin/perl
require v5.6;
use strict;
use CGI qw(:standard :html3 :netscape);
use CGI::Carp;
use DBI;
use DBD::Oracle qw(:ora_session_modes);

my ($ORACLE_HOME, $DBH);

if ( $ENV{TWO_TASK} ) { undef $ENV{TWO_TASK}; }
$ENV{"ORACLE_HOME"}='/path/to/oracle/install/dir';

my $statusRec;
print 'Content-Type: text/xml' . "\n\n";
print '<?xml version="1.0"?>' . "\n";
print '<rss version="2.0">' . "\n";
print ' <channel>' . "\n";
print ' <title>Oracle ORA-00600</title>' . "\n";
print ' <description>ORA 600 errors</description>' . "\n";
print ' <language>en-us</language>' . "\n";
print ' <copyright>Copyright 2007</copyright>' . "\n";
print ' <managingEditor>email@domain</managingEditor>' . "\n";
print ' <webMaster>email@domain</webMaster>' . "\n";
print ' <generator>script name</generator>';

# Create db connection
$DBH = DBI->connect("DBI:Oracle:host=zzz;SID=zzz;port=nnnn"
                   , "alertlog", "alertlog",
{ RaiseError => 1, AutoCommit => 0 })
|| die "Could not connect\n\tError: $DBI::errstr";

my $STH = $DBH->prepare("with alert as
(select rownum rn
,text_line
from alert_log)
select a.text_line date_msg
,b.text_line file_msg
,c.text_line err_msg
from alert a inner join alert b
on a.rn = b.rn - 1
inner join alert c
on b.rn = c.rn - 1
where c.text_line like '%ORA-00600%'");

$STH->execute() || die "Couldn't execute statement: $STH->errstr";

while($statusRec = $STH->fetchrow_hashref())
{
print " <item>\n";
print " <title>ORA-600 Occured</title>\n";
print " <description>An ORA-00600 has been detected.\n";
print "<p>\n";
print " \n";
print "The following information was logged about the event:\n</p><p>";
print $statusRec->{"DATE_MSG"} . "</p>\n<p>";
print $statusRec->{"FILE_MSG"} . "</p>\n<p>";
print $statusRec->{"ERR_MSG"} . "</p>\n" . "</description>\n";
print " <author>your name</author>\n";
print " </item>\n";
}

$STH->finish();
$DBH->disconnect();

print " </channel>\n";
print "</rss>";

That is all it takes. This is obviously a CGI script that would run in your web server. If you have one with CGI capabilities configured, you’d place the script there and call it with an url like “http://your.domain/cgi-bin/script_name.cgi”. Ask your web admin if you don’ know where and how to place this script. If you have your own web server and don’t know how to do this, leave a comment and I’ll try to give you a few quick hints about how to get it working.

I’m afraid the code above will be truncated by google’s new blog interface. The code will still be there so just cut and paste it into your favorite code editor and you’ll have all the needed code.

You will probably want to change these lines to something different:

$ENV{"ORACLE_HOME"}='/path/to/oracle/install/dir';

$DBH = DBI->connect("DBI:Oracle:host=...snip...,

...and the following nodes...

copyright

managingEditor

webMaster

generator

author

The first one should point to where you have Oracle installed and the second will be your connection string. If you don’t know the port ask your DBA or try the default of 1521. It is the port you have your listener configured to listen on.

There is no guarantee that the code works as is. Every environment is different and the code is clearly not environment proof. If you have problems with it, check your error log for the web server and leave a message if you want my input on what the problem might be.

Enough alert log stuff? Probably. Sorry if you feel I’ve overdone it and got stuck on this subject for too long. Next post will not even mention the alert log.

If you have APEX or want to wait for 11G where it will be a supported option, you will want to use APEX and pure SQL for this rather than Perl. A good intro to how to do it can be found on asktom.oracle.com. It is written by Sean Dillon and looks well written and easy to follow, it can be found here. I’ve not tried it myself, but it sounds straightforward and anything from the people behind asktom and APEX at Oracle is usually both easy to understand and easy to implement (relative to the subject’s complexity).

Leave a Comment

Your email address will not be published. Required fields are marked *

*