 |
|
Oracle Scheduling Running OS Commands and
Scripts from PL/SQL
Oracle Tips by Burleson Consulting |
Running OS Commands and Scripts from
PL/SQL
Not all jobs that can be scheduled are written
as stored procedures. Sometimes it is necessary to schedule
jobs to run operating system commands or batch scripts.
Typically, these types of jobs have been scheduled using an
operating system scheduler, such as CRON, since it is not possible
to call operating system command or executable scripts natively from
PL/SQL. Splitting job scheduling between two schedulers can
get confusing, so many database administrators resign themselves to
only using the operating system scheduler.
The scheduler in Oracle10g can be used to
schedule operating system commands and scripts natively, giving the
option of avoiding the operating system scheduler. This is
great if using Oracle10g, but what can be done if using Oracle 8i
and 9i? One method is to use Java stored procedures to do the
work.
First, the Java stored procedure that will
actually do the work needs to be created.
* Host.java
--
-- Parameters:
-- 1) Host command or executable file to execute.
-- *****************************************************************
CREATE OR
REPLACE AND COMPILE JAVA SOURCE NAMED "Host" AS
import java.io.*;
public class Host {
public static void executeCommand(String command) {
try {
String[] finalCommand;
if (isWindows()) {
finalCommand = new String[4];
finalCommand[0] = "C:\\winnt\\system32\\cmd.exe";
finalCommand[1] = "/y";
finalCommand[2] = "/c";
finalCommand[3] = command;
}
else {
finalCommand = new String[3];
finalCommand[0] = "/bin/sh";
finalCommand[1] = "-c";
finalCommand[2] = command;
}
final Process pr = Runtime.getRuntime().exec(finalCommand);
new Thread(new Runnable() {
public void run() {
try {
BufferedReader br_in = new BufferedReader(new
InputStreamReader(pr.getInputStream()));
String buff =
null;
while ((buff
= br_in.readLine()) != null) {
System.out.println(buff);
try {Thread.sleep(100); } catch(Exception e) {}
}
br_in.close();
}
catch (IOException ioe) {
System.out.println("Exception caught
printing process output.");
ioe.printStackTrace();
}
}
}).start();
new Thread(new Runnable() {
public void run() {
try {
BufferedReader br_err = new BufferedReader(new
InputStreamReader(pr.getErrorStream()));
String buff =
null;
while ((buff
= br_err.readLine()) != null) {
System.out.println(buff);
try {Thread.sleep(100); } catch(Exception e) {}
}
br_err.close();
}
catch (IOException ioe) {
System.out.println("Exception caught printing process error.");
ioe.printStackTrace();
}
}
}).start();
}
catch (Exception ex) {
System.out.println(ex.getLocalizedMessage());
}
}
public static boolean isWindows() {
if (System.getProperty("os.name").toLowerCase().indexOf("windows")
!= -1)
return true;
else
return false;
}
};
/
show errors
java source "Host"
The Host.java procedure is loaded in the same
way as a PL/SQL stored procedure.
SQL> @Host.java
In order to call the Java stored procedure, a
PL/SQL call specification must be published. This is
essentially a PL/SQL wrapper with the correct parameter list which
allows the Java code to be called as if it were a PL/SQL procedure
or function.
*
host_command.sql
--
*************************************************
-- Copyright ? 2005 by Rampant TechPress
-- This script is free for non-commercial purposes
--
-- To license this script for a commercial purpose,
-- contact info@rampant.cc
-- *************************************************
-- Parameters:
-- 1) Host command or executable file to execute.
-- *****************************************************************
CREATE OR
REPLACE PROCEDURE host_command (p_command IN VARCHAR2)
AS LANGUAGE JAVA
NAME 'Host.executeCommand (java.lang.String)';
/
By default, the JServer has very little access
to the operating system of the database server. To make sure
there are no problems accessing the file system and operating system
commands, the appropriate permissions using the grant_permission
procedure of the dbms_java package must be given to the user.
PROCEDURE
grant_permission (
grantee
IN VARCHAR2,
permission_type IN VARCHAR2,
permission_name IN VARCHAR2,
permission_action IN VARCHAR2)
Assuming that job_user is the schema that owns
the Host Java stored procedure, the following permissions need to be
granted:
BEGIN
DBMS_JAVA.grant_permission ('JOB_USER', 'java.io.FilePermission',
'<>', 'read ,write, execute, delete');
DBMS_JAVA.grant_permission ('JOB_USER', 'SYS:java.lang.RuntimePermission',
'writeFileDescriptor', '');
DBMS_JAVA.grant_permission ('JOB_USER', 'SYS:java.lang.RuntimePermission',
'readFileDescriptor', '');
END;
/
The effects of these permissions are only seen
when the grantee reconnects.
The host_command procedure can be tested as
follows:
SET
SERVEROUTPUT ON SIZE 1000000
CALL DBMS_JAVA.SET_OUTPUT(1000000);
BEGIN
host_command (p_command => ?touch /u01/app/oracle/test_file');
END;
/
With the host_command procedure in place, the
OS commands can now be scheduled using the dbms_job package the same
way any normal PL/SQL procedure is used.
Care should be taken over who gets access to
the host_command procedure as it runs OS commands and executable
scripts as the operating system user that owns the Oracle software.
As such, it can be the cause of security vulnerabilities if used
incorrectly.
 |
This is an excerpt from the book "Oracle
Job Scheduling" by Dr. Tim Hall. You can buy it direct
from the publisher for 30%-off and get instant access to the
code depot of Oracle job scheduling scripts. |