Skip Headers

Oracle9i Supplied PL/SQL Packages and Types Reference
Release 2 (9.2)

Part Number A96612-01
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback

Go to previous page Go to beginning of chapter Go to next page

DBMS_LOB , 2 of 2


Summary of DBMS_LOB Subprograms

Table 23-4 DBMS_LOB Subprograms  
Subprogram Description

APPEND Procedure

Appends the contents of the source LOB to the destination LOB.

CLOSE Procedure

Closes a previously opened internal or external LOB.

COMPARE Function

Compares two entire LOBs or parts of two LOBs.

COPY Procedure

Copies all, or part, of the source LOB to the destination LOB.

CREATETEMPORARY Procedure

Creates a temporary BLOB or CLOB and its corresponding index in the user's default temporary tablespace.

ERASE Procedure

Erases all or part of a LOB.

FILECLOSE Procedure

Closes the file.

FILECLOSEALL Procedure

Closes all previously opened files.

FILEEXISTS Function

Checks if the file exists on the server.

FILEGETNAME Procedure

Gets the directory alias and file name.

FILEISOPEN Function

Checks if the file was opened using the input BFILE locators.

FILEOPEN Procedure

Opens a file.

FREETEMPORARY Procedure

Frees the temporary BLOB or CLOB in the user's default temporary tablespace.

GETCHUNKSIZE Function

Returns the amount of space used in the LOB chunk to store the LOB value.

GETLENGTH Function

Gets the length of the LOB value.

INSTR Function

Returns the matching position of the nth occurrence of the pattern in the LOB.

ISOPEN Function

Checks to see if the LOB was already opened using the input locator.

ISTEMPORARY Function

Checks if the locator is pointing to a temporary LOB.

LOADFROMFILE Procedure

Loads BFILE data into an internal LOB.

LOADBLOBFROMFILE Procedure

Loads BFILE data into an internal BLOB.

LOADCLOBFROMFILE Procedure

Loads BFILE data into an internal CLOB.

OPEN Procedure

Opens a LOB (internal, external, or temporary) in the indicated mode.

READ Procedure

Reads data from the LOB starting at the specified offset.

SUBSTR Function

Returns part of the LOB value starting at the specified offset.

TRIM Procedure

Trims the LOB value to the specified shorter length.

WRITE Procedure

Writes data to the LOB from a specified offset.

WRITEAPPEND Procedure

Writes a buffer to the end of a LOB.

APPEND Procedure

This procedure appends the contents of a source internal LOB to a destination LOB. It appends the complete source LOB.

There are two overloaded APPEND procedures.

Syntax

DBMS_LOB.APPEND (
   dest_lob IN OUT  NOCOPY BLOB, 
   src_lob  IN             BLOB); 

DBMS_LOB.APPEND (
   dest_lob IN OUT  NOCOPY CLOB  CHARACTER SET ANY_CS, 
   src_lob  IN             CLOB  CHARACTER SET dest_lob%CHARSET);

Parameters

Table 23-5 APPEND Procedure Parameters
Parameter Description
dest_lob

Locator for the internal LOB to which the data is to be appended.

src_lob

Locator for the internal LOB from which the data is to be read.

Exceptions

Table 23-6 APPEND Procedure Exceptions
Exception Description
VALUE_ERROR

Either the source or the destination LOB is NULL.

Usage Notes

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Examples

CREATE OR REPLACE PROCEDURE Example_1a IS
    dest_lob BLOB;
    src_lob  BLOB;
BEGIN
    -- get the LOB locators
    -- note that the FOR UPDATE clause locks the row
    SELECT b_lob INTO dest_lob
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    SELECT b_lob INTO src_lob
        FROM lob_table
        WHERE key_value = 21;
    DBMS_LOB.APPEND(dest_lob, src_lob);
    COMMIT;
EXCEPTION
    WHEN some_exception
    THEN handle_exception;
END;

CREATE OR REPLACE PROCEDURE Example_1b IS
    dest_lob, src_lob  BLOB;
BEGIN
    -- get the LOB locators
    -- note that the FOR UPDATE clause locks the row
    SELECT b_lob INTO dest_lob
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    SELECT b_lob INTO src_lob
        FROM lob_table
        WHERE key_value = 12;
    DBMS_LOB.APPEND(dest_lob, src_lob);
    COMMIT;
EXCEPTION
    WHEN some_exception
    THEN handle_exception;
END;

CLOSE Procedure

This procedure closes a previously opened internal or external LOB.

Syntax

DBMS_LOB.CLOSE (
   lob_loc    IN OUT NOCOPY BLOB); 

DBMS_LOB.CLOSE (
   lob_loc    IN OUT NOCOPY CLOB CHARACTER SET ANY_CS); 

DBMS_LOB.CLOSE (
   file_loc   IN OUT NOCOPY BFILE); 

Errors

No error is returned if the BFILE exists but is not opened. An error is returned if the LOB is not open.

Usage Notes

CLOSE requires a round-trip to the server for both internal and external LOBs. For internal LOBs, CLOSE triggers other code that relies on the close call, and for external LOBs (BFILEs), CLOSE actually closes the server-side operating system file.

It is not mandatory that you wrap all LOB operations inside the Open/Close APIs. However, if you open a LOB, you must close it before you commit or rollback the transaction; an error is produced if you do not. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

It is an error to commit the transaction before closing all opened LOBs that were opened by the transaction. When the error is returned, the openness of the open LOBs is discarded, but the transaction is successfully committed. Hence, all the changes made to the LOB and non-LOB data in the transaction are committed, but the domain and function-based indexes are not updated. If this happens, you should rebuild the functional and domain indexes on the LOB column.

COMPARE Function

This function compares two entire LOBs or parts of two LOBs. You can only compare LOBs of the same datatype (LOBs of BLOB type with other BLOBs, and CLOBs with CLOBs, and BFILEs with BFILEs). For BFILEs, the file must be already opened using a successful FILEOPEN operation for this operation to succeed.

COMPARE returns zero if the data exactly matches over the range specified by the offset and amount parameters. Otherwise, a nonzero INTEGER is returned.

For fixed-width n-byte CLOBs, if the input amount for COMPARE is specified to be greater than (4294967295/n), then COMPARE matches characters in a range of size (4294967295/n), or Max(length(clob1), length(clob2)), whichever is lesser.

Syntax

DBMS_LOB.COMPARE (
   lob_1            IN BLOB,
   lob_2            IN BLOB,
   amount           IN INTEGER := 4294967295,
   offset_1         IN INTEGER := 1,
   offset_2         IN INTEGER := 1)
  RETURN INTEGER;

DBMS_LOB.COMPARE (
   lob_1            IN CLOB  CHARACTER SET ANY_CS,
   lob_2            IN CLOB  CHARACTER SET lob_1%CHARSET,
   amount           IN INTEGER := 4294967295,
   offset_1         IN INTEGER := 1,
   offset_2         IN INTEGER := 1)
  RETURN INTEGER; 

DBMS_LOB.COMPARE (
   lob_1            IN BFILE,
   lob_2            IN BFILE,
   amount           IN INTEGER,
   offset_1         IN INTEGER := 1,
   offset_2         IN INTEGER := 1)
  RETURN INTEGER;

Pragmas

pragma restrict_references(COMPARE, WNDS, WNPS, RNDS, RNPS);

Parameters

Table 23-7 COMPARE Function Parameters
Parameter Description
lob_1

LOB locator of first target for comparison.

lob_2

LOB locator of second target for comparison.

amount

Number of bytes (for BLOBs) or characters (for CLOBs) to compare.

