Wednesday, August 15, 2007

... LOBs

Initial problem was: "LOB segment is wasting disk space, need to shrink it". So how can one investigate if there is some "wasted" space inside a LOB and how to reclaim it?

Note:386341.1 metalink article that quite helped me on this

To get the LOB segment size, use the dba_lobs and dba_segment views.
First find out the name of the LOB segment:
select segment_name,table_name,column_name,tablespace_name from dba_lobs where table_name = '[table_name]'
Then the size on disk:
select blocks, bytes from dba_segments where segment_name = '[lob_system_segment_name]';
To get to know how much data is stored in this LOB:
select sum(dbms_lob.getlength([lob_column])) from [table];
If the last number if much smaller than previous, then apparently there is some space wasted and could be reclaimed. If you have been deleting rows from the LOB's parent table, then LOB segment blocks (or chunks) are left in "deleted" state. Theoretically this space will be reused when subsequent "insert" will come [upd: tested and it really does work like that]. But if you need to shrink the LOB and reclaim some space for other segments, then you have the following opportunities.

First, you will have to rebuild the freepools, using the following command:
alter table [table name] modify lob([lob column name])
(freepools [number of free pools]);
In RAC configuration, the number of freepools = number of RAC instances, otherwise it is 1 (or it can be looked up in dba_lobs view. In case null is what you see there, then 1 is your choice).

:(((( Although this did not work with my LOB...

There is also a special keyword for this in ALTER TABLE syntax in 10.2:
alter table [table_name] modify lob [lob_column] (freepools rebuild);
After this you should see the free blocks either using the DBMS_SPACE.SPACE_USAGE (in case of an ASSM tablespace) or with DBMS_SPACE.FREE_BLOCKS in case of a manual segment management. You can also use the very convenient and useful Tom Kyte's show_space() procedure. Which actually uses the same DBMS_SPACE package, but it also detects automatically what kind of segment management do you have set and acts appropriately.

Now to actually reclaim the space from a LOB into a tablespace, starting 10.2 you have the wonderful shrink space command:
alter table [table name] modify lob([lob column name]) (shrink space [cascade]);
If lower than 10.2 then the only option is to rebuild the LOB:
alter table [table name] move lob [lob column name]) store as (tablespace [tablespace name]);
This is done online, so no need to bring anything off-line.

Now why this did not work with my LOB, even though the difference between "real" data size and the size of the segment itself was more than 2 times.
The truth was, that there were actually no bytes wasted. It was just normal, since the field was of NCLOB type and Oracle stores NCLOBs in UCS2 compatible internal encoding, which has fixed-width of 2 bytes per character. Now what the dbms_lob.getlength() function was returning, was the number of characters. So this is were I was getting this difference and this is why you have to multiply the result by 2, if you are using NCLOBs.
But what has got me totally distracted on this, was that when I performed a test with CLOBs, which had 2K chunks, inserting 2K into each, I was also getting a double sized LOB segments. The reason was revealed by Jonathan Lewis himself on comp.databases.oracle.server
Here's what he wrote:
[A 2KB block allows 1,988 bytes of space for LOB
storage - the remaining 60 bytes is the standard block
overhead plus a few bytes of data specific to the LOB,
such as the object number, LOB ID, and SCN. So if
your character set is single byte then you can get 1,988
characters per block.]
It is also must be kept in mind that LOB segment doesn't use PCTFREE PCTUSED parameters, it always allocates a full chunk. So (roughly) if you have 8K chunks and you store 2K of data in each row, then you will have 6K of disk space wasted per row.

Also here could be found a very useful document by Tanel Põder, which explains a lot about LOB internals.

Some sqls needed to perform test with LOBs.

To create a table with a clob named 't1_lob', with 2K chunksize (need to have a 2K buffer cache and a 2K block tablespace called 'smallblock'). Make the LOB to be out-of-line and leave no space for concurrency:
create table t1 (i int, b clob)
lob (b) store as t1_lob (
chunk 2K
disable storage in row
tablespace smallblock
pctversion 0);
To fill the table:
begin
for i in 1..1000 loop
insert into t1 values (mod(i,5), rpad('*',1988,'*'));
end loop;
end;

To load CLOB from a file:
declare
nc clob;
begin
select b into nc from t1 where i = 1 for update;
loadCLOB1_proc(nc,'ROOT_DIR','test.txt');
update t1 set b = nc where i = 1;
end;
The loadCLOB1_proc source

Other LOB related examples could be found in $ORACLE_HOME/rdbms/demo/lobs/plsql

Wednesday, August 1, 2007

Parallel query execution

helpful article: metalink docid: Note:237287.1
oracle docs

first check if the parallel query option is enabled:
At SQLPLUS
==========
- SQL>select * from v$option;

PARAMETER VALUE
-------------------------
Parallel execution TRUE

General stats:
 select *  from  V$PX_PROCESS_SYSSTAT;
your own:
 select * from v$pq_sesstat;
To make the query use parallelism, use one of three options:
  • set the degree of parallelism for the table: ALTER TABLE t PARALLEL 2;
  • use ALTER SESSION FORCE PARALLEL QUERY
  • give a hint within the sql itself: SELECT /*+ PARALLEL(t,2) */ * from t;