Oracle8i Application Developer's Guide - Large Objects (LOBs) Release 2 (8.1.6) Part Number A76940-01 |
|
Modeling and Design, 4 of 12
If a LOB column is NULL, no data blocks are used to store the information. The NULL value is stored in the row just like any other NULL value. This is true even when you specify DISABLE STORAGE IN ROW
for the LOB.
If a LOB column is initialized with EMPTY_CLOB() or EMPTY_BLOB(), instead of NULL, a LOB locator is stored in the row. No additional storage is used.
ENABLE
or DISABLE STORAGE IN ROW
. In addition, an entire chunksize of data blocks is used to store the one byte of data if the LOB column was created as DISABLE STORAGE IN ROW.
ENABLE
STORAGE IN ROW
, Oracle8i only consumes one extra byte of storage in the row to store the one byte of data. If you have a LOB column created with ENABLE
STORAGE IN ROW
and the amount of data to store is larger than will fit in the row (approximately 4,000 bytes) Oracle8i uses a multiple of chunksizes to store it.
When defining LOB
s in a table, you can explicitly indicate the tablespace and storage characteristics for each internal LOB
.
For example:
CREATE TABLE ContainsLOB_tab (n NUMBER, c CLOB) lob (c) STORE AS (CHUNK 4096 PCTVERSION 5 NOCACHE LOGGING STORAGE (MAXEXTENTS 5) );
There are no extra tablespace or storage characteristics for external LOB
s since they are not stored in the database.
If you later wish to modify the LOB
storage parameters, use the MODIFY
LOB
clause of the ALTER
TABLE
statement.
As shown in the previous example, specifying a name for the LOB
data segment makes for a much more intuitive working environment. When querying the LOB
data dictionary views USER_LOBS
, ALL_LOBS
, DBA_LOBS
(see Oracle8i Reference), you see the LOB
data segment that you chose instead of system-generated names.
LOB
storage characteristics that can be specified for a LOB
column or a LOB
attribute include the following:
TABLESPACE
PCTVERSION
CACHE
/NOCACHE/CACHE READS
LOGGING/NOLOGGING
CHUNK
ENABLE
/DISABLE
STORAGE
IN
ROW
STORAGE.
See the "STORAGE clause" in Oracle8i SQL Reference for more information.
For most users, defaults for these storage characteristics will be sufficient. If you want to fine-tune LOB storage, you should consider the following guidelines.
Best performance for LOB
s can be achieved by specifying storage for LOB
s in a tablespace different from the one used for the table that contains the LOB
. If many different LOB
s will be accessed frequently, it may also be useful to specify a separate tablespace for each LOB
column or attribute in order to reduce device contention.
The LOB
index is an internal structure that is strongly associated with LOB
storage. This implies that a user may not drop the LOB
index and rebuild it.
The system determines which tablespace to use for LOB
data and LOB
index depending on the user specification in the LOB
storage clause:
LOB
data, the table's tablespace is used for the LOB
data and index.
LOB
data, both the LOB
data and index use the tablespace that was specified.
If in creating tables in 8.1 you specify a tablespace for the LOB
index for a non-partitioned table, your specification of the tablespace will be ignored and the LOB
index will be co-located with the LOB
data. Partitioned LOB
s do not include the LOB
index syntax.
Specifying a separate tablespace for the LOB
storage segments will allow for a decrease in contention on the table's tablespace.
When a LOB
is modified, a new version of the LOB
page is made in order to support consistent read of prior versions of the LOB
value.
PCTVERSION
is the percentage of all used LOB
data space that can be occupied by old versions of LOB
data pages. As soon as old versions of LOB
data pages start to occupy more than the PCTVERSION
amount of used LOB
space, Oracle tries to reclaim the old versions and reuse them. In other words, PCTVERSION
is the percent of used LOB
data blocks that is available for versioning old LOB
data.
Default: 10 (%) Minimum: 0 (%) Maximum: 100 (%)
In order to decide what value PCTVERSION
should be set to, consider how often LOB
s are updated, and how often you read the updated LOB
s.
Table 7-2, "Recommended PCTVERSION Settings" provides some guidelines for determining a suitable PCTVERSION
value.
Several LOB updates concurrent with heavy reads of LOBs.
set PCTVERSION
= 20%
Setting PCTVERSION
to twice the default allows more free pages to be used for old versions of data pages. Since large queries may require consistent reads of LOB
s, it may be useful to retain old versions of LOB
pages. In this case LOB
storage may grow because Oracle will not reuse free pages aggressively.
LOBs are created and written just once and are primarily read-only afterwards. Updates are infrequent.
set PCTVERSION = 5% or lower
The more infrequent and smaller the LOB
updates are, the less space needs to be reserved for old copies of LOB
data. If existing LOB
s are known to be read-only, you could safely set PCTVERSION
to 0% since there would never be any pages needed for old versions of data.
When creating tables that contain LOBs, use the cache options according to the guidelines in Table 7-3, "When to Use CACHE, NOCACHE, and CACHE READS":
Cache Mode | Read ... | Written To ... |
---|---|---|
|
Frequently |
Frequently |
|
Once or occasionally |
Never |
|
Frequently |
Once or occasionally |
If you have CACHE READS
set for LOBs in 8.1.6 and you downgrade to 8.1.5 or 8.0.x, your CACHE READS
LOBs generate a warning and become CACHE LOGGING
LOBs.
You can explicitly alter the LOBs' storage characteristics later if you do not want your LOBs to be CACHE LOGGING
. For example, if you want the LOBs to be NOCACHE
, use ALTER TABLE to clearly modify them to NOCACHE
.
[NO
] LOGGING
has a similar application with regard to using LOBs as it does for other table operations. In the normal case, if the [NO
]LOGGING
clause is omitted, this means that neither NO
LOGGING
nor LOGGING
is specified and the logging attribute of the table or table partition defaults to the logging attribute of the tablespace in which it resides.
For LOB
s, there is a further alternative depending on how CACHE
is stipulated.
NO
]LOGGING
clause is omitted, LOGGING
is automatically implemented (because you cannot have CACHE
NOLOGGING
).
NO
]LOGGING
clause is omitted, the process defaults in the same way as it does for tables and partitioned tables. That is, the [NO
]LOGGING
value is obtained from the tablespace in which the LOB
value resides.
The following issues should also be kept in mind.
Regardless of whether LOGGING
or NOLOGGING
is set LOB
s will never generate rollback information (undo) for LOB
data pages because old LOB
data is stored in versions. Rollback information that is created for LOB
s tends to be small because it is only for the LOB
index page changes.
NOLOGGING
is intended to be used when a customer does not care about media recovery. Thus, if the disk/tape/storage media fails, you will not be able to recover your changes from the log since the changes were never logged.
An example of when NOLOGGING
is useful is bulk loads or inserts. For instance, when loading data into the LOB
, if you don't care about redo and can just start the load over if it fails, set the LOB
's data segment storage characteristics to NOCACHE
NOLOGGING
. This will give good performance for the initial load of data. Once you have completed loading the data, you can use ALTER
TABLE
to modify the LOB
storage characteristics for the LOB
data segment to be what you really want for normal LOB
operations -- i.e. CACHE
or NOCACHE
LOGGING
.
Set CHUNK
to the number of blocks of LOB
data that will be accessed at one time i.e. the number of blocks that will be read or written via OCILobRead()
, OCILobWrite()
, DBMS_LOB
.READ()
, or DBMS_LOB
.WRITE()
during one access of the LOB
value.
If only one block of LOB
data is accessed at a time, set CHUNK
to the size of one block. For example, if the database block size is 2K, then set CHUNK
to 2K.
If you explicitly specify storage characteristics for the LOB
, make sure that INITIAL
and NEXT
for the LOB
data segment storage are set to a size that is larger than the CHUNK
size. For example, if the database block size is 2K and you specify a CHUNK
of 8K, make sure that INITIAL
and NEXT
are bigger than 8K and preferably considerably bigger (for example, at least 16K).
Put another way: If you specify a value for INITIAL, NEXT
or the LOB CHUNK
size, make sure that:
and
You use the ENABLE
| DISABLE
STORAGE
IN
ROW
clause to indicate whether the LOB
should be stored inline (i.e. in the row) or out of line.
The default is ENABLE
STORAGE
IN
ROW
.
The maximum amount of LOB
data stored in the row is the maximum VARCHAR
size (4000). This includes the control information as well as the LOB
value. If you indicate that the LOB
should be stored in the row, once the LOB
value and control information is larger than 4000, the LOB
value is automatically moved out of the row.
This suggests the following guidelines:
LOB
is small (i.e. < 4000 bytes), then storing the LOB
data out of line will decrease performance. However, storing the LOB
in the row increases the size of the row. This will impact performance if the user is doing a lot of base table processing, such as full table scans, multi-row accesses (range scans) or many UPDATE
/SELECT
to columns other than the LOB
columns.
LOB
data to be < 4000 bytes, i.e. if all LOB
s are big, then the default, ENABLE STORAGE IN ROW, is the best choice for the following reasons:
|
![]() Copyright © 1996-2000, Oracle Corporation. All Rights Reserved. |
|