offset_1

Offset in bytes or characters on the first LOB (origin: 1) for the comparison.

offset_2

Offset in bytes or characters on the first LOB (origin: 1) for the comparison.

Returns

Exceptions

Table 23-8 COMPARE Function Exceptions for BFILE operations
Exception Description
UNOPENED_FILE

File was not opened using the input locator.

NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

INVALID_OPERATION

File does not exist, or you do not have access privileges on the file.

Examples

CREATE OR REPLACE PROCEDURE Example2a IS
    lob_1, lob_2      BLOB;
    retval            INTEGER;
BEGIN
    SELECT b_col INTO lob_1 FROM lob_table
        WHERE key_value = 45;
    SELECT b_col INTO lob_2 FROM lob_table
        WHERE key_value = 54;
    retval := dbms_lob.compare(lob_1, lob_2, 5600, 33482,
         128);
    IF retval = 0 THEN
      ;    -- process compared code 
    ELSE
      ;    -- process not compared code
    END IF;
END;

CREATE OR REPLACE PROCEDURE Example_2b IS
    fil_1, fil_2       BFILE;    
    retval             INTEGER;
BEGIN

    SELECT f_lob INTO fil_1 FROM lob_table WHERE key_value = 45;
    SELECT f_lob INTO fil_2 FROM lob_table WHERE key_value = 54;
    dbms_lob.fileopen(fil_1, dbms_lob.file_readonly);
    dbms_lob.fileopen(fil_2, dbms_lob.file_readonly);
    retval := dbms_lob.compare(fil_1, fil_2, 5600,
                                  3348276, 2765612);
    IF (retval = 0) 
    THEN
        ; -- process compared code 
    ELSE
        ; -- process not compared code 
    END IF;
    dbms_lob.fileclose(fil_1);
    dbms_lob.fileclose(fil_2);
END;

COPY Procedure

This procedure copies all, or a part of, a source internal LOB to a destination internal LOB. You can specify the offsets for both the source and destination LOBs, and the number of bytes or characters to copy.

If the offset you specify in the destination LOB is beyond the end of the data currently in this LOB, then zero-byte fillers or spaces are inserted in the destination BLOB or CLOB respectively. If the offset is less than the current length of the destination LOB, then existing data is overwritten.

It is not an error to specify an amount that exceeds the length of the data in the source LOB. Thus, you can specify a large amount to copy from the source LOB, which copies data from the src_offset to the end of the source LOB.

Syntax

DBMS_LOB.COPY (
  dest_lob    IN OUT NOCOPY BLOB,
  src_lob     IN            BLOB,
  amount      IN            INTEGER,
  dest_offset IN            INTEGER := 1,
  src_offset  IN            INTEGER := 1);

DBMS_LOB.COPY ( 
  dest_lob    IN OUT NOCOPY CLOB  CHARACTER SET ANY_CS,
  src_lob     IN            CLOB  CHARACTER SET dest_lob%CHARSET,
  amount      IN            INTEGER,
  dest_offset IN            INTEGER := 1,
  src_offset  IN            INTEGER := 1);

Parameters

Table 23-9 COPY Procedure Parameters
Parameter Description
dest_lob

LOB locator of the copy target.

src_lob

LOB locator of source for the copy.

amount

Number of bytes (for BLOBs) or characters (for CLOBs) to copy.

dest_offset

Offset in bytes or characters in the destination LOB (origin: 1) for the start of the copy.

src_offset

Offset in bytes or characters in the source LOB (origin: 1) for the start of the copy.

Exceptions

Table 23-10  COPY Procedure Exceptions
Exception Description
VALUE_ERROR

Any of the input parameters are NULL or invalid.

INVALID_ARGVAL

Either:

- src_offset or dest_offset < 1

- src_offset or dest_offset > LOBMAXSIZE

- amount < 1

- amount > LOBMAXSIZE

Usage Notes

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Examples

CREATE OR REPLACE PROCEDURE Example_3a IS
    lobd, lobs     BLOB; 
    dest_offset    INTEGER := 1
    src_offset     INTEGER := 1
    amt            INTEGER := 3000;
BEGIN
    SELECT b_col INTO lobd
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    SELECT b_col INTO lobs
        FROM lob_table
        WHERE key_value = 21;
    DBMS_LOB.COPY(lobd, lobs, amt, dest_offset, src_offset);
    COMMIT;
   EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;

CREATE OR REPLACE PROCEDURE Example_3b IS
    lobd, lobs     BLOB;
    dest_offset    INTEGER := 1
    src_offset     INTEGER := 1
    amt            INTEGER := 3000;
BEGIN
    SELECT b_col INTO lobd
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    SELECT b_col INTO lobs
        FROM lob_table
        WHERE key_value = 12;
    DBMS_LOB.COPY(lobd, lobs, amt, dest_offset, src_offset);
    COMMIT;
   EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;

CREATETEMPORARY Procedure

This procedure creates a temporary BLOB or CLOB and its corresponding index in your default temporary tablespace.

Syntax

DBMS_LOB.CREATETEMPORARY (
   lob_loc IN OUT NOCOPY BLOB,
   cache   IN            BOOLEAN,
   dur     IN            PLS_INTEGER := 10);
  
DBMS_LOB.CREATETEMPORARY (
   lob_loc IN OUT NOCOPY CLOB CHARACTER SET ANY_CS,
   cache   IN            BOOLEAN,
   dur     IN            PLS_INTEGER := 10);

Parameters

Table 23-11 CREATETEMPORARY Procedure Parameters
Parameter Description
lob_loc

LOB locator.

cache

Specifies if LOB should be read into buffer cache or not.

dur

1 of 2 predefined duration values (SESSION or CALL) which specifies a hint as to whether the temporary LOB is cleaned up at the end of the session or call.

If dur is omitted, then the session duration is used.

Example

DBMS_LOB.CREATETEMPORARY(Dest_Loc, TRUE)
See Also:

PL/SQL User's Guide and Reference for more information about NOCOPY and passing temporary lobs as parameters.

ERASE Procedure

This procedure erases an entire internal LOB or part of an internal LOB.


Note:

The length of the LOB is not decreased when a section of the LOB is erased. To decrease the length of the LOB value, see the "TRIM Procedure".


When data is erased from the middle of a LOB, zero-byte fillers or spaces are written for BLOBs or CLOBs respectively.

The actual number of bytes or characters erased can differ from the number you specified in the amount parameter if the end of the LOB value is reached before erasing the specified number. The actual number of characters or bytes erased is returned in the amount parameter.

Syntax

DBMS_LOB.ERASE (
   lob_loc           IN OUT   NOCOPY   BLOB,
   amount            IN OUT   NOCOPY   INTEGER,
   offset            IN                INTEGER := 1);

DBMS_LOB.ERASE (
   lob_loc           IN OUT   NOCOPY   CLOB CHARACTER SET ANY_CS,
   amount            IN OUT   NOCOPY   INTEGER,
   offset            IN                INTEGER := 1);

Parameters

Table 23-12 ERASE Procedure Parameters
Parameter Description
lob_loc

Locator for the LOB to be erased.

amount

Number of bytes (for BLOBs or BFILES) or characters (for CLOBs or NCLOBs) to be erased.

offset

Absolute offset (origin: 1) from the beginning of the LOB in bytes (for BLOBs) or characters (CLOBs).

Exceptions

Table 23-13 ERASE Procedure Exceptions
Exception Description
VALUE_ERROR

Any input parameter is NULL.

INVALID_ARGVAL

Either:

- amount < 1 or amount > LOBMAXSIZE

- offset < 1 or offset > LOBMAXSIZE

Usage Notes

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Example

CREATE OR REPLACE PROCEDURE Example_4 IS
    lobd       BLOB;
    amt        INTEGER := 3000;
BEGIN
    SELECT b_col INTO lobd
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    dbms_lob.erase(dest_lob, amt, 2000);
    COMMIT;
END;
See Also:

"TRIM Procedure"

FILECLOSE Procedure

This procedure closes a BFILE that has already been opened through the input locator.


Note:

Oracle has only read-only access to BFILEs. This means that BFILEs cannot be written through Oracle.


Syntax

DBMS_LOB.FILECLOSE (
    file_loc IN OUT NOCOPY BFILE); 

Parameters

Table 23-14 FILECLOSE Procedure Parameter
Parameter Description
file_loc

Locator for the BFILE to be closed.

Exceptions

Table 23-15 FILECLOSE Procedure Exceptions
Exception Description
VALUE_ERROR

NULL input value for file_loc.

UNOPENED_FILE

File was not opened with the input locator.

NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

INVALID_OPERATION

File does not exist, or you do not have access privileges on the file.

Example

CREATE OR REPLACE PROCEDURE Example_5 IS
    fil BFILE;
BEGIN
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 99;
    dbms_lob.fileopen(fil);
    -- file operations
    dbms_lob.fileclose(fil);
    EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;
See Also:

FILECLOSEALL Procedure

This procedure closes all BFILEs opened in the session.

Syntax

DBMS_LOB.FILECLOSEALL; 

Exceptions

Table 23-16 FILECLOSEALL Procedure Exception
Exception Description
UNOPENED_FILE

No file has been opened in the session.

Example

CREATE OR REPLACE PROCEDURE Example_6 IS
    fil BFILE;
BEGIN
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 99;
    dbms_lob.fileopen(fil);
    -- file operations
    dbms_lob.filecloseall;
    EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;
See Also:

FILEEXISTS Function

This function finds out if a given BFILE locator points to a file that actually exists on the server's file system.

Syntax

DBMS_LOB.FILEEXISTS (
   file_loc     IN    BFILE)
  RETURN INTEGER; 

Pragmas

pragma restrict_references(FILEEXISTS, WNDS, RNDS, WNPS, RNPS);

Parameters

Table 23-17 FILEEXISTS Function Parameter
Parameter Description
file_loc

Locator for the BFILE.

Returns

Table 23-18 FILEEXISTS Function Returns
Return Description
0

Physical file does not exist.

1

Physical file exists.

Exceptions

Table 23-19 FILEEXISTS Function Exceptions
Exception Description
NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

Example

CREATE OR REPLACE PROCEDURE Example_7 IS
    fil BFILE;
BEGIN    
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 12;
    IF (dbms_lob.fileexists(fil)) 
    THEN
        ; -- file exists code
    ELSE
        ; -- file does not exist code
    END IF;
    EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;
See Also:

"FILEISOPEN Function".

FILEGETNAME Procedure

This procedure determines the directory alias and filename, given a BFILE locator. This function only indicates the directory alias name and filename assigned to the locator, not if the physical file or directory actually exists.

The maximum constraint values for the dir_alias buffer is 30, and for the entire path name, it is 2000.

Syntax

DBMS_LOB.FILEGETNAME (
   file_loc   IN    BFILE, 
   dir_alias  OUT   VARCHAR2,
   filename   OUT   VARCHAR2); 

Parameters

Table 23-20 FILEGETNAME Procedure Parameters
Parameter Description
file_loc

Locator for the BFILE.

dir_alias

Directory alias.

filename

Name of the BFILE.

Exceptions

Table 23-21 FILEGETNAME Procedure Exceptions
Exception Description
VALUE_ERROR

Any of the input parameters are NULL or INVALID.

INVALID_ARGVAL

dir_alias or filename are NULL.

Example

CREATE OR REPLACE PROCEDURE Example_8 IS
    fil BFILE;
    dir_alias VARCHAR2(30);
    name VARCHAR2(2000);
BEGIN
    IF (dbms_lob.fileexists(fil))
    THEN
        dbms_lob.filegetname(fil, dir_alias, name);
        dbms_output.put_line("Opening " || dir_alias || name);
        dbms_lob.fileopen(fil, dbms_lob.file_readonly);
        -- file operations
        dbms_output.fileclose(fil); 
    END IF;
END;

FILEISOPEN Function

This function finds out whether a BFILE was opened with the given FILE locator.

If the input FILE locator was never passed to the FILEOPEN procedure, then the file is considered not to be opened by this locator. However, a different locator may have this file open. In other words, openness is associated with a specific locator.

Syntax

DBMS_LOB.FILEISOPEN (
   file_loc   IN    BFILE)
  RETURN INTEGER; 

Pragmas

pragma restrict_references(FILEISOPEN, WNDS, RNDS, WNPS, RNPS);

Parameters

Table 23-22 FILEISOPEN Function Parameter
Parameter Description
file_loc

Locator for the BFILE.

Returns

INTEGER: 0 = file is not open, 1 = file is open

Exceptions

Table 23-23 FILEISOPEN Function Exceptions
Exception Description
NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

Example

CREATE OR REPLACE PROCEDURE Example_9 IS
DECLARE
    fil      BFILE;
    pos      INTEGER;
    pattern  VARCHAR2(20);
BEGIN
    SELECT f_lob INTO fil FROM lob_table 
        WHERE key_value = 12;
    -- open the file
    IF (dbms_lob.fileisopen(fil))
    THEN
        pos := dbms_lob.instr(fil, pattern, 1025, 6);
         -- more file operations
         dbms_lob.fileclose(fil);
   ELSE
        ; -- return error
    END IF;
END;
See Also:

"FILEEXISTS Function"

FILEOPEN Procedure

This procedure opens a BFILE for read-only access. BFILEs may not be written through Oracle.

Syntax

DBMS_LOB.FILEOPEN (
   file_loc   IN OUT NOCOPY  BFILE, 
   open_mode  IN             BINARY_INTEGER := file_readonly); 

Parameters

Table 23-24 FILEOPEN Procedure Parameters
Parameter Description
file_loc

Locator for the BFILE.

open_mode

File access is read-only.

Exceptions

Table 23-25 FILEOPEN Procedure Exceptions
Exception Description
VALUE_ERROR

file_loc or open_mode is NULL.

INVALID_ARGVAL

open_mode is not equal to FILE_READONLY.

OPEN_TOOMANY

Number of open files in the session exceeds session_max_open_files.

NOEXIST_DIRECTORY

Directory associated with file_loc does not exist.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

INVALID_OPERATION

File does not exist, or you do not have access privileges on the file.

Example

CREATE OR REPLACE PROCEDURE Example_10 IS
    fil BFILE;
BEGIN
    -- open BFILE
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 99;
    IF (dbms_lob.fileexists(fil))
    THEN
        dbms_lob.fileopen(fil, dbms_lob.file_readonly);
        -- file operation
        dbms_lob.fileclose(fil);
    END IF;
    EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;
See Also:

FREETEMPORARY Procedure

This procedure frees the temporary BLOB or CLOB in your default temporary tablespace. After the call to FREETEMPORARY, the LOB locator that was freed is marked as invalid.

If an invalid LOB locator is assigned to another LOB locator using OCILobLocatorAssign in OCI or through an assignment operation in PL/SQL, then the target of the assignment is also freed and marked as invalid.

Syntax

DBMS_LOB.FREETEMPORARY (
   lob_loc  IN OUT  NOCOPY BLOB); 

