Tip

Browsing OS files from TOAD or SQL*Plus

This tip describes the process required to browse operating system (OS) files from a PC application like TOAD or SQL*PLUS. This process will be useful for browsing the Oracle alert log when access via the OS is restricted. It will only work on Oracle version 8.1.6 and above.

Setting up the browse OS files procedure:

  1. Start up TOAD and connect to the database that has access to the files you wish to view.
  2. Within a SQL session, run the SQL in Appendix 1 to create the procedure.
  3. Give a logical name to each OS directory you wish to access. NT and Unix SQL examples are shown.
    create directory ALERTLOG_DIR as 'd:/oracle/admin/DTM2/bdump'; 
    create directory TNS_ADMIN as '/home/oracle/network/admin'; 
     

Running the browse OS files procedure:

  1. Start up TOAD and connect to the database that has access to the files you wish to view.
  2. Within the TOAD SQL editor, enter an execute statement for the procedure and then execute using TOAD's Quest ScriptRunner product. Here is an example of the SQL:
    set serveroutput on;
    exec browse_os_file('TNS_LOG','listener.log');
    
  3. The 'set serveroutput on' command is required or you will not see the contents of the file.
  4. If the file being browsed is over approximately 80Kb then it will show the last 80Kb of the file only.
  5. If SQL*PLUS is used instead of ScriptRunner, the procedure will fail for any file that is over 2000 bytes OR you can amend the line 'if (m_file_size) >

    Requires Free Membership to View

  1. 85000 then' to 'if (m_file_size) > 1600 then'. This will cause SQL*PLUS to show the last 1.5Kb of the file if the file being browsed is over approximately 1.5Kb.

Appendix 1:

CREATE OR REPLACE PROCEDURE browse_os_file ( 
m_logical_directory IN VARCHAR2, 
m_input_filename IN VARCHAR2
) 
IS 
m_dirname varchar2(32);
m_filename varchar2(32);
m_file BFILE; 
m_buffer raw(100); --raw 
m_file_size INTEGER ; 
m_buf_size INTEGER; 
m_position INTEGER; 
m_start_pos INTEGER;
loop_end_flag INTEGER;
BEGIN 
-- This procedure allows users to browse the contents of any OS file 
-- that Oracle has read access to 
-- The only prerequisites are: Oracle 8.1.6 or above and the directory 
-- has been assigned a logical name e.g. 
-- create directory ALERTLOG_DIR as '/home/oracle/admin/MSAMD/bdump'; 
-- m_logical_directory := 'ALERTLOG_DIR'; 
-- m_input_filename := 'alert_MSAMD.log'; 
--
-- Author: Jim Leask - November 2002 

m_file := BFILENAME(m_logical_directory, m_input_filename); 
m_position := 1;
m_start_pos := 1; 
m_buf_size := 64; 
loop_end_flag := 0;
if (dbms_lob.fileexists( file_loc => m_file ) != 1) then
dbms_output.put_line('***** File or Directory reference does not exist *****');
GOTO end_section;
end if;
m_file_size := dbms_lob.getlength(m_file);
if (m_file_size) > 85000 then
DBMS_OUTPUT.put_line('***** File too large - showing tail end of file *****');
m_position := m_file_size - 84999;
m_start_pos := m_position;
end if;
DBMS_LOB.FILEOPEN(file_loc => m_file, 
open_mode => dbms_lob.file_readonly); 
WHILE loop_end_flag = 0 LOOP 
dbms_lob.read( file_loc => m_file,
amount => m_buf_size,
offset => m_position,
buffer => m_buffer ); 
m_position := m_position + m_buf_size; 
DBMS_OUTPUT.put_line(utl_raw.cast_to_varchar2(m_buffer)); --convert to varchar2 
if (m_buf_size) != 64 then
DBMS_OUTPUT.put_line('***** End of the file *****');
loop_end_flag := 1;
end if;
if (m_position - m_start_pos) > 85000 then
DBMS_OUTPUT.put_line('***** File about to exceed buffer size *****');
loop_end_flag := 1;
end if;
END LOOP; 
DBMS_LOB.FILECLOSE(file_loc => m_file); 
<<end_section>> 
null;
exception 
when no_data_found then 
DBMS_OUTPUT.put_line('***** Unkown Error - see other messages *****');
END;  

Reader Feedback

Duncan M. writes: If you include

dbms_output.enable(1000000);
at the beginning of the procedure, you can display files larger than that suggested in the article (in SQL*Plus).

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in January 2003

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

Disclaimer: Our Tips Exchange is a forum for you to share technical advice and expertise with your peers and to learn from other enterprise IT professionals. TechTarget provides the infrastructure to facilitate this sharing of information. However, we cannot guarantee the accuracy or validity of the material submitted. You agree that your use of the Ask The Expert services and your reliance on any questions, answers, information or other materials received through this Web site is at your own risk.