| Oracle9i Supplied PL/SQL Packages and Types Reference Release 2 (9.2) Part Number A96612-01 |
|
DBMS_LOB , 2 of 2
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.
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);
| Parameter | Description |
|---|---|
dest_lob |
Locator for the internal |
src_lob |
Locator for the internal |
| Exception | Description |
|---|---|
VALUE_ERROR |
Either the source or the destination |
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.
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;
This procedure closes a previously opened internal or external LOB.
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);
No error is returned if the BFILE exists but is not opened. An error is returned if the LOB is not open.
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.
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.
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;
pragma restrict_references(COMPARE, WNDS, WNPS, RNDS, RNPS);
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;
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.
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);
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of the input parameters are |
INVALID_ARGVAL |
- - - |
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.
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;
This procedure creates a temporary BLOB or CLOB and its corresponding index in your default temporary tablespace.
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);
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. |
This procedure erases an entire internal LOB or part of an internal LOB.
|
Note: The length of the |
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.
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);
| Exception | Description |
|---|---|
VALUE_ERROR |
Any input parameter is |
INVALID_ARGVAL |
- - |
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.
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;
This procedure closes a BFILE that has already been opened through the input locator.
|
Note: Oracle has only read-only access to |
DBMS_LOB.FILECLOSE ( file_loc IN OUT NOCOPY BFILE);
| Parameter | Description |
|---|---|
file_loc |
Locator for the |
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;
This procedure closes all BFILEs opened in the session.
DBMS_LOB.FILECLOSEALL;
| Exception | Description |
|---|---|
UNOPENED_FILE |
No file has been opened in the session. |
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;
This function finds out if a given BFILE locator points to a file that actually exists on the server's file system.
DBMS_LOB.FILEEXISTS ( file_loc IN BFILE) RETURN INTEGER;
pragma restrict_references(FILEEXISTS, WNDS, RNDS, WNPS, RNPS);
| Parameter | Description |
|---|---|
file_loc |
Locator for the |
| Return | Description |
|---|---|
0 |
Physical file does not exist. |
1 |
Physical file exists. |
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;
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.
DBMS_LOB.FILEGETNAME ( file_loc IN BFILE, dir_alias OUT VARCHAR2, filename OUT VARCHAR2);
| Parameter | Description |
|---|---|
file_loc |
Locator for the |
dir_alias |
Directory alias. |
filename |
Name of the |
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of the input parameters are |
INVALID_ARGVAL |
|
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;
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.
DBMS_LOB.FILEISOPEN ( file_loc IN BFILE) RETURN INTEGER;
pragmarestrict_references(FILEISOPEN,WNDS,RNDS,WNPS,RNPS);
| Parameter | Description |
|---|---|
file_loc |
Locator for the |
INTEGER: 0 = file is not open, 1 = file is open
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;
This procedure opens a BFILE for read-only access. BFILEs may not be written through Oracle.
DBMS_LOB.FILEOPEN ( file_loc IN OUT NOCOPY BFILE, open_mode IN BINARY_INTEGER := file_readonly);
| Parameter | Description |
|---|---|
file_loc |
Locator for the |
open_mode |
File access is read-only. |
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;
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.
DBMS_LOB.FREETEMPORARY ( lob_loc IN OUT NOCOPY BLOB); DBMS_LOB.FREETEMPORARY ( lob_loc IN OUT NOCOPY CLOB CHARACTER SET ANY_CS);
| Parameter | Description |
|---|---|
lob_loc |
|
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;
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.
DBMS_LOB.GETCHUNKSIZE ( lob_loc IN BLOB) RETURN INTEGER; DBMS_LOB.GETCHUNKSIZE ( lob_loc IN CLOB CHARACTER SET ANY_CS) RETURN INTEGER;
pragma restrict_references(GETCHUNKSIZE, WNDS, RNDS, WNPS, RNPS);
| Parameter | Description |
|---|---|
lob_loc |
|
The value returned for BLOBs is in terms of bytes. The value returned for CLOBs is in terms of characters.
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.
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.
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;
pragma restrict_references(GETLENGTH, WNDS, WNPS, RNDS, RNPS);
| Parameter | Description |
|---|---|
file_loc |
The file locator for the |
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:
lob_loc does not have the necessary directory and operating system privilegeslob_loc cannot be read because of an operating system read errorCREATE 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;
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.
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;
pragma restrict_references(INSTR, WNDS, WNPS, RNDS, RNPS);
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;
This function checks to see if the LOB was already opened using the input locator. This subprogram is for internal and external LOBs.
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;
pragma restrict_references(ISOPEN, WNDS, RNDS, WNPS, RNPS);
| Parameter | Description |
|---|---|
lob_loc |
|
file_loc |
File locator. |
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.
DBMS_LOB.ISTEMPORARY ( lob_loc IN BLOB) RETURN INTEGER; DBMS_LOB.ISTEMPORARY ( lob_loc IN CLOB CHARACTER SET ANY_CS) RETURN INTEGER;
PRAGMA RESTRICT_REFERENCES(istemporary, WNDS, RNDS, WNPS, RNPS);
| Parameter | Description |
|---|---|
lob_loc |
|
temporary |
Boolean, which indicates whether the LOB is temporary or not. |
This function returns TRUE in temporary if the locator is pointing to a temporary LOB. It returns FALSE otherwise.
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.
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.
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);
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.
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of the input parameters are |
INVALID_ARGVAL |
- - - |
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);
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).
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);
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.
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.
|
Parameter |
Default Value |
Description |
|---|---|---|
|
|
|
Load the entire file |
|
|
|
start from the beginning |
|
|
|
start from the beginning |
Constants defined in DBMSLOB.SQL
lobmaxsize CONSTANT INTEGER := 4294967295;
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of the input parameters are |
INVALID_ARGVAL |
- - - |
TBD ;
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).
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);
csid=0 indicates the default behavior that uses database csid for CLOB and national csid for NCLOB in the place of source csid. Conversion is still necessary if it is of varying widthLOB 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.
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.
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;
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of the input parameters are |
INVALID_ARGVAL |
- - - |
TBD ;
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 |
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.
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);
| Parameter | Description |
|---|---|
lob_loc |
|
open_mode |
Mode in which to open. |
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.
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.
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);
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.
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;
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.
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;
pragma restrict_references(SUBSTR, WNDS, WNPS, RNDS, RNPS);
| Return | Description |
|---|---|
RAW |
Function overloading that has a |
VARCHAR2 |
|
NULL |
- |
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.
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;
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 |
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.
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);
| Parameter | Description |
|---|---|
lob_loc |
Locator for the internal |
newlen |
New, trimmed length of the |
| Exception | Description |
|---|---|
VALUE_ERROR |
|
INVALID_ARGVAL |
- |
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.
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;
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.
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);
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of |
INVALID_ARGVAL |
- |
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.
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;
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.
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);
| Exception | Description |
|---|---|
VALUE_ERROR |
Any of |
INVALID_ARGVAL |
- |
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.
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;
|
![]() Copyright © 2000, 2002 Oracle Corporation. All Rights Reserved. |
|