DBMS_LOB.FREETEMPORARY (
   lob_loc  IN OUT  NOCOPY CLOB CHARACTER SET ANY_CS); 

Parameters

Table 23-26 FREETEMPORARY Procedure Parameters
Parameter Description
lob_loc

LOB locator.

Example

DECLARE 
  a blob; 
  b blob; 
BEGIN 
  dbms_lob.createtemporary(a, TRUE); 
  dbms_lob.createtemporary(b, TRUE); 
  ... 
  -- the following call frees lob a 
  dbms_lob.freetemporary(a); 
  -- at this point lob locator a is marked as invalid 
  -- the following assignment frees the lob b and marks it as invalid 
also 
  b := a; 
END; 

GETCHUNKSIZE Function

When creating the table, you can specify the chunking factor, which can be a multiple of Oracle blocks. This corresponds to the chunk size used by the LOB data layer when accessing or modifying the LOB value. Part of the chunk is used to store system-related information, and the rest stores the LOB value.

This function returns the amount of space used in the LOB chunk to store the LOB value.

Syntax

DBMS_LOB.GETCHUNKSIZE (
   lob_loc IN BLOB) 
  RETURN INTEGER; 

DBMS_LOB.GETCHUNKSIZE (
   lob_loc IN CLOB CHARACTER SET ANY_CS) 
  RETURN INTEGER; 

Pragmas

pragma restrict_references(GETCHUNKSIZE, WNDS, RNDS, WNPS, RNPS); 

Parameters

Table 23-27 GETCHUNKSIZE Function Parameters
Parameter Description
lob_loc

LOB locator.

Returns

The value returned for BLOBs is in terms of bytes. The value returned for CLOBs is in terms of characters.

Usage Notes

Performance is improved if you enter read/write requests using a multiple of this chunk size. For writes, there is an added benefit, because LOB chunks are versioned, and if all writes are done on a chunk basis, then no extra or excess versioning is done or duplicated. You could batch up the WRITE until you have enough for a chunk, instead of issuing several WRITE calls for the same chunk.

GETLENGTH Function

This function gets the length of the specified LOB. The length in bytes or characters is returned.

The length returned for a BFILE includes the EOF, if it exists. Any 0-byte or space filler in the LOB caused by previous ERASE or WRITE operations is also included in the length count. The length of an empty internal LOB is 0.

Syntax

DBMS_LOB.GETLENGTH (
   lob_loc    IN  BLOB) 
  RETURN INTEGER;
 
DBMS_LOB.GETLENGTH (
   lob_loc    IN  CLOB   CHARACTER SET ANY_CS) 
  RETURN INTEGER; 

DBMS_LOB.GETLENGTH (
   file_loc    IN  BFILE) 
  RETURN INTEGER;

Pragmas

pragma restrict_references(GETLENGTH, WNDS, WNPS, RNDS, RNPS);

Parameters

Table 23-28 GETLENGTH Function Parameter
Parameter Description
file_loc

The file locator for the LOB whose length is to be returned.

Returns

The length of the LOB in bytes or characters as an INTEGER. NULL is returned if the input LOB is NULL or if the input lob_loc is NULL. An error is returned in the following cases for BFILEs:

Examples

CREATE OR REPLACE PROCEDURE Example_11a IS
    lobd        BLOB;
    length      INTEGER;
BEGIN
    -- get the LOB locator
    SELECT b_lob INTO lobd FROM lob_table
        WHERE key_value = 42;
    length := dbms_lob.getlength(lobd);
    IF length IS NULL THEN
        dbms_output.put_line('LOB is null.');
    ELSE
        dbms_output.put_line('The length is '
            || length);
    END IF;
END;

CREATE OR REPLACE PROCEDURE Example_11b IS
DECLARE
    len INTEGER;
    fil BFILE;
BEGIN
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 12; 
    len := dbms_lob.length(fil);
END;

INSTR Function

This function returns the matching position of the nth occurrence of the pattern in the LOB, starting from the offset you specify.

The form of the VARCHAR2 buffer (the pattern parameter) must match the form of the CLOB parameter. In other words, if the input LOB parameter is of type NCLOB, then the buffer must contain NCHAR data. Conversely, if the input LOB parameter is of type CLOB, then the buffer must contain CHAR data.

For BFILEs, the file must be already opened using a successful FILEOPEN operation for this operation to succeed.

Operations that accept RAW or VARCHAR2 parameters for pattern matching, such as INSTR, do not support regular expressions or special matching characters (as in the case of SQL LIKE) in the pattern parameter or substrings.

Syntax

DBMS_LOB.INSTR (
   lob_loc    IN   BLOB,
   pattern    IN   RAW,
   offset     IN   INTEGER := 1,
   nth        IN   INTEGER := 1)
  RETURN INTEGER;

DBMS_LOB.INSTR (
   lob_loc    IN   CLOB      CHARACTER SET ANY_CS,
   pattern    IN   VARCHAR2  CHARACTER SET lob_loc%CHARSET,
   offset     IN   INTEGER := 1,
   nth        IN   INTEGER := 1)
  RETURN INTEGER;

DBMS_LOB.INSTR (
   file_loc   IN   BFILE,
   pattern    IN   RAW,
   offset     IN   INTEGER := 1,
   nth        IN   INTEGER := 1)
  RETURN INTEGER;

Pragmas

pragma restrict_references(INSTR, WNDS, WNPS, RNDS, RNPS);

Parameters

Table 23-29 INSTR Function Parameters
Parameter Description
lob_loc

Locator for the LOB to be examined.

file_loc

The file locator for the LOB to be examined.

pattern

Pattern to be tested for. The pattern is a group of RAW bytes for BLOBs, and a character string (VARCHAR2) for CLOBs.The maximum size of the pattern is 16383 bytes.

offset

Absolute offset in bytes (BLOBs) or characters (CLOBs) at which the pattern matching is to start. (origin: 1)

nth

Occurrence number, starting at 1.

Returns

Table 23-30 INSTR Function Returns
Return Description
INTEGER

Offset of the start of the matched pattern, in bytes or characters.

It returns 0 if the pattern is not found.

NULL

Either:

-any one or more of the IN parameters was NULL or INVALID.

-offset < 1 or offset > LOBMAXSIZE.

-nth < 1.

-nth > LOBMAXSIZE.

Exceptions

Table 23-31 INSTR Function Exceptions for BFILES
Exception Description
UNOPENED_FILE

File was not opened using the input locator.

NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

INVALID_OPERATION

File does not exist, or you do not have access privileges on the file.

Examples

CREATE OR REPLACE PROCEDURE Example_12a IS
    lobd        CLOB;
    pattern     VARCHAR2 := 'abcde';
    position    INTEGER  := 10000;
BEGIN
-- get the LOB locator
    SELECT b_col INTO lobd
        FROM lob_table
        WHERE key_value = 21;
    position := DBMS_LOB.INSTR(lobd,
                        pattern, 1025, 6);
    IF position = 0 THEN
        dbms_output.put_line('Pattern not found');
    ELSE
        dbms_output.put_line('The pattern occurs at ' 
                || position);
    END IF;
END;

CREATE OR REPLACE PROCEDURE Example_12b IS
DECLARE
    fil BFILE;
    pattern VARCHAR2;
    pos INTEGER;
BEGIN
    -- initialize pattern
    -- check for the 6th occurrence starting from 1025th byte
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 12;
    dbms_lob.fileopen(fil, dbms_lob.file_readonly);
    pos := dbms_lob.instr(fil, pattern, 1025, 6);
    dbms_lob.fileclose(fil);
