UTL_FILE v11
The UTL_FILE
package provides the capability to read from, and write to files on the operating system’s file system. Non-superusers must be granted EXECUTE
privilege on the UTL_FILE
package by a superuser before using any of the functions or procedures in the package. For example the following command grants the privilege to user mary
:
Also, the operating system username, enterprisedb
, must have the appropriate read and/or write permissions on the directories and files to be accessed using the UTL_FILE
functions and procedures. If the required file permissions are not in place, an exception is thrown in the UTL_FILE
function or procedure.
A handle to the file to be written to, or read from is used to reference the file. The file handle is defined by a public variable in the UTL_FILE
package named, UTL_FILE.FILE_TYPE
. A variable of type FILE_TYPE
must be declared to receive the file handle returned by calling the FOPEN
function. The file handle is then used for all subsequent operations on the file.
References to directories on the file system are done using the directory name or alias that is assigned to the directory using the CREATE DIRECTORY
command.
The procedures and functions available in the UTL_FILE
package are listed in the following table:
Function/Procedure | Return Type | Description |
---|---|---|
FCLOSE(file IN OUT) | n/a | Closes the specified file identified by file . |
FCLOSE_ALL | n/a | Closes all open files. |
FCOPY(location, filename, dest_dir, dest_file [, start_line [, end_line ] ]) | n/a | Copies filename in the directory identified by location to file, dest_file , in directory, dest_dir , starting from line, start_line , to line, end_line . |
FFLUSH(file) | n/a | Forces data in the buffer to be written to disk in the file identified by file . |
FOPEN(location, filename, open_mode [, max_linesize ]) | FILE_TYPE | Opens file, filename , in the directory identified by location . |
FREMOVE(location, filename) | n/a | Removes the specified file from the file system. |
FRENAME(location, filename, dest_dir, dest_file [, overwrite ]) | n/a | Renames the specified file. |
GET_LINE(file, buffer OUT) | n/a | Reads a line of text into variable, buffer , from the file identified by file . |
IS_OPEN(file) | BOOLEAN | Determines whether or not the given file is open. |
NEW_LINE(file [, lines ]) | n/a | Writes an end-of-line character sequence into the file. |
PUT(file, buffer) | n/a | Writes buffer to the given file. PUT does not write an end-of-line character sequence. |
PUT_LINE(file, buffer) | n/a | Writes buffer to the given file. An end-of-line character sequence is added by the PUT_LINE procedure. |
PUTF(file, format [, arg1 ] [, ...]) | n/a | Writes a formatted string to the given file. Up to five substitution parameters, arg1,...arg5 may be specified for replacement in format . |
Advanced Server's implementation of UTL_FILE
is a partial implementation when compared to Oracle's version. Only those functions and procedures listed in the table above are supported.
UTL_FILE Exception Codes
If a call to a UTL_FILE
procedure or function raises an exception, you can use the condition name to catch the exception. The UTL_FILE
package reports the following exception codes compatible with Oracle databases:
Exception Code | Condition name |
---|---|
-29283 | invalid_operation |
-29285 | write_error |
-29284 | read_error |
-29282 | invalid_filehandle |
-29287 | invalid_maxlinesize |
-29281 | invalid_mode |
-29280 | invalid_path |
Setting File Permissions with utl_file.umask
When a UTL_FILE
function or procedure creates a file, there are default file permissions as shown by the following.
Note that all permissions are denied on users belonging to the enterprisedb
group as well as all other users. Only the enterprisedb
user has read and write permissions on the created file.
If you wish to have a different set of file permissions on files created by the UTL_FILE
functions and procedures, you can accomplish this by setting the utl_file.umask
configuration parameter.
The utl_file.umask
parameter sets the file mode creation mask or simply, the mask, in a manner similar to the Linux umask
command. This is for usage only within the Advanced Server UTL_FILE
package.
Note
The utl_file.umask
parameter is not supported on Windows systems.
The value specified for utl_file.umask
is a 3 or 4-character octal string that would be valid for the Linux umask
command. The setting determines the permissions on files created by the UTL_FILE
functions and procedures. (Refer to any information source regarding Linux or Unix systems for information on file permissions and the usage of the umask
command.)
The following is an example of setting the file permissions with utl_file.umask
.
First, set up the directory in the file system to be used by the UTL_FILE
package. Be sure the operating system account, enterprisedb
or postgres
, whichever is applicable, can read and write in the directory.
The CREATE DIRECTORY
command is issued in psql
to create the directory database object using the file system directory created in the preceding step.
Set the utl_file.umask
configuration parameter. The following setting allows the file owner any permission. Group users and other users are permitted any permission except for the execute permission.
In the same session during which the utl_file.umask
parameter is set to the desired value, run the UTL_FILE
functions and procedures.
The permission settings on the resulting file show that group users and other users have read and write permissions on the file as well as the file owner.
This parameter can also be set on a per role basis with the ALTER ROLE
command, on a per database basis with the ALTER DATABASE
command, or for the entire database server instance by setting it in the postgresql.conf
file.
FCLOSE
The FCLOSE
procedure closes an open file.
Parameters
file
Variable of type FILE_TYPE
containing a file handle of the file to be closed.
FCLOSE_ALL
The FLCLOSE_ALL
procedures closes all open files. The procedure executes successfully even if there are no open files to close.
FCOPY
The FCOPY
procedure copies text from one file to another.
Parameters
location
Directory name, as stored in pg_catalog.edb_dir.dirname
, of the directory containing the file to be copied.
filename
Name of the source file to be copied.
dest_dir
Directory name, as stored in pg_catalog.edb_dir.dirname
, of the directory to which the file is to be copied.
dest_file
Name of the destination file.
start_line
Line number in the source file from which copying will begin. The default is 1.
end_line
Line number of the last line in the source file to be copied. If omitted or null, copying will go to the last line of the file.
Examples
The following makes a copy of a file, C:\TEMP\EMPDIR\empfile.csv
, containing a comma-delimited list of employees from the emp
table. The copy, empcopy.csv
, is then listed.
FFLUSH
The FFLUSH
procedure flushes unwritten data from the write buffer to the file.
Parameters
file
Variable of type FILE_TYPE
containing a file handle.
Examples
Each line is flushed after the NEW_LINE
procedure is called.
FOPEN
The FOPEN
function opens a file for I/O.
Parameters
location
Directory name, as stored in pg_catalog.edb_dir.dirname
, of the directory containing the file to be opened.
filename
Name of the file to be opened.
open_mode
Mode in which the file will be opened. Modes are: a
- append to file; r
- read from file; w
- write to file.
max_linesize
Maximum size of a line in characters. In read mode, an exception is thrown if an attempt is made to read a line exceeding max_linesize
. In write and append modes, an exception is thrown if an attempt is made to write a line exceeding max_linesize
. The end-of-line character(s) are not included in determining if the maximum line size is exceeded. This behavior is not compatible with Oracle databases; Oracle does count the end-of-line character(s).
filetype
Variable of type FILE_TYPE
containing the file handle of the opened file.
FREMOVE
The FREMOVE
procedure removes a file from the system.
An exception is thrown if the file to be removed does not exist.
Parameters
location
Directory name, as stored in pg_catalog.edb_dir.dirname
, of the directory containing the file to be removed.
filename
Name of the file to be removed.
Examples
The following removes file empfile.csv
.
FRENAME
The FRENAME
procedure renames a given file. This effectively moves a file from one location to another.
Parameters
location
Directory name, as stored in pg_catalog.edb_dir.dirname
, of the directory containing the file to be renamed.
filename
Name of the source file to be renamed.
dest_dir
Directory name, as stored in pg_catalog.edb_dir.dirname
, of the directory to which the renamed file is to exist.
dest_file
New name of the original file.
overwrite
Replaces any existing file named dest_file
in dest_dir
if set to TRUE
, otherwise an exception is thrown if set to FALSE
. This is the default.
Examples
The following renames a file, C:\TEMP\EMPDIR\empfile.csv
, containing a comma-delimited list of employees from the emp
table. The renamed file, C:\TEMP\NEWDIR\newemp.csv
, is then listed.
GET_LINE
The GET_LINE
procedure reads a line of text from a given file up to, but not including the end-of-line terminator. A NO_DATA_FOUND
exception is thrown when there are no more lines to read.
Parameters
file
Variable of type FILE_TYPE
containing the file handle of the opened file.
buffer
Variable to receive a line from the file.
Examples
The following anonymous block reads through and displays the records in file empfile.csv
.
IS_OPEN
The IS_OPEN
function determines whether or not the given file is open.
Parameters
file
Variable of type FILE_TYPE
containing the file handle of the file to be tested.
status
TRUE
if the given file is open, FALSE
otherwise.
NEW_LINE
The NEW_LINE
procedure writes an end-of-line character sequence in the file.
Parameters
file
Variable of type FILE_TYPE
containing the file handle of the file to which end-of-line character sequences are to be written.
lines
Number of end-of-line character sequences to be written. The default is one.
Examples
A file containing a double-spaced list of employee records is written.
This file is then displayed:
PUT
The PUT
procedure writes a string to the given file. No end-of-line character sequence is written at the end of the string. Use the NEW_LINE
procedure to add an end-of-line character sequence.
Parameters
file
Variable of type FILE_TYPE
containing the file handle of the file to which the given string is to be written.
buffer
Text to be written to the specified file.
Examples
The following example uses the PUT
procedure to create a comma-delimited file of employees from the emp
table.
The following is the contents of empfile.csv
created above:
PUT_LINE
The PUT_LINE
procedure writes a single line to the given file including an end-of-line character sequence.
Parameters
file
Variable of type FILE_TYPE
containing the file handle of the file to which the given line is to be written.
buffer
Text to be written to the specified file.
Examples
The following example uses the PUT_LINE
procedure to create a comma-delimited file of employees from the emp
table.
The following is the contents of empfile.csv
created above:
PUTF
The PUTF
procedure writes a formatted string to the given file.
Parameters
file
Variable of type FILE_TYPE
containing the file handle of the file to which the formatted line is to be written.
format
String to format the text written to the file. The special character sequence, %s
, is substituted by the value of arg. The special character sequence, \n
, indicates a new line. Note, however, in Advanced Server, a new line character must be specified with two consecutive backslashes instead of one - \\n
. This characteristic is not compatible with Oracle databases.
arg1
Up to five arguments, arg1
,...arg5
, to be substituted in the format string for each occurrence of %s
. The first arg is substituted for the first occurrence of %s
, the second arg is substituted for the second occurrence of %s
, etc.
Examples
The following anonymous block produces formatted output containing data from the emp
table. Note the use of the E literal syntax and double backslashes for the new line character sequence in the format string which are not compatible with Oracle databases.
The following is the contents of empfile.csv
created above: