Intra Block Chaining ! Impact on Logical Reads

I presented this during Sangam 12 (User Group Conference) and many participants wanted me to post a Blog on this. It is important to know the impact of Intra Block Chaining, which occurs, if the number of columns in a table exceed 255. If a table has more than 255 columns, the row pieces are stored in multiple row pieces of 255 each. Now, whether it stores columns 1 to 255 in one Row Piece and 256 to the remaining columns in next row piece, is an interesting fact that everyone wants to know. Through this blog, I will try to demonstrate and answer following facts :

  1. If a table consists of 300 Columns, which all columns will constitute the 2 row pieces ? i.e. Row Piece 1 : 1-255 Columns and Row Piece 2 : 256-300 Columns, or will it be something else ?
  2. What will be the performance impact of Intra Block Chaining ?

The reason, I picked this as one of the topic that the Developers and the DBA’s should know, is based on a Real Life Example. One of my customer complained of a Severe Performance issues, post applying an Application Patch. This patch was to introduce certain new functionality for their end-users. Further, this functionality change modified many of the critical tables used by the application. This change was : introduction of new columns. Few tables, which had less than 255 columns, were altered and new columns were added, which grew these numbers to more than 255. This was enough to cause the performance issues, which went unnoticed, during a test run, which was with done with less user load. On production, the user load was way high, and therefore, any increase in the I/O was capable enough to increase the CPU Utilization.

Let us start with a Demonstration, which is an easiest way to understand the facts. We will first create a table, with required number of columns. First, a table with 300 Columns and then I will insert single row into this table. Following two pl/sql blocks uses a Dynamic SQL to accomplish the task.

variable b1 number;
exec :b1:=&number_of_columns; -- Pass the Number of Columns to be required in a Table 

-- Dynamically Create Intra_Block table with required number of rows. This block constructs the CREATE TABLE Statement.

declare
l_statement	long:='create table intra_block (';
begin
  for i in 1..:b1
  loop
    if i<:b1 then
    l_statement:=l_statement||' A'||i||' number(3),';
    else
    l_statement:=l_statement||' A'||i||' number(3))';
    end if;
  end loop;
  execute immediate l_statement;
end;
/

-- Insert Single Row into the table. This block constructs the INSERT Statement.

declare
l_statement	long:='insert into intra_block(';
begin
   for i in 1..:b1
   loop
     if i<:b1 then
     l_statement:=l_statement||'A'||i||',';
     else
     l_statement:=l_statement||'A'||i||') values(';
     end if;
   end loop;
   for i in 1..:b1
   loop
     if i<:b1 then
     l_statement:=l_statement||i||',';
     else
     l_statement:=l_statement||i||')';
     end if;
   end loop;
   execute immediate l_statement;   
   commit;
end;
/
-- Gather Statistics
exec dbms_stats.gather_table_stats(user,'INTRA_BLOCK');

select table_name, blocks, num_rows from dba_tables where table_name='INTRA_BLOCK';

OWNER           PAR   NUM_ROWS     BLOCKS
--------------- --- ---------- ----------
VIVEK           NO           1          5

I created this table with 300 columns and inserted one row. DBA_Tables shows 5 blocks in the table. Next, the following queries show that the entire 300 columns fit into 1 block, block#182 in my case.

select dbms_rowid.rowid_block_number(rowid) bno, count(*) from intra_block group by dbms_rowid.rowid_block_number(rowid);

       BNO   COUNT(*)
---------- ----------
       182          1

Next, we shall execute a Query against the first column, which is A1, and then on the last column, which is A300. We will compare the I/O’s done by each of these queries.

set autot on stat

select a1 from intra_block;

        A1
----------
         1

Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
          7  consistent gets <--- 7 Logical I/O's

select A300 from intra_block;

      A300
----------
       300

Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
          8  consistent gets <-- One Additional Logical I/O's

Query on the last column (for a table with more than 255 columns) incurred one Additional Logical I/O. Let us now check, row piece structure. We now know that with 300 columns, the Rows will be inserted into 2 Row Pieces. One Row Piece will incur less I/O as compared to the another Row Piece. I want to check the columns in Row Piece 1 and Columns in Row Piece 2, which will help us know, which column onwards the query will start incurring additional I/O. Following pl/sql executes a query on each of the columns and we shall check for the I/O’s (from buffer_gets column of v$sqlarea).

 declare
l_statement varchar2(132);
l_value number;
begin
  for i in 1..:b1
  loop
    l_statement:='select /*+ intra_'||lpad(i,3,0)||' */ A'||i||' from intra_block';
    execute immediate l_statement into l_value;
  end loop;
end;
/

select sql_id, sql_text, buffer_gets, executions, rows_processed
from v$sqlarea where sql_text like 'select /*+ intra%'
order by to_number(substr(sql_text,instr(sql_text,'i',1)+6,3));