END;
See Also:

"SUBSTR Function"

ISOPEN Function

This function checks to see if the LOB was already opened using the input locator. This subprogram is for internal and external LOBs.

Syntax

DBMS_LOB.ISOPEN (
   lob_loc IN BLOB) 
  RETURN INTEGER; 

DBMS_LOB.ISOPEN (
   lob_loc IN CLOB CHARACTER SET ANY_CS) 
  RETURN INTEGER; 

DBMS_LOB.ISOPEN (
   file_loc IN BFILE) 
  RETURN INTEGER; 

Pragmas

pragma restrict_references(ISOPEN, WNDS, RNDS, WNPS, RNPS); 

Parameters

Table 23-32 ISOPEN Function Parameters
Parameter Description
lob_loc

LOB locator.

file_loc

File locator.

Usage Notes

For BFILES, openness is associated with the locator. If the input locator was never passed to OPEN, the BFILE is not considered to be opened by this locator. However, a different locator may have opened the BFILE. More than one OPEN can be performed on the same BFILE using different locators.

For internal LOBs, openness is associated with the LOB, not with the locator. If locator1 opened the LOB, then locator2 also sees the LOB as open. For internal LOBs, ISOPEN requires a round-trip, because it checks the state on the server to see if the LOB is indeed open.

For external LOBs (BFILEs), ISOPEN also requires a round-trip, because that's where the state is kept.

ISTEMPORARY Function

Syntax

DBMS_LOB.ISTEMPORARY (
   lob_loc IN BLOB)
  RETURN INTEGER;
 
DBMS_LOB.ISTEMPORARY (
   lob_loc IN CLOB CHARACTER SET ANY_CS)
  RETURN INTEGER;

Pragmas

PRAGMA RESTRICT_REFERENCES(istemporary, WNDS, RNDS, WNPS, RNPS);

Parameters

Table 23-33 ISTEMPORARY Procedure Parameters
Parameter Description
lob_loc

LOB locator.

temporary

Boolean, which indicates whether the LOB is temporary or not.

Returns

This function returns TRUE in temporary if the locator is pointing to a temporary LOB. It returns FALSE otherwise.

LOADFROMFILE Procedure

This procedure copies all, or a part of, a source external LOB (BFILE) to a destination internal LOB.

You can specify the offsets for both the source and destination LOBs, and the number of bytes to copy from the source BFILE. The amount and src_offset, because they refer to the BFILE, are in terms of bytes, and the dest_offset is either in bytes or characters for BLOBs and CLOBs respectively.


Note:

The input BFILE must have been opened prior to using this procedure. No character set conversions are performed implicitly when binary BFILE data is loaded into a CLOB. The BFILE data must already be in the same character set as the CLOB in the database. No error checking is performed to verify this.


If the offset you specify in the destination LOB is beyond the end of the data currently in this LOB, then zero-byte fillers or spaces are inserted in the destination BLOB or CLOB respectively. If the offset is less than the current length of the destination LOB, then existing data is overwritten.

There is an error if the input amount plus offset exceeds the length of the data in the BFILE.


Note:

If the character set is varying width, UTF-8 for example, the LOB value is stored in the fixed-width UCS2 format. Therefore, if you are using DBMS_LOB.LOADFROMFILE, the data in the BFILE should be in the UCS2 character set instead of the UTF-8 character set. However, you should use sql*loader instead of LOADFROMFILE to load data into a CLOB or NCLOB because sql*loader will provide the necessary character set conversions.


Syntax

DBMS_LOB.LOADFROMFILE (
   dest_lob    IN OUT NOCOPY BLOB, 
   src_file    IN            BFILE, 
   amount      IN            INTEGER, 
   dest_offset IN            INTEGER  := 1, 
   src_offset  IN            INTEGER  := 1); 
  

Parameters

Table 23-34 LOADFROMFILE Procedure Parameters
Parameter Description
dest_lob

LOB locator of the target for the load.

src_file 

BFILE locator of the source for the load.

amount

Number of bytes to load from the BFILE.

dest_offset

Offset in bytes or characters in the destination LOB (origin: 1) for the start of the load.

src_offset

Offset in bytes in the source BFILE (origin: 1) for the start of the load.

Usage Requirements

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Exceptions

Table 23-35 LOADFROMFILE Procedure Exceptions
Exception Description
VALUE_ERROR

Any of the input parameters are NULL or INVALID.

INVALID_ARGVAL

Either:

- src_offset or dest_offset < 1.

- src_offset or dest_offset > LOBMAXSIZE.

- amount < 1.

- amount > LOBMAXSIZE.

Example

CREATE OR REPLACE PROCEDURE Example_l2f IS 
  lobd       BLOB; 
  fils       BFILE   := BFILENAME('SOME_DIR_OBJ','some_file'); 
  amt        INTEGER := 4000; 
BEGIN 
  SELECT b_lob INTO lobd FROM lob_table WHERE key_value = 42 FOR UPDATE;
  dbms_lob.fileopen(fils, dbms_lob.file_readonly); 
  dbms_lob.loadfromfile(lobd, fils, amt); 
  COMMIT; 
  dbms_lob.fileclose(fils); 

LOADBLOBFROMFILE Procedure

This procedure loads data from BFILE to internal BLOB. This achieves the same outcome as LOADFROMFILE, and returns the new offsets.

You can specify the offsets for both the source and destination LOBs, and the number of bytes to copy from the source BFILE. The amount and src_offset, because they refer to the BFILE, are in terms of bytes, and the dest_offset is in bytes for BLOBs.

If the offset you specify in the destination LOB is beyond the end of the data currently in this LOB, then zero-byte fillers or spaces are inserted in the destination BLOB. If the offset is less than the current length of the destination LOB, then existing data is overwritten.

There is an error if the input amount plus offset exceeds the length of the data in the BFILE (unless the amount specified is LOBMAXSIZE which you can specify to continue loading until the end of the BFILE is reached).

Syntax

DBMS_LOB.LOADBLOBFROMFILE (
   dest_lob    IN OUT NOCOPY BLOB, 
   src_bfile   IN            BFILE, 
   amount      IN            INTEGER, 
   dest_offset IN OUT        INTEGER, 
   src_offset  IN OUT        INTEGER);

Parameters

Table 23-36 LOADBLOBFROMFILE Procedure Parameters
Parameter Description
dest_lob

BLOB locator of the target for the load.

src_bfile 

BFILE locator of the source for the load.

amount

Number of bytes to load from the BFILE. You can also use DBMS_LOB.LOBMAXSIZE to load until the end of the BFILE.

dest_offset

(IN) Offset in bytes in the destination BLOB (origin: 1) for the start of the write. (OUT) New offset in bytes in the destination BLOB right after the end of this write, which is also where the next write should begin.

src_offset

(IN) Offset in bytes in the source BFILE (origin: 1) for the start of the read .(OUT) Offset in bytes in the source BFILE right after the end of this read, which is also where the next read should begin.

Usage Requirements

It is not mandatory that you wrap the LOB operation inside the OPEN/CLOSE operations. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the OPEN/CLOSE, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Constants and Defaults

There is no easy way to omit parameters. You must either declare a variable for IN/OUT parameter or provide a default value for the IN parameter. Here is a summary of the constants and the defaults that can be used.

.
Table 23-37 Suggested Values of the Parameter

Parameter

Default Value

Description

amount

DBMSLOB.LOBMAXSIZE (IN)

Load the entire file

dest_offset

1 (IN)

start from the beginning

src_offset

1 (IN)

start from the beginning

Constants defined in DBMSLOB.SQL

