Index Organized Tables – PCTTHRESHOLD (The Wedding Song) February 8, 2012
Posted by Richard Foote in Block Dumps, Index Internals, Index Organized Tables, IOT, Oracle Indexes, Overflow Segment, PCTTHRESHOLD.7 comments
I’ve recently returned from a great two-week holiday, firstly at the Australian Open Tennis (what a final !!) and then up at the Gold Coast in not quite so sunny Queensland. Time now to get back to my blog 🙂
In my previous IOT examples, we had a very large column called Description which we didn’t really want to store within the Index Organized Table as it would cause the resultant index structure to get very inflated and inefficient. All the rows contained a very large Description value so it never made sense to include the Description column within the IOT.
In the following example, the Description column has values of varying lengths. Some of the values remain very large, however many of the Description values are quite moderate in size and wouldn’t be problematic to store within the IOT. Indeed, it would be quite beneficial as it wouldn’t be necessary to perform additional I/Os to the Overflow segment in cases where the Description was quite small in size and required by the application.
PCTTHRESHOLD gives us more flexibility in what is actually stored within the IOT index structure by storing the non-PK columns up to the INCLUDING clause within the IOT but only if the row length to be stored inside the IOT is below a specified percentage threshold of the block size. So with a PCTTHRESHOLD of (say) 5, the non-PK columns up to the INCLUDING clause will be included within the IOT but only if the resultant row size is less than 5% of the blocksize. If a row size were to be greater than the specified percentage threshold of the block size, then any non-PK columns that would violate this length threshold would not be included within the IOT and stored instead within the Overflow segment.
In the following example, every other row is actually quite small and we would want these rows to have the Description value stored within the IOT. Therefore, we have modified the IOT table definition to include the Description column if the resultant row is less than 5% of the (8K in this case) blocksize:
SQL> CREATE TABLE album_sales_iot(album_id NUMBER, country_id NUMBER, total_sales NUMBER, description VARCHAR2(1000), CONSTRAINT album_sales_iot_pk PRIMARY KEY(album_id, country_id)) ORGANIZATION INDEX INCLUDING description PCTTHRESHOLD 5 OVERFLOW TABLESPACE bowie2; Table created. SQL> BEGIN 2 FOR i in 1..5000 LOOP 3 FOR c in 1..100 LOOP 4 if mod(c,2) = 1 then 5 INSERT INTO album_sales_iot VALUES(i, c, ceil(dbms_random.value(1,5000000)), 'A really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really really long description'); 6 else INSERT INTO album_sales_iot VALUES(i, c, ceil(dbms_random.value(1,5000000)), 'A short description'); 7 end if; 8 END LOOP; 9 END LOOP; 10 COMMIT; 11 END; 12 / PL/SQL procedure successfully completed. SQL> exec dbms_stats.gather_table_stats(ownname=>'BOWIE', tabname=> 'ALBUM_SALES_IOT', cascade=> true, estimate_percent=> null, method_opt=> 'FOR ALL COLUMNS SIZE 1'); PL/SQL procedure successfully completed.
If we look at the size of the resultant IOT:
SQL> ANALYZE INDEX album_sales_iot_pk VALIDATE STRUCTURE; Index analyzed. SQL> SELECT blocks, height, br_blks, lf_blks FROM index_stats; BLOCKS HEIGHT BR_BLKS LF_BLKS ---------- ---------- ---------- ---------- 2176 3 5 2052
The IOT is only of a moderate size, with 5 branch blocks and 2,052 leaf blocks.
If we look at the size of the Overflow segment:
SQL> SELECT object_id FROM user_objects WHERE object_name = 'ALBUM_SALES_IOT'; OBJECT_ID ---------- 74209 SQL> SELECT table_name, iot_name, iot_type, blocks FROM user_tables WHERE table_name = 'SYS_IOT_OVER_74209'; TABLE_NAME IOT_NAME IOT_TYPE BLOCKS ------------------ ---------------- ------------ ---------- SYS_IOT_OVER_74209 ALBUM_SALES_IOT IOT_OVERFLOW 35715
We see that the vast majority of the storage is still allocated to the Overflow segment, at 35,715 blocks in size.
If look at a partial block dump of an IOT leaf block:
Leaf block dump
===============
header address 461972060=0x1b89225c
kdxcolev 0
KDXCOLEV Flags = – – –
kdxcolok 1
kdxcoopc 0x97: opcode=7: iot flags=I– is converted=Y
kdxconco 2
kdxcosdc 1
kdxconro 251
kdxcofbo 538=0x21a
kdxcofeo 561=0x231
kdxcoavs 23
kdxlespl 0
kdxlende 0
kdxlenxt 21053971=0x1414213
kdxleprv 0=0x0
kdxledsz 0
kdxlebksz 8036
row#0[561] flag: K—S-, lock: 2, len=23
col 0; len 2; (2): c1 02
col 1; len 2; (2): c1 02
tl: 15 fb: –H-F— lb: 0x0 cc: 1
nrid: 0x01811901.0
col 0: [ 5] c4 04 57 1d 44
row#1[584] flag: K—S-, lock: 2, len=36
col 0; len 2; (2): c1 02
col 1; len 2; (2): c1 03
tl: 28 fb: –H-FL– lb: 0x0 cc: 2
col 0: [ 4] c3 1d 2a 2e
col 1: [19] 41 20 73 68 6f 72 74 20 64 65 73 63 72 69 70 74 69 6f 6e
row#2[620] flag: K—S-, lock: 2, len=23
col 0; len 2; (2): c1 02
col 1; len 2; (2): c1 04
tl: 15 fb: –H-F— lb: 0x0 cc: 1
nrid: 0x01811901.1
col 0: [ 5] c4 04 22 2d 07
row#3[643] flag: K—S-, lock: 2, len=37
col 0; len 2; (2): c1 02
col 1; len 2; (2): c1 05
tl: 29 fb: –H-FL– lb: 0x0 cc: 2
col 0: [ 5] c4 04 36 17 52
col 1: [19] 41 20 73 68 6f 72 74 20 64 65 73 63 72 69 70 74 69 6f 6e
We notice the leaf block contains 251 row entries. Half the rows with a Description of 19 bytes have the Description value stored within the IOT leaf block, while the other half of rows with the larger Description values contain a nrid that refers to the corresponding Description within the Overflow segment.
If we analyze the table:
SQL> ANALYZE TABLE album_sales_iot COMPUTE STATISTICS; Table analyzed. SQL> SELECT table_name, num_rows, chain_cnt, blocks from user_tables WHERE table_name = 'ALBUM_SALES_IOT'; TABLE_NAME NUM_ROWS CHAIN_CNT BLOCKS ------------------------------ ---------- ---------- ---------- ALBUM_SALES_IOT 500000 250000
We notice that only half the rows are now “chained rows”.
If we run a query that only references the rows with a small Description that are stored within the IOT structure:
SQL> SELECT * FROM album_sales_iot WHERE album_id = 42 and mod(country_id,2)=0; 50 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1834499174 --------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 510 | 5 (0)| 00:00:01 | |* 1 | INDEX RANGE SCAN| ALBUM_SALES_IOT_PK | 1 | 510 | 3 (0)| 00:00:01 | --------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("ALBUM_ID"=42) filter(MOD("COUNTRY_ID",2)=0) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 7 consistent gets 0 physical reads 0 redo size 2211 bytes sent via SQL*Net to client 557 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 50 rows processed
The query at 7 consistent gets is relatively efficient as all the required data can be found within the IOT.
If however we run a query that references the larger Description rows:
SQL> SELECT * FROM album_sales_iot WHERE album_id = 42 and mod(country_id,2)=1; 50 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1834499174 --------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 510 | 5 (0)| 00:00:01 | |* 1 | INDEX RANGE SCAN| ALBUM_SALES_IOT_PK | 1 | 510 | 3 (0)| 00:00:01 | --------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("ALBUM_ID"=42) filter(MOD("COUNTRY_ID",2)=1) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 18 consistent gets 0 physical reads 0 redo size 4147 bytes sent via SQL*Net to client 557 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 50 rows processed
We see that it’s less efficient at 18 consistent gets as it needs to obviously access a larger volume of data and requires additional I/Os to access the corresponding Overflow segment.
So, with a combination of the INCLUDING and PCTTHRESHOLD clauses, one can control what data is and is not included within the IOT index structure.