SQL_ID        SQL_TEXT                                           BUFFER_GETS EXECUTIONS ROWS_PROCESSED
------------- -------------------------------------------------- ----------- ---------- --------------
47u9afvh40vqf select /*+ intra_001 */ A1 from intra_block                  7          1              1
cvjvxgnfz7h78 select /*+ intra_002 */ A2 from intra_block                  7          1              1
cbdajswujwnyf select /*+ intra_003 */ A3 from intra_block                  7          1              1
8g18r5syanmbx select /*+ intra_004 */ A4 from intra_block                  7          1              1
d5kyqtgd2d4q3 select /*+ intra_005 */ A5 from intra_block                  7          1              1
c0yvymb9p7gj0 select /*+ intra_006 */ A6 from intra_block                  7          1              1
.....
..... (some entries trimmed)
.....
f1rrwb22u89gf select /*+ intra_029 */ A29 from intra_block                 7          1              1
1556fp9466r4x select /*+ intra_030 */ A30 from intra_block                 7          1              1
3sk2zpnyqanmc select /*+ intra_031 */ A31 from intra_block                 7          1              1
asp7vk16b07sb select /*+ intra_032 */ A32 from intra_block                 7          1              1
9ts2g9w5dra0q select /*+ intra_033 */ A33 from intra_block                 7          1              1
c9dnc235v6w00 select /*+ intra_034 */ A34 from intra_block                 7          1              1
a532dxfj0d0w6 select /*+ intra_035 */ A35 from intra_block                 7          1              1
1p2yzsxax20qm select /*+ intra_036 */ A36 from intra_block                 7          1              1
6zb16tkbyrbhm select /*+ intra_037 */ A37 from intra_block                 7          1              1
38zqdzgvvg70w select /*+ intra_038 */ A38 from intra_block                 7          1              1
51f39r5tnw73d select /*+ intra_039 */ A39 from intra_block                 7          1              1
f1fywzj4avnz0 select /*+ intra_040 */ A40 from intra_block                 7          1              1
46015j3s4trsk select /*+ intra_041 */ A41 from intra_block                 7          1              1
1sdrag4sxbcjh select /*+ intra_042 */ A42 from intra_block                 7          1              1
a0t2nrpb8r83s select /*+ intra_043 */ A43 from intra_block                 7          1              1
aj2w0gvj5zy1g select /*+ intra_044 */ A44 from intra_block                 7          1              1
6nk7x7430k9uk select /*+ intra_045 */ A45 from intra_block                 7          1              1
ahdr7bqsm18x8 select /*+ intra_046 */ A46 from intra_block                 8          1              1
1vsus8qg2rsft select /*+ intra_047 */ A47 from intra_block                 8          1              1
86njp3z8adan3 select /*+ intra_048 */ A48 from intra_block                 8          1              1
6v6u6hp71vtwb select /*+ intra_049 */ A49 from intra_block                 8          1              1
7a9a7gbyhrvkr select /*+ intra_050 */ A50 from intra_block                 8          1              1
8wp83m0fn4kgw select /*+ intra_051 */ A51 from intra_block                 8          1              1
7q464wb184tpu select /*+ intra_052 */ A52 from intra_block                 8          1              1
.....
..... (some entries trimmed)
.....
9dmv986638rk4 select /*+ intra_235 */ A235 from intra_block                8          1              1
d2ks041mqfv1b select /*+ intra_236 */ A236 from intra_block                8          1              1
b0muufu2qqs7y select /*+ intra_237 */ A237 from intra_block                8          1              1
fbd5x0z45udvr select /*+ intra_238 */ A238 from intra_block                8          1              1
c31yuufwr2wzc select /*+ intra_239 */ A239 from intra_block                8          1              1
2aczq7gsf0680 select /*+ intra_240 */ A240 from intra_block                8          1              1
7us824yhm9c4s select /*+ intra_241 */ A241 from intra_block                8          1              1
c26kyzhmm1ad1 select /*+ intra_242 */ A242 from intra_block                8          1              1
dqrp4n7a5uzjp select /*+ intra_243 */ A243 from intra_block                8          1              1
4wzw76dh7sa6h select /*+ intra_244 */ A244 from intra_block                8          1              1
b4qwud4k9j9qg select /*+ intra_245 */ A245 from intra_block                8          1              1
6cyzxr6c7t4km select /*+ intra_246 */ A246 from intra_block                8          1              1
7u8krqjy6aq0k select /*+ intra_247 */ A247 from intra_block                8          1              1
8sxmn5ukxzqad select /*+ intra_248 */ A248 from intra_block                8          1              1
a66frsvy8q8vq select /*+ intra_249 */ A249 from intra_block                8          1              1
9htnkqmfchypc select /*+ intra_250 */ A250 from intra_block                8          1              1
058f3hvkf2y6m select /*+ intra_251 */ A251 from intra_block                8          1              1
1m9wfv39zmn6v select /*+ intra_252 */ A252 from intra_block                8          1              1
23mmdngutgbc6 select /*+ intra_253 */ A253 from intra_block                8          1              1
bnxt1ujafku6s select /*+ intra_254 */ A254 from intra_block                8          1              1
a4gv26ujgjhjv select /*+ intra_255 */ A255 from intra_block                8          1              1
draytdg79hc5c select /*+ intra_256 */ A256 from intra_block                8          1              1
4gr6ntv7zx764 select /*+ intra_257 */ A257 from intra_block                8          1              1
csfz96fkfz2vj select /*+ intra_258 */ A258 from intra_block                8          1              1
1v4sjc8740kdc select /*+ intra_259 */ A259 from intra_block                8          1              1
b38nmwf9bnfv0 select /*+ intra_260 */ A260 from intra_block                8          1              1
b52d8sd512zpr select /*+ intra_261 */ A261 from intra_block                8          1              1
6s8963hfnpt9b select /*+ intra_262 */ A262 from intra_block                8          1              1
5h19qru6dsudz select /*+ intra_263 */ A263 from intra_block                8          1              1
fpnvs4ry55qqg select /*+ intra_264 */ A264 from intra_block                8          1              1
2us1f52hmqz4j select /*+ intra_265 */ A265 from intra_block                8          1              1
g7xbq7nvg119d select /*+ intra_266 */ A266 from intra_block                8          1              1
78z5hjw7nam1n select /*+ intra_267 */ A267 from intra_block                8          1              1
82w5nq265jyfp select /*+ intra_268 */ A268 from intra_block                8          1              1
fh0hnjydm2unq select /*+ intra_269 */ A269 from intra_block                8          1              1
39tqqf1p9jm1s select /*+ intra_270 */ A270 from intra_block                8          1              1
cn4np8vkgk4mc select /*+ intra_271 */ A271 from intra_block                8          1              1
.....
..... (some entries trimmed)
.....
19m0kx9w80afs select /*+ intra_296 */ A296 from intra_block                8          1              1
1q9kg224txpqu select /*+ intra_297 */ A297 from intra_block                8          1              1
36dya8xmc8a0a select /*+ intra_298 */ A298 from intra_block                8          1              1
abn6s5jr2bac3 select /*+ intra_299 */ A299 from intra_block                8          1              1
grnbn11qw3xjk select /*+ intra_300 */ A300 from intra_block                8          1              1

