Skip to Main Content

Breadcrumb

XMAS_TREE

The AskTOM team is taking a break over the holiday season, so we're not taking questions or responding to comments, but we might still sneak in a few Office Hours sessions! Thanks for being a member of the AskTOM community.

Question and Answer

Tom Kyte

Thanks for the question, Unmesh.

Asked: October 29, 2008 - 2:55 am UTC

Last updated: October 29, 2008 - 10:09 am UTC

Version: 9.1.0.1

Viewed 10K+ times! This question is

You Asked

Hi,

I am trying to read one DBF file using the following code snippet. But it is returning an error which is 'Error : ORA-22285: non-existent directory or file for FILEOPEN operation'.


create or replace procedure readfile(FilePath in varchar2,FileName in varchar2)
as
Xml_file UTL_FILE.FILE_TYPE;
File_name varchar2(100);
xref_data varchar2(50);
ref_no_data varchar2(50);
data varchar2(100);
l_bfile BFILE;
begin
l_bfile := BFILENAME( FilePath, FileName);
dbms_lob.fileopen(l_bfile );
exception
when OTHERS then
dbms_output.put_line('Error : ' || SQLERRM );
end;
/


Please help me to resolve this.

Thanks in advance for the support
Unmesh

and Tom said...

Sorry, but I've decided to be totally blunt with when others from now on....


I hate your code:

exception
when OTHERS then
dbms_output.put_line('Error : ' || SQLERRM );
end; 


stop doing that right now, that is the worst programming practice on the planet, there is no reason for it, none.

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::NO::P11_QUESTION_ID:1270688200346183091

As for the problem at hand here, let's see

we don't know what directory you are trying to read
we don't know what directory you created
we don't know if that directory exists on the SERVER (it has too)



So, what did your create directory look like? The CASE is important... Identifiers are folded to upper case. Maybe it looks like this:

ops$tkyte%ORA9IR2> create or replace directory my_dir as '/tmp'
  2  /

Directory created.


so the directory is really MY_DIR, not my_dir...


so, if you have a procedure like:


ops$tkyte%ORA9IR2> create or replace procedure readfile(FilePath in varchar2,FileName in varchar2)
  2  as
  3          l_bfile    BFILE;
  4  begin
  5          l_bfile := BFILENAME( FilePath, FileName);
  6          dbms_lob.fileopen(l_bfile );
  7  end;
  8  /

Procedure created.



and a file you know exists IN THAT DIRECTORY ON THAT SERVER - I am no sqlnet'ed in - I'm on the server itself:

ops$tkyte%ORA9IR2>
ops$tkyte%ORA9IR2> !touch /tmp/test.dat



you would expect this:

ops$tkyte%ORA9IR2> exec readFile( 'my_dir', 'test.dat' );
BEGIN readFile( 'my_dir', 'test.dat' ); END;

*
ERROR at line 1:
ORA-22285: non-existent directory or file for FILEOPEN operation
ORA-06512: at "SYS.DBMS_LOB", line 504
ORA-06512: at "OPS$TKYTE.READFILE", line 6
ORA-06512: at line 1


if you used lower case and this:
ops$tkyte%ORA9IR2> exec readFile( 'MY_DIR', 'test.dat' );

PL/SQL procedure successfully completed.


otherwise (but hey, if you leave that really bad WHEN OTHERS in there, you might just see "PL/SQL procedure successfully completed." for both!!!! so stop it)


So, work through a more simple example - and stop the when others, pretend the word OTHERS does not exist in plsql.





Rating

  (1 rating)

We're not taking comments currently, so please try again later if you want to add a comment.

Comments

Thanks

Unmesh Mohanan, October 30, 2008 - 12:52 am UTC

Hi Tom,

Thanks a lot. It works fine now. The reply you 've given is truly amazing and a wonderful eye opener too ( pertains to the WHEN OTHERS clause). That was just a sample piece of code I was trying to open the file, and the production code was never intended to have the WHEN OTHERS code. But your explanation on the same was amazing and gave a lot of insight to the same, and what more .. me also getting irritated when seeing the code 'WHEN OTHERS' anywhere .. :)

I ve decided for sure .. I ll be disturbing you with such technical stuff once in a while


More to Explore

CLOB/BLOB/etc

Complete documentation on Securefiles and Large Objects here