PK
(Aoa, mimetypeapplication/epub+zipPK (A iTunesMetadata.pliste
This chapter contains these topics:
The data interface for persistent LOBs includes a set of Java, PL/SQL, and OCI APIs that are extended to work with LOB data types. These APIs, originally designed for use with legacy data types such as LONG
, LONG
RAW
, and VARCHAR2
, can also be used with the corresponding LOB data types shown in Table 20-1 and Table 20-2. These tables show the legacy data types in the "bind or define type" column and the corresponding supported LOB data type in the "LOB column type" column. You can use the data interface for LOBs to store and manipulate character data and binary data in a LOB column just as if it were stored in the corresponding legacy datatype.
Note: The data interface works for LOB columns and LOBs that are attributes of objects. In this chapter "LOB columns" means LOB columns and LOB attributes.You can use array bind and define interfaces to insert and select multiple rows in one round trip. |
For simplicity, this chapter focuses on character datatypes; however, the same concepts apply to the full set of character and binary datatypes listed in Table 20-1 and Table 20-2. CLOB
also means NCLOB
in these tables.
Table 20-1 Corresponding LONG and LOB Datatypes in SQL and PL/SQL
Bind or Define Type | LOB Column Type | Used For Storing |
---|---|---|
|
|
Character data |
|
|
Character data |
|
|
Character data |
|
|
Binary data |
|
|
Binary data |
Table 20-2 Corresponding LONG and LOB Datatypes in OCI
Bind or Define Type | LOB Column Type | Used For Storing |
---|---|---|
|
|
Character data |
|
|
Character data |
|
|
Character data |
|
|
Character data |
|
|
Binary data |
|
|
Binary data |
|
|
Binary data |
Using the data interface for persistent LOBs has the following benefits:
If your application uses LONG
datatypes, then you can use the same application with LOB datatypes with little or no modification of your existing application required. To do so, just convert LONG
datatype columns in your tables to LOB datatype columns as discussed in Chapter 18, "Migrating Columns from LONGs to LOBs".
Performance is better for OCI applications that use sequential access techniques. A piecewise INSERT
or fetch using the data interface has comparable performance to using OCI functions like OCILobRead2()
and OCILobWrite2()
. Because the data interface allows more than 4K bytes of data to be inserted into a LOB in a single OCI call, a round-trip to the server is saved.
You can read LOB data in one OCIStmtFetch()
call, instead of fetching the LOB locator first and then calling OCILobRead2()
. This improves performance when you want to read LOB data starting at the beginning.
You can use array bind and define interfaces to insert and select multiple rows with LOBs in one round trip.
The data interface enables you to use LONG
and LOB datatypes listed in Table 20-1 to perform the following operations in PL/SQL:
INSERT
or UPDATE
character data stored in datatypes such as VARCHAR2
, CHAR
, or LONG
into a CLOB
column.
INSERT
or UPDATE
binary data stored in datatypes such as RAW
or LONG
RAW
into a BLOB
column.
Use the SELECT
statement on CLOB
columns to select data into a character buffer variable such as CHAR
, LONG
, or VARCHAR2
.
Use the SELECT
statement on BLOB
columns to select data into a binary buffer variable such as RAW
and LONG
RAW
.
Make cross-type assignments (implicit type conversions) between CLOB
and VARCHAR2
, CHAR
, or LONG
variables.
Make cross-type assignments (implicit type conversions) between BLOB
and RAW
or LONG
RAW
variables.
Pass LOB datatypes to functions defined to accept LONG
datatypes or pass LONG
datatypes to functions defined to accept LOB datatypes. For example, you can pass a CLOB
instance to a function defined to accept another character type, such as VARCHAR2
, CHAR
, or LONG
.
Use CLOB
s with other PL/SQL functions and operators that accept VARCHAR2
arguments such as INSTR
and SUBSTR
. See "Passing CLOBs to SQL and PL/SQL Built-In Functions" for a complete list.
Note: When using the data interface for LOBs with theSELECT statement in PL/SQL, you cannot specify the amount you want to read. You can only specify the buffer length of your buffer. If your buffer length is smaller than the LOB data length, then the database throws an exception. |
See Also:
|
This section describes techniques you use to access LOB columns or attributes using the data interface for persistent LOBs.
Data from CLOB
and BLOB
columns or attributes can be referenced by regular SQL statements, such as INSERT
, UPDATE
, and SELECT
.
There is no piecewise INSERT
, UPDATE
, or fetch routine in PL/SQL. Therefore, the amount of data that can be accessed from a LOB column or attribute is limited by the maximum character buffer size. PL/SQL supports character buffer sizes up to 32KB - 1 (32767 bytes). For this reason, only LOBs less than 32K bytes in size can be accessed by PL/SQL applications using the data interface for persistent LOBs.
If you must access more than 32KB -1 using the data interface, then you must make OCI calls from the PL/SQL code to use the APIs for piece-wise insert and fetch.
Use he following are guidelines for using the data interface to access LOB columns or attributes:
INSERT operations
You can INSERT
into tables containing LOB columns or attributes using regular INSERT
statements in the VALUES
clause. The field of the LOB column can be a literal, a character datatype, a binary datatype, or a LOB locator.
UPDATE
operations
LOB columns or attributes can be updated as a whole by UPDATE
... SET
statements. In the SET
clause, the new value can be a literal, a character datatype, a binary datatype, or a LOB locator.
4000 byte limit on hexadecimal to raw and raw to hexadecimal conversions
The database does not do implicit hexadecimal to RAW
or RAW
to hexadecimal conversions on data that is more than 4000 bytes in size. You cannot bind a buffer of character data to a binary datatype column, and you cannot bind a buffer of binary data to a character datatype column if the buffer is over 4000 bytes in size. Attempting to do so results in your column data being truncated at 4000 bytes.
For example, you cannot bind a VARCHAR2
buffer to a LONG
RAW
or a BLOB
column if the buffer is more than 4000 bytes in size. Similarly, you cannot bind a RAW
buffer to a LONG
or a CLOB
column if the buffer is more than 4000 bytes in size.
SELECT
operations
LOB columns or attributes can be selected into character or binary buffers in PL/SQL. If the LOB column or attribute is longer than the buffer size, then an exception is raised without filling the buffer with any data. LOB columns or attributes can also be selected into LOB locators.
Implicit assignment and parameter passing are supported for LOB columns. For the datatypes listed in Table 20-1 and Table 20-2, you can pass or assign: any character type to any other character type, or any binary type to any other binary type using the data interface for persistent LOBs.
Implicit assignment works for variables declared explicitly and for variables declared by referencing an existing column type using the %TYPE
attribute as show in the following example. This example assumes that column long_col
in table t
has been migrated from a LONG
to a CLOB
column.
CREATE TABLE t (long_col LONG); -- Alter this table to change LONG column to LOB DECLARE a VARCHAR2(100); b t.long_col%type; -- This variable changes from LONG to CLOB BEGIN SELECT * INTO b FROM t; a := b; -- This changes from "VARCHAR2 := LONG to VARCHAR2 := CLOB b := a; -- This changes from "LONG := VARCHAR2 to CLOB := VARCHAR2 END;
Implicit parameter passing is allowed between functions and procedures. For example, you can pass a CLOB
to a function or procedure where the formal parameter is defined as a VARCHAR2
.
Note: The assigning aVARCHAR2 buffer to a LOB variable is somewhat less efficient than assigning a VARCHAR2 to a LONG variable because the former involves creating a temporary LOB. Therefore, PL/SQL users experience a slight deterioration in the performance of their applications. |
Implicit parameter passing is also supported for built-in PL/SQL functions that accept character data. For example, INSTR
can accept a CLOB
and other character data.
Any SQL or PL/SQL built-in function that accepts a VARCHAR2
can accept a CLOB
as an argument. Similarly, a VARCHAR2
variable can be passed to any DBMS_LOB
API for any parameter that takes a LOB locator.
In PL/SQL, the following explicit conversion functions convert other data types to CLOB
and BLOB
datatypes as follows:
TO_CLOB()
converts LONG
, VARCHAR2
, and CHAR
to CLOB
TO_BLOB()
converts LONG RAW
and RAW
to BLOB
Also note that the conversion function TO_CHAR()
can convert a CLOB
to a CHAR
type.
When a PL/SQL or C procedure is called from SQL, buffers with more than 4000 bytes of data are not allowed.
You can call a PL/SQL or C procedure from PL/SQL. You can pass a CLOB
as an actual parameter where CHR
is the formal parameter, or vice versa. The same holds for BLOB
s and RAW
s.
One example of when these cases can arise is when either the formal or the actual parameter is an anchored type, that is, the variable is declared using the table_name.column_name
%type
syntax.
PL/SQL procedures or functions can accept a CLOB
or a VARCHAR2
as a formal parameter. For example the PL/SQL procedure could be one of the following:
When the formal parameter is a CLOB:
CREATE OR REPLACE PROCEDURE get_lob(table_name IN VARCHAR2, lob INOUT CLOB) AS ... BEGIN ... END; /
When the formal parameter is a VARCHAR2:
CREATE OR REPLACE PROCEDURE get_lob(table_name IN VARCHAR2, lob INOUT VARCHAR2) AS ... BEGIN ... END; /
The calling function could be of any of the following types:
When the actual parameter is a CHR:
create procedure ... declare c VARCHAR2[200]; BEGIN get_lob('table_name', c); END;
When the actual parameter is a CLOB:
create procedure ... declare c CLOB; BEGIN get_lob('table_name', c); END;
Binds of all sizes are supported for INSERT
and UPDATE
operations on LOB columns. Multiple binds of any size are allowed in a single INSERT
or UPDATE
statement.
Note: When you create a table, the length of the default value you specify for any LOB column is restricted to 4000 bytes. |
If you bind more than 4000 bytes of data to a BLOB
or a CLOB
, and the data consists of a SQL operator, then Oracle Database limits the size of the result to at most 4000 bytes.
The following statement inserts only 4000 bytes because the result of LPAD
is limited to 4000 bytes:
INSERT INTO print_media (ad_sourcetext) VALUES (lpad('a', 5000, 'a'));
The following statement inserts only 2000 bytes because the result of LPAD
is limited to 4000 bytes, and the implicit hexadecimal to raw conversion converts it to 2000 bytes of RAW
data:
INSERT INTO print_media (ad_photo) VALUES (lpad('a', 5000, 'a'));
The following example illustrates how the result for SQL operators is limited to 4000 bytes.
/* The following command inserts only 4000 bytes because the result of * LPAD is limited to 4000 bytes */ INSERT INTO print_media(product_id, ad_id, ad_sourcetext) VALUES (2004, 5, lpad('a', 5000, 'a')); SELECT LENGTH(ad_sourcetext) FROM print_media WHERE product_id=2004 AND ad_id=5; ROLLBACK; /* The following command inserts only 2000 bytes because the result of * LPAD is limited to 4000 bytes, and the implicit hex to raw conversion * converts it to 2000 bytes of RAW data. */ INSERT INTO print_media(product_id, ad_id, ad_composite) VALUES (2004, 5, lpad('a', 5000, 'a')); SELECT LENGTH(ad_composite) from print_media WHERE product_id=2004 AND ad_id=5; ROLLBAACK;
The following lists the restrictions for binds of more than 4000 bytes:
If a table has both LONG
and LOB columns, then you can bind more than 4000 bytes of data to either the LONG
or LOB columns, but not both in the same statement.
In an INSERT
AS
SELECT
operation, binding of any length data to LOB columns is not allowed.
Parallel execution of the following DML operations on tables with LOB columns is supported. These operations run in parallel execution mode only when performed on a partitioned table. DML statements on non-partitioned tables with LOB columns continue to execute in serial execution mode.
INSERT AS SELECT
CREATE TABLE AS SELECT
DELETE
UPDATE
MERGE
(conditional UPDATE
and INSERT
)
Multi-table INSERT
See Also: Oracle Database Administrator's Guide section "Managing Processes for Parallel SQL Execution" |
DECLARE bigtext VARCHAR2(32767); smalltext VARCHAR2(2000); bigraw RAW (32767); BEGIN bigtext := LPAD('a', 32767, 'a'); smalltext := LPAD('a', 2000, 'a'); bigraw := utl_raw.cast_to_raw (bigtext); /* Multiple long binds for LOB columns are allowed for INSERT: */ INSERT INTO print_media(product_id, ad_id, ad_sourcetext, ad_composite) VALUES (2004, 1, bigtext, bigraw); /* Single long bind for LOB columns is allowed for INSERT: */ INSERT INTO print_media (product_id, ad_id, ad_sourcetext) VALUES (2005, 2, smalltext); bigtext := LPAD('b', 32767, 'b'); smalltext := LPAD('b', 20, 'a'); bigraw := utl_raw.cast_to_raw (bigtext); /* Multiple long binds for LOB columns are allowed for UPDATE: */ UPDATE print_media SET ad_sourcetext = bigtext, ad_composite = bigraw, ad_finaltext = smalltext; /* Single long bind for LOB columns is allowed for UPDATE: */ UPDATE print_media SET ad_sourcetext = smalltext, ad_finaltext = bigtext; /* The following is NOT allowed because we are trying to insert more than 4000 bytes of data in a LONG and a LOB column: */ INSERT INTO print_media(product_id, ad_id, ad_sourcetext, press_release) VALUES (2030, 3, bigtext, bigtext); /* Insert of data into LOB attribute is allowed */ INSERT INTO print_media(product_id, ad_id, ad_header) VALUES (2049, 4, adheader_typ(null, null, null, bigraw)); /* The following is not allowed because we try to perform INSERT AS SELECT data INTO LOB */ INSERT INTO print_media(product_id, ad_id, ad_sourcetext) SELECT 2056, 5, bigtext FROM dual; END; /
INSERT
and UPDATE
statements on LOBs are used in the same way as on LONG
s. For example:
DECLARE ad_buffer VARCHAR2(100); BEGIN INSERT INTO print_media(product_id, ad_id, ad_sourcetext) VALUES(2004, 5, 'Source for advertisement 1'); UPDATE print_media SET ad_sourcetext= 'Source for advertisement 2' WHERE product_id=2004 AND ad_id=5; /* This retrieves the LOB column if it is up to 100 bytes, otherwise it * raises an exception */ SELECT ad_sourcetext INTO ad_buffer FROM print_media WHERE product_id=2004 AND ad_id=5; END; /
The data interface for LOBs enables implicit assignment and parameter passing as shown in the following example:
CREATE TABLE t (clob_col CLOB, blob_col BLOB); INSERT INTO t VALUES('abcdefg', 'aaaaaa'); DECLARE var_buf VARCHAR2(100); clob_buf CLOB; raw_buf RAW(100); blob_buf BLOB; BEGIN SELECT * INTO clob_buf, blob_buf FROM t; var_buf := clob_buf; clob_buf:= var_buf; raw_buf := blob_buf; blob_buf := raw_buf; END; / CREATE OR REPLACE PROCEDURE FOO ( a IN OUT CLOB) IS BEGIN -- Any procedure body a := 'abc'; END; / CREATE OR REPLACE PROCEDURE BAR (b IN OUT VARCHAR2) IS BEGIN -- Any procedure body b := 'xyz'; END; / DECLARE a VARCHAR2(100) := '1234567'; b CLOB; BEGIN FOO(a); SELECT clob_col INTO b FROM t; BAR(b); END; /
This example illustrates the use of CLOB
s in PL/SQL built-in functions, using the data interface for LOBs:
DECLARE my_ad CLOB; revised_ad CLOB; myGist VARCHAR2(100):= 'This is my gist.'; revisedGist VARCHAR2(100); BEGIN INSERT INTO print_media (product_id, ad_id, ad_sourcetext) VALUES (2004, 5, 'Source for advertisement 1'); -- select a CLOB column into a CLOB variable SELECT ad_sourcetext INTO my_ad FROM print_media WHERE product_id=2004 AND ad_id=5; -- perform VARCHAR2 operations on a CLOB variable revised_ad := UPPER(SUBSTR(my_ad, 1, 20)); -- revised_ad is a temporary LOB -- Concat a VARCHAR2 at the end of a CLOB revised_ad := revised_ad || myGist; -- The following statement raises an error if my_ad is -- longer than 100 bytes myGist := my_ad; END; /