300 rows selected.

From the output above, it can be seen that for 300 Columns, the I/O’s increased from 46th Column (A46), which is 300-255=45. This means, columns A300-A46 (255 columns) are together stored in One Row Piece, whereas, A45-A1 are stored in another Row Piece. This information was a bit interesting. Initially I thought, any query that queries columns A256 and above, would incur additional I/O, but the rows are stored backward and 255 limit also starts from back i.e.last column onwards.

For curiosity, I ran the entire test again for 256 columns. The table was dropped and recreated to have A1..A256 columns. With this, I could see that the I/O’s increased by 1 from column A2 onwards (256-255=1). Again, Columns A2..A256 were stored in one Row Piece and A1 in another. This also means, if you have a table with 255 columns, you add one column and would immediately see I/O’s go up by 1 for any column starting 2nd Column.

You may run this for any number of columns, and should see the same results. The third test I did was on a 600 Column Table. The I/O’s were as under :

Columns A1..A90 --- 7 I/O's
Columns A91..A345 --- 8 I/O's
Columns A346 onwards --- 9 I/O's 

600-255=345
345-255=90

This test proves that the Table Design requires careful planning. There is hardly any reason, why a Table needs to be created with more than 255 columns. However, I have seen many applications that create tables with more number of columns. This blog should be an eye opener for them. Any additional (unwanted) I/O’s that are saved will have dramatic impact on Application performance. This will improve the Scalability of the Application.

About these ads

About Vivek Sharma
I am an Oracle Professional from Mumbai (India). I blog on the issues that I feel is Interesting for my readers. These are all my real life examples, which I hope, you would find interesting. Comments are always a welcome.

4 Responses to Intra Block Chaining ! Impact on Logical Reads

  1. Mohammed says:

    Good observation!!

    Thanks for sharing…

    Keep going..

    Mohammed.

  2. Palwinder says:

    Thank you Vivek for yet another informative blog. Wanted to add :- in case the table contains more than 255 columns and not all the columns are selective or contain nulls, the table can be rebuilt by keeping the more selective columns in the list of first 255 and remaining least selective/null columns from 256 onwards. This way if we cant tune the application/denormalize the table… we can atleast control the I/Os. Please share your view on this.

    • Vivek says:

      Palwinder, the strategy the Application or Database Administrator follow depends on 2 Objective. Objective 1 – Saving Storage Space, for which, they keep the NULLABLE columns at the end, Object 2 – Performance, where the most selective columns are at the beginning of the table structure. In my blog, I demonstrated the Impact of Intra Block Chaining and this was due to a Full Table Scan. I need to check the impact of this on Index Scan Queries.

      Hope this clarifies.

      Regards
      Vivek

  3. madasameee says:

    Hi Vivek,

    Thanks a lot for the info. Its so valuable and very interesting. But i have a doubt.

    Say i have a billion rows in a table contains around 257 columns. and the first three are the composite keys that forms the primary keys.

    So in this case, it will worse the performance because of the i/o . isnt it?

    Lets discuss here about this :)

    Thanks again for the info.

    Madasamy

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Follow

Get every new post delivered to your Inbox.

Join 125 other followers