lobmaxsize                    CONSTANT INTEGER        := 4294967295;

Exceptions

Table 23-38 LOADBLOBFROMFILE Procedure Exceptions
Exception Description
VALUE_ERROR

Any of the input parameters are NULL or INVALID.

INVALID_ARGVAL

Either:

- src_offset or dest_offset < 1.

- src_offset or dest_offset > LOBMAXSIZE.

- amount < 1.

- amount > LOBMAXSIZE.

Example

TBD
;

LOADCLOBFROMFILE Procedure

This procedure loads data from a BFILE to an internal CLOB/NCLOB with necessary character set conversion and returns the new offsets.

You can specify the offsets for both the source and destination LOBs, and the number of bytes to copy from the source BFILE. The amount and src_offset, because they refer to the BFILE, are in terms of bytes, and the dest_offset is in characters for CLOBs.

If the offset you specify in the destination LOB is beyond the end of the data currently in this LOB, then zero-byte fillers or spaces are inserted in the destination CLOB. If the offset is less than the current length of the destination LOB, then existing data is overwritten.

There is an error if the input amount plus offset exceeds the length of the data in the BFILE (unless the amount specified is LOBMAXSIZE which you can specify to continue loading until the end of the BFILE is reached).

Syntax

DBMS_LOB.LOADCLOBFROMFILE (
   dest_lob       IN OUT NOCOPY   BLOB, 
   src_bfile      IN              BFILE, 
   amount         IN              INTEGER, 
   dest_offset    IN OUT          INTEGER, 
   src_offset     IN OUT          INTEGER,
   src_csid       IN              NUMBER,
   lang_context   IN OUT          INTEGER,
   warning        OUT             INTEGER);

Parameters

Table 23-39 LOADCLOBFROMFILE Procedure Parameters
Parameter Description
dest_lob

CLOB/NCLOB locator of the target for the load.

src_bfile 

BFILE locator of the source for the load.

amount

Number of bytes to load from the BFILE. Use DBMS_LOB.LOBMAXSIZE to load until the end of the BFILE.

dest_offset

(IN) Offset in characters in the destination CLOB (origin: 1) for the start of the write. (OUT) The new offset in characters right after the end of this load, which is also where the next load should start. It always points to the beginning of the first complete character after the end of load. If the last character is not complete, offset goes back to the beginning of the partial character.

src_offset

(IN) Offset in bytes in the source BFILE (origin: 1) for the start of the read.(OUT)Offset in bytes in the source BFILE right after the end of this read, which is also where the next read should begin.

src_csid

Character set id of the source (BFILE) file.

lang_context

(IN) Language context, such as shift status, for the current load. (OUT) The language context at the time when the current load stopped, and what the next load should be using if continuing loading from the same source. This information is returned to the user so that they can use it for the continuous load without losing or misinterpreting any source data. For the very first load or if do not care, simply use the default 0. The details of this language context is hidden from the user. One does not need to know what it is or what's in it in order to make the call

warning

(OUT) Warning message. This indicates something abnormal happened during the loading. It may or may not be caused by the user's mistake. The loading is completed as required, and it's up to the user to check the warning message. Currently, the only possible warning is the inconvertible character. This happens when the character in the source cannot be properly converted to a character in destination, and the default replacement character (e.g., '?') is used in place. The message is defined as warn_inconvertable_char in DBMSLOB.

Usage Requirements

Constants and Defaults

There is no easy way to omit parameters. You must either declare a variable for IN/OUT parameter or give a default value for the IN parameter. Here is a summary of the constants and the defaults that can be used.

.
Table 23-40 Suggested Values of the Parameter

Parameter

Default Value

Description

amount

DBMSLOB.LOBMAXSIZE (IN)

Load the entire file

dest_offset

1 (IN)

start from the beginning

src_offset

1 (IN)

start from the beginning

csid

0 (IN)

default csid, use destination csid

lang_context

0 (IN)

default language context

warning

0 (OUT)

no warning message, everything is ok

Constants defined in DBMSLOB.SQL

lobmaxsize                    CONSTANT INTEGER        := 4294967295;
warn_inconvertible_char       CONSTANT INTEGER        := 1;
default_csid                  CONSTANT INTEGER        := 0; 
default_lang_ctx              CONSTANT INTEGER        := 0;
no_warning                    CONSTANT INTEGER        := 0;

Exceptions

Table 23-41 LOADCLOBFROMFILE Procedure Exceptions
Exception Description
VALUE_ERROR

Any of the input parameters are NULL or INVALID.

INVALID_ARGVAL

Either:

- src_offset or dest_offset < 1.

- src_offset or dest_offset > LOBMAXSIZE.

- amount < 1.

- amount > LOBMAXSIZE.

Example

TBD
;

OPEN Procedure

This procedure opens a LOB, internal or external, in the indicated mode. Valid modes include read-only, and read/write. It is an error to open the same LOB twice.


Note:

If the LOB was opened in read-only mode, and if you try to write to the LOB, then an error is returned. BFILE can only be opened with read-only mode.


In Oracle8.0, the constant file_readonly was the only valid mode in which to open a BFILE. For Oracle 8i, two new constants have been added to the DBMS_LOB package: lob_readonly and lob_readwrite.

Syntax

DBMS_LOB.OPEN (
   lob_loc   IN OUT NOCOPY BLOB,
   open_mode IN            BINARY_INTEGER);
 
DBMS_LOB.OPEN (
   lob_loc   IN OUT NOCOPY CLOB CHARACTER SET ANY_CS,
   open_mode IN            BINARY_INTEGER);
 
DBMS_LOB.OPEN (
   file_loc  IN OUT NOCOPY BFILE,
   open_mode IN            BINARY_INTEGER := file_readonly);

Parameters

Table 23-42 OPEN Procedure Parameters
Parameter Description
lob_loc

LOB locator.

open_mode

Mode in which to open.

Usage Notes

OPEN requires a roundtrip to the server for both internal and external LOBs. For internal LOBs, OPEN triggers other code that relies on the OPEN call. For external LOBs (BFILEs), OPEN requires a round-trip because the actual operating system file on the server side is being opened.

It is not mandatory that you wrap all LOB operations inside the Open/Close APIs. However, if you open a LOB, you must close it before you commit or rollback the transaction; an error is produced if you do not. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

It is an error to commit the transaction before closing all opened LOBs that were opened by the transaction. When the error is returned, the openness of the open LOBs is discarded, but the transaction is successfully committed. Hence, all the changes made to the LOB and nonLOB data in the transaction are committed, but the domain and function-based indexes are not updated. If this happens, you should rebuild the functional and domain indexes on the LOB column.

READ Procedure

This procedure reads a piece of a LOB, and returns the specified amount into the buffer parameter, starting from an absolute offset from the beginning of the LOB.

The number of bytes or characters actually read is returned in the amount parameter. If the input offset points past the End of LOB, then amount is set to 0, and a NO_DATA_FOUND exception is raised.

Syntax

DBMS_LOB.READ (
   lob_loc   IN             BLOB,
   amount    IN OUT  NOCOPY BINARY_INTEGER,
   offset    IN             INTEGER,
   buffer    OUT            RAW);

DBMS_LOB.READ (
   lob_loc   IN             CLOB CHARACTER SET ANY_CS,
   amount    IN OUT  NOCOPY BINARY_INTEGER,
   offset    IN             INTEGER,
   buffer    OUT            VARCHAR2 CHARACTER SET lob_loc%CHARSET); 

DBMS_LOB.READ (
   file_loc   IN              BFILE,
   amount    IN OUT   NOCOPY BINARY_INTEGER,
   offset    IN              INTEGER,
   buffer    OUT             RAW);

Parameters

Table 23-43 READ Procedure Parameters
Parameter Description
lob_loc

Locator for the LOB to be read.

file_loc

The file locator for the LOB to be examined.

amount

Number of bytes (for BLOBs) or characters (for CLOBs) to read, or number that were read.

offset

Offset in bytes (for BLOBs) or characters (for CLOBs) from the start of the LOB (origin: 1).

buffer

Output buffer for the read operation.

Exceptions

Table 23-44 READ Procedure Exceptions
Exception Description
VALUE_ERROR

Any of lob_loc, amount, or offset parameters are NULL.

INVALID_ARGVAL

Either:

- amount < 1

- amount > MAXBUFSIZE

- offset < 1

- offset > LOBMAXSIZE

- amount is greater, in bytes or characters, than the capacity of buffer.

NO_DATA_FOUND

End of the LOB is reached, and there are no more bytes or characters to read from the LOB: amount has a value of 0.

Exceptions

Table 23-45 READ Procedure Exceptions for BFILEs
Exception Description
UNOPENED_FILE

File is not opened using the input locator.

NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

INVALID_OPERATION

File does not exist, or you do not have access privileges on the file.

Usage Notes

The form of the VARCHAR2 buffer must match the form of the CLOB parameter. In other words, if the input LOB parameter is of type NCLOB, then the buffer must contain NCHAR data. Conversely, if the input LOB parameter is of type CLOB, then the buffer must contain CHAR data.

When calling DBMS_LOB.READ from the client (for example, in a BEGIN/END block from within SQL*Plus), the returned buffer contains data in the client's character set. Oracle converts the LOB value from the server's character set to the client's character set before it returns the buffer to the user.

Examples

CREATE OR REPLACE PROCEDURE Example_13a IS
    src_lob        BLOB;
    buffer         RAW(32767);
    amt            BINARY_INTEGER := 32767;
    pos            INTEGER := 2147483647;
BEGIN
    SELECT b_col INTO src_lob
        FROM lob_table
        WHERE key_value = 21;
    LOOP
        dbms_lob.read (src_lob, amt, pos, buffer);
        -- process the buffer 
        pos := pos + amt;
    END LOOP;
    EXCEPTION
        WHEN NO_DATA_FOUND THEN
            dbms_output.put_line('End of data');
END;

CREATE OR REPLACE PROCEDURE Example_13b IS
    fil BFILE;
    buf RAW(32767);
    amt BINARY_INTEGER := 32767;
    pos INTEGER := 2147483647;
BEGIN
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 21;
    dbms_lob.fileopen(fil, dbms_lob.file_readonly);
    LOOP
        dbms_lob.read(fil, amt, pos, buf);
        -- process contents of buf
        pos := pos + amt;
    END LOOP;
    EXCEPTION
      WHEN NO_DATA_FOUND
      THEN
      BEGIN
        dbms_output.putline ('End of LOB value reached');
        dbms_lob.fileclose(fil);
      END;
END;

Example for efficient operating system I/O that performs better with block I/O rather than stream I/O:

CREATE OR REPLACE PROCEDURE Example_13c IS
    fil BFILE;
    amt BINARY_INTEGER := 1024; -- or n x 1024 for reading n 
    buf RAW(1024); -- blocks at a time
    tmpamt BINARY_INTEGER;
BEGIN
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 99;
    dbms_lob.fileopen(fil, dbms_lob.file_readonly);
    LOOP
        dbms_lob.read(fil, amt, pos, buf);
       -- process contents of buf
        pos := pos + amt;
    END LOOP;
    EXCEPTION
        WHEN NO_DATA_FOUND
        THEN
            BEGIN
                dbms_output.putline ('End of data reached');
                dbms_lob.fileclose(fil);
            END;
END;

SUBSTR Function

This function returns amount bytes or characters of a LOB, starting from an absolute offset from the beginning of the LOB.

For fixed-width n-byte CLOBs, if the input amount for SUBSTR is specified to be greater than (32767/n), then SUBSTR returns a character buffer of length (32767/n), or the length of the CLOB, whichever is lesser. For CLOBs in a varying-width character set, n is 2.

Syntax

DBMS_LOB.SUBSTR (
   lob_loc     IN    BLOB,
   amount      IN    INTEGER := 32767,
   offset      IN    INTEGER := 1)
  RETURN RAW;

DBMS_LOB.SUBSTR (
   lob_loc     IN    CLOB   CHARACTER SET ANY_CS,
   amount      IN    INTEGER := 32767,
   offset      IN    INTEGER := 1)
  RETURN VARCHAR2 CHARACTER SET lob_loc%CHARSET;

DBMS_LOB.SUBSTR (
   file_loc     IN    BFILE,
   amount      IN    INTEGER := 32767,
   offset      IN    INTEGER := 1)
  RETURN RAW;

Pragmas

pragma restrict_references(SUBSTR, WNDS, WNPS, RNDS, RNPS);

Parameters

Table 23-46 SUBSTR Function Parameters
Parameter Description
lob_loc

Locator for the LOB to be read.

file_loc

The file locator for the LOB to be examined.

amount

Number of bytes (for BLOBs) or characters (for CLOBs) to be read.

offset

Offset in bytes (for BLOBs) or characters (for CLOBs) from the start of the LOB (origin: 1).

Returns

Table 23-47 SUBSTR Function Returns
Return Description
RAW

Function overloading that has a BLOB or BFILE in parameter.

VARCHAR2

CLOB version.

NULL

Either:

- any input parameter is NULL

- amount < 1

- amount > 32767

- offset < 1

- offset > LOBMAXSIZE

Exceptions

Table 23-48 SUBSTR Function Exceptions for BFILE operations
Exception Description
UNOPENED_FILE

File is not opened using the input locator.

NOEXIST_DIRECTORY

Directory does not exist.

NOPRIV_DIRECTORY

You do not have privileges for the directory.

INVALID_DIRECTORY

Directory has been invalidated after the file was opened.

INVALID_OPERATION

File does not exist, or you do not have access privileges on the file.

Usage Notes

The form of the VARCHAR2 buffer must match the form of the CLOB parameter. In other words, if the input LOB parameter is of type NCLOB, then the buffer must contain NCHAR data. Conversely, if the input LOB parameter is of type CLOB, then the buffer must contain CHAR data.

When calling DBMS_LOB.SUBSTR from the client (for example, in a BEGIN/END block from within SQL*Plus), the returned buffer contains data in the client's character set. Oracle converts the LOB value from the server's character set to the client's character set before it returns the buffer to the user.

Examples

CREATE OR REPLACE PROCEDURE Example_14a IS
    src_lob        CLOB;
    pos            INTEGER := 2147483647;
    buf            VARCHAR2(32000);
BEGIN
    SELECT c_lob INTO src_lob FROM lob_table
        WHERE key_value = 21;
    buf := DBMS_LOB.SUBSTR(src_lob, 32767, pos);
    -- process the data 
END;

CREATE OR REPLACE PROCEDURE Example_14b IS
    fil BFILE;
    pos INTEGER := 2147483647;
    pattern RAW;
BEGIN
    SELECT f_lob INTO fil FROM lob_table WHERE key_value = 21;
    dbms_lob.fileopen(fil, dbms_lob.file_readonly);
    pattern := dbms_lob.substr(fil, 255, pos);
    dbms_lob.fileclose(fil);
END;  
See Also:

TRIM Procedure

This procedure trims the value of the internal LOB to the length you specify in the newlen parameter. Specify the length in bytes for BLOBs, and specify the length in characters for CLOBs.


Note:

The TRIM procedure decreases the length of the LOB to the value specified in the newlen parameter.


If you attempt to TRIM an empty LOB, then nothing occurs, and TRIM returns no error. If the new length that you specify in newlen is greater than the size of the LOB, then an exception is raised.

Syntax

DBMS_LOB.TRIM (
   lob_loc        IN OUT  NOCOPY BLOB,
   newlen         IN             INTEGER);

DBMS_LOB.TRIM (
   lob_loc        IN OUT  NOCOPY CLOB CHARACTER SET ANY_CS,
   newlen         IN             INTEGER);

Parameters

Table 23-49 TRIM Procedure Parameters
Parameter Description
lob_loc

Locator for the internal LOB whose length is to be trimmed.

newlen

New, trimmed length of the LOB value in bytes for BLOBs or characters for CLOBs.

Exceptions

Table 23-50 TRIM Procedure Exceptions
Exception Description
VALUE_ERROR

lob_loc is NULL.

INVALID_ARGVAL

Either:

- new_len < 0

- new_len > LOBMAXSIZE

Usage Notes

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Example

CREATE OR REPLACE PROCEDURE Example_15 IS
    lob_loc        BLOB;
BEGIN
-- get the LOB locator
    SELECT b_col INTO lob_loc
        FROM lob_table
        WHERE key_value = 42 FOR UPDATE;
    dbms_lob.trim(lob_loc, 4000);
    COMMIT;
END;
See Also:

WRITE Procedure

This procedure writes a specified amount of data into an internal LOB, starting from an absolute offset from the beginning of the LOB. The data is written from the buffer parameter.

WRITE replaces (overwrites) any data that already exists in the LOB at the offset, for the length you specify.

There is an error if the input amount is more than the data in the buffer. If the input amount is less than the data in the buffer, then only amount bytes or characters from the buffer is written to the LOB. If the offset you specify is beyond the end of the data currently in the LOB, then zero-byte fillers or spaces are inserted in the BLOB or CLOB respectively.

Syntax

DBMS_LOB.WRITE (
   lob_loc  IN OUT NOCOPY  BLOB,
   amount   IN             BINARY_INTEGER,
   offset   IN             INTEGER,
   buffer   IN             RAW);

DBMS_LOB.WRITE (
   lob_loc  IN OUT  NOCOPY CLOB   CHARACTER SET ANY_CS,
   amount   IN             BINARY_INTEGER,
   offset   IN             INTEGER,
   buffer   IN             VARCHAR2 CHARACTER SET lob_loc%CHARSET); 

Parameters

Table 23-51 WRITE Procedure Parameters
Parameter Description
lob_loc

Locator for the internal LOB to be written to.

amount

Number of bytes (for BLOBs) or characters (for CLOBs) to write, or number that were written.

offset

Offset in bytes (for BLOBs) or characters (for CLOBs) from the start of the LOB (origin: 1) for the write operation.

buffer

Input buffer for the write.

Exceptions

Table 23-52 WRITE Procedure Exceptions
Exception Description
VALUE_ERROR

Any of lob_loc, amount, or offset parameters are NULL, out of range, or INVALID.

INVALID_ARGVAL

Either:

- amount < 1

- amount > MAXBUFSIZE

- offset < 1

- offset > LOBMAXSIZE

Usage Notes

The form of the VARCHAR2 buffer must match the form of the CLOB parameter. In other words, if the input LOB parameter is of type NCLOB, then the buffer must contain NCHAR data. Conversely, if the input LOB parameter is of type CLOB, then the buffer must contain CHAR data.

When calling DBMS_LOB.WRITE from the client (for example, in a BEGIN/END block from within SQL*Plus), the buffer must contain data in the client's character set. Oracle converts the client-side buffer to the server's character set before it writes the buffer data to the LOB.

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Example

CREATE OR REPLACE PROCEDURE Example_16 IS
    lob_loc        BLOB;
    buffer         RAW;
    amt            BINARY_INTEGER := 32767;
    pos            INTEGER := 2147483647;
    i              INTEGER;
BEGIN
    SELECT b_col INTO lob_loc
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    FOR i IN 1..3 LOOP
        dbms_lob.write (lob_loc, amt, pos, buffer);
        -- fill in more data 
        pos := pos + amt;
    END LOOP;
    EXCEPTION
        WHEN some_exception
        THEN handle_exception;
END;
See Also:

WRITEAPPEND Procedure

This procedure writes a specified amount of data to the end of an internal LOB. The data is written from the buffer parameter.

There is an error if the input amount is more than the data in the buffer. If the input amount is less than the data in the buffer, then only amount bytes or characters from the buffer are written to the end of the LOB.

Syntax

DBMS_LOB.WRITEAPPEND (
   lob_loc IN OUT NOCOPY BLOB, 
   amount  IN            BINARY_INTEGER, 
   buffer  IN            RAW); 

DBMS_LOB.WRITEAPPEND (
   lob_loc IN OUT NOCOPY CLOB CHARACTER SET ANY_CS, 
   amount  IN            BINARY_INTEGER, 
   buffer  IN            VARCHAR2 CHARACTER SET lob_loc%CHARSET); 

Parameters

Table 23-53 WRITEAPPEND Procedure Parameters
Parameter Description
lob_loc

Locator for the internal LOB to be written to.

amount

Number of bytes (for BLOBs) or characters (for CLOBs) to write, or number that were written.

buffer

Input buffer for the write.

Exceptions

Table 23-54 WRITEAPPEND Procedure Exceptions
Exception Description
VALUE_ERROR

Any of lob_loc, amount, or offset parameters are NULL, out of range, or INVALID.

INVALID_ARGVAL

Either:

- amount < 1

- amount > MAXBUFSIZE

Usage Notes

The form of the VARCHAR2 buffer must match the form of the CLOB parameter. In other words, if the input LOB parameter is of type NCLOB, then the buffer must contain NCHAR data. Conversely, if the input LOB parameter is of type CLOB, then the buffer must contain CHAR data.

When calling DBMS_LOB.WRITEAPPEND from the client (for example, in a BEGIN/END block from within SQL*Plus), the buffer must contain data in the client's character set. Oracle converts the client-side buffer to the server's character set before it writes the buffer data to the LOB.

It is not mandatory that you wrap the LOB operation inside the Open/Close APIs. If you did not open the LOB before performing the operation, the functional and domain indexes on the LOB column are updated during the call. However, if you opened the LOB before performing the operation, you must close it before you commit or rollback the transaction. When an internal LOB is closed, it updates the functional and domain indexes on the LOB column.

If you do not wrap the LOB operation inside the Open/Close API, the functional and domain indexes are updated each time you write to the LOB. This can adversely affect performance. Therefore, it is recommended that you enclose write operations to the LOB within the OPEN or CLOSE statement.

Example

CREATE OR REPLACE PROCEDURE Example_17 IS
    lob_loc    BLOB;
    buffer     RAW;
    amt        BINARY_INTEGER := 32767;
    i          INTEGER;
BEGIN
    SELECT b_col INTO lob_loc
        FROM lob_table
        WHERE key_value = 12 FOR UPDATE;
    FOR i IN 1..3 LOOP
        -- fill the buffer with data to be written to the lob
        dbms_lob.writeappend (lob_loc, amt, buffer);
    END LOOP;
END;
See Also:

Go to previous page Go to beginning of chapter Go to next page
Oracle
Copyright © 2000, 2002 Oracle Corporation.

All Rights Reserved.
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback