Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Hariharan.

Asked: June 12, 2019 - 1:56 pm UTC

Last updated: June 17, 2019 - 9:09 am UTC

Version: 11.2.0.4

Viewed 1000+ times

You Asked

Hi,

Customer is having a large partitioned table which will before too long will exceed 255 columns. A number of references says that row will be chained, either within the block or over multiple blocks after we exceed 255 columns.

There are some columns that have never been used, and some that will no longer be used. We will set these columns as unused, and the table is too large to drop the columns - downtime can't be more than 1hr.

1. Do columns marked as unused count against the 255 limit?
2. If the answer to question 1 is yes, is that still true for new rows in new partitions?
3. Provided the new rows don't exceed the block size will the only be chained within a block?
4. Is the most likely performance issues if existing rows get columns updated that added after the 255th column?

There is a concern about performance as someone here has experienced performance problems with more the 255 columns in the past.

In this case the new columns are likely to be populated for on new rows, and old partitions are regularly dropped, with new partitions added. How concerned should be be about a degradation in performance?



Thanks,

and Chris said...

1. Yes.

/* You need to create this if it doesn't exist!
create table CHAINED_ROWS (
  owner_name         varchar2(30),
  table_name         varchar2(30),
  cluster_name       varchar2(30),
  partition_name     varchar2(30),
  subpartition_name  varchar2(30),
  head_rowid         rowid,    
  analyze_timestamp  date
);
*/

truncate table CHAINED_ROWS;
create table t (
  c1 int, c2 int, c3 int, c4 int, c5 int, c6 int, c7 int, c8 int, c9 int, c10 int, c11 int, c12 int, c13 int, c14 int, c15 int, c16 int, c17 int, c18 int, c19 int, c20 int, c21 int, c22 int, c23 int, c24 int, c25 int, c26 int, c27 int, c28 int, c29 int, c30 int, c31 int, c32 int, c33 int, c34 int, c35 int, c36 int, c37 int, c38 int, c39 int, c40 int, c41 int, c42 int, c43 int, c44 int, c45 int, c46 int, c47 int, c48 int, c49 int, c50 int, c51 int, c52 int, c53 int, c54 int, c55 int, c56 int, c57 int, c58 int, c59 int, c60 int, c61 int, c62 int, c63 int, c64 int, c65 int, c66 int, c67 int, c68 int, c69 int, c70 int, c71 int, c72 int, c73 int, c74 int, c75 int, c76 int, c77 int, c78 int, c79 int, c80 int, c81 int, c82 int, c83 int, c84 int, c85 int, c86 int, c87 int, c88 int, c89 int, c90 int, c91 int, c92 int, c93 int, c94 int, c95 int, c96 int, c97 int, c98 int, c99 int, c100 int, c101 int, c102 int, c103 int, c104 int, c105 int, c106 int, c107 int, c108 int, c109 int, c110 int, c111 int, c112 int, c113 int, c114 int, c115 int, c116 int, c117 int, c118 int, c119 int, c120 int, c121 int, c122 int, c123 int, c124 int, c125 int, c126 int, c127 int, c128 int, c129 int, c130 int, c131 int, c132 int, c133 int, c134 int, c135 int, c136 int, c137 int, c138 int, c139 int, c140 int, c141 int, c142 int, c143 int, c144 int, c145 int, c146 int, c147 int, c148 int, c149 int, c150 int, c151 int, c152 int, c153 int, c154 int, c155 int, c156 int, c157 int, c158 int, c159 int, c160 int, c161 int, c162 int, c163 int, c164 int, c165 int, c166 int, c167 int, c168 int, c169 int, c170 int, c171 int, c172 int, c173 int, c174 int, c175 int, c176 int, c177 int, c178 int, c179 int, c180 int, c181 int, c182 int, c183 int, c184 int, c185 int, c186 int, c187 int, c188 int, c189 int, c190 int, c191 int, c192 int, c193 int, c194 int, c195 int, c196 int, c197 int, c198 int, c199 int, c200 int, c201 int, c202 int, c203 int, c204 int, c205 int, c206 int, c207 int, c208 int, c209 int, c210 int, c211 
int, c212 int, c213 int, c214 int, c215 int, c216 int, c217 int, c218 int, c219 int, c220 int, c221 int, c222 int, c223 int, c224 int, c225 int, c226 int, c227 int, c228 int, c229 int, c230 int, c231 int, c232 int, c233 int, c234 int, c235 int, c236 int, c237 int, c238 int, c239 int, c240 int, c241 int, c242 int, c243 int, c244 int, c245 int, c246 int, c247 int, c248 int, c249 int, c250 int, c251 int, c252 int, c253 int, c254 int, c255 int
);

insert into t values (
  1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209, 210, 211, 212, 213, 214, 215, 216, 217, 218, 219, 220, 221, 222, 223, 224, 225, 226, 227, 228, 229, 230, 231, 232, 233, 234, 235, 236, 237, 238, 239, 240, 241, 242, 243, 244, 245, 246, 247, 248, 249, 250, 251, 252, 253, 254, 255
);

commit;
alter table t 
  set unused column c255;
  
analyze table t list chained rows;

select table_name, head_rowid from chained_rows;

no rows selected

alter table t add ( c256 int );
update t
set    c256 = 256;
commit;

analyze table t list chained rows;

select table_name, head_rowid from chained_rows;

TABLE_NAME   HEAD_ROWID           
T            AAAUL4AAEAAAAR4AAA    


Note: demo is from 11.2. As discussed below, later versions get better at chaining within the block. So you may not see this effect (unless the block is already "full").

2. Yes

3. It depends...

Both pieces need to fit in the block. And there be sufficient space to do this.

And it depends which version you're on!

The following inserts a row with 257 columns. This must chain because it has > 255 columns. But the analyze reports no chaining?! => the chaining happens within the block:

truncate table chained_rows;
drop table t cascade constraints purge;
create table t (
  c1 int primary key, c2 int, c3 int, c4 int, c5 int, c6 int, c7 int, c8 int, c9 int, c10 int, c11 int, c12 int, c13 int, c14 int, c15 int, c16 int, c17 int, c18 int, c19 int, c20 int, c21 int, c22 int, c23 int, c24 int, c25 int, c26 int, c27 int, c28 int, c29 int, c30 int, c31 int, c32 int, c33 int, c34 int, c35 int, c36 int, c37 int, c38 int, c39 int, c40 int, c41 int, c42 int, c43 int, c44 int, c45 int, c46 int, c47 int, c48 int, c49 int, c50 int, c51 int, c52 int, c53 int, c54 int, c55 int, c56 int, c57 int, c58 int, c59 int, c60 int, c61 int, c62 int, c63 int, c64 int, c65 int, c66 int, c67 int, c68 int, c69 int, c70 int, c71 int, c72 int, c73 int, c74 int, c75 int, c76 int, c77 int, c78 int, c79 int, c80 int, c81 int, c82 int, c83 int, c84 int, c85 int, c86 int, c87 int, c88 int, c89 int, c90 int, c91 int, c92 int, c93 int, c94 int, c95 int, c96 int, c97 int, c98 int, c99 int, c100 int, c101 int, c102 int, c103 int, c104 int, c105 int, c106 int, c107 int, c108 int, c109 int, c110 int, c111 int, c112 int, c113 int, c114 int, c115 int, c116 int, c117 int, c118 int, c119 int, c120 int, c121 int, c122 int, c123 int, c124 int, c125 int, c126 int, c127 int, c128 int, c129 int, c130 int, c131 int, c132 int, c133 int, c134 int, c135 int, c136 int, c137 int, c138 int, c139 int, c140 int, c141 int, c142 int, c143 int, c144 int, c145 int, c146 int, c147 int, c148 int, c149 int, c150 int, c151 int, c152 int, c153 int, c154 int, c155 int, c156 int, c157 int, c158 int, c159 int, c160 int, c161 int, c162 int, c163 int, c164 int, c165 int, c166 int, c167 int, c168 int, c169 int, c170 int, c171 int, c172 int, c173 int, c174 int, c175 int, c176 int, c177 int, c178 int, c179 int, c180 int, c181 int, c182 int, c183 int, c184 int, c185 int, c186 int, c187 int, c188 int, c189 int, c190 int, c191 int, c192 int, c193 int, c194 int, c195 int, c196 int, c197 int, c198 int, c199 int, c200 int, c201 int, c202 int, c203 int, c204 int, c205 int, c206 int, c207 int, c208 int, c209 int, 
c210 int, c211 int, c212 int, c213 int, c214 int, c215 int, c216 int, c217 int, c218 int, c219 int, c220 int, c221 int, c222 int, c223 int, c224 int, c225 int, c226 int, c227 int, c228 int, c229 int, c230 int, c231 int, c232 int, c233 int, c234 int, c235 int, c236 int, c237 int, c238 int, c239 int, c240 int, c241 int, c242 int, c243 int, c244 int, c245 int, c246 int, c247 int, c248 int, c249 int, c250 int, c251 int, c252 int, c253 int, c254 int, c255 int, c256 int, c257 int
);

insert into t values (
  1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209, 210, 211, 212, 213, 214, 215, 216, 217, 218, 219, 220, 221, 222, 223, 224, 225, 226, 227, 228, 229, 230, 231, 232, 233, 234, 235, 236, 237, 238, 239, 240, 241, 242, 243, 244, 245, 246, 247, 248, 249, 250, 251, 252, 253, 254, 255, 256, 257
);

commit;

analyze table t list chained rows;

PRO Everything fits in the block on insert
select table_name, head_rowid from chained_rows;

no rows selected


But insert a value for just the first column, then update the last and this is chained:

insert into t ( c1 ) values ( 2 );

update t
set    c257 = 257
where  c1 = 2;

commit;

analyze table t list chained rows;

select table_name, head_rowid from chained_rows;

TABLE_NAME   HEAD_ROWID           
T            AAAUL8AAEAAAAR4AAC 


Again, demo is from 11.2. On 18c the analyze reports no chaining => it's happened within the block. I've not checked 12c behaviour.

4. It depends...

A key thing to note is that chaining happens on the last 255 columns. So if you have a 255 column table, add a 256th, columns 2-256 will be chained!

You can verify this by looking for the "table fetch continued row" statistic.

The following creates a 257 column table. Populates just the first column. Then updates the last:

create table t (
  c1 int primary key, c2 int, c3 int, c4 int, c5 int, c6 int, c7 int, c8 int, c9 int, c10 int, c11 int, c12 int, c13 int, c14 int, c15 int, c16 int, c17 int, c18 int, c19 int, c20 int, c21 int, c22 int, c23 int, c24 int, c25 int, c26 int, c27 int, c28 int, c29 int, c30 int, c31 int, c32 int, c33 int, c34 int, c35 int, c36 int, c37 int, c38 int, c39 int, c40 int, c41 int, c42 int, c43 int, c44 int, c45 int, c46 int, c47 int, c48 int, c49 int, c50 int, c51 int, c52 int, c53 int, c54 int, c55 int, c56 int, c57 int, c58 int, c59 int, c60 int, c61 int, c62 int, c63 int, c64 int, c65 int, c66 int, c67 int, c68 int, c69 int, c70 int, c71 int, c72 int, c73 int, c74 int, c75 int, c76 int, c77 int, c78 int, c79 int, c80 int, c81 int, c82 int, c83 int, c84 int, c85 int, c86 int, c87 int, c88 int, c89 int, c90 int, c91 int, c92 int, c93 int, c94 int, c95 int, c96 int, c97 int, c98 int, c99 int, c100 int, c101 int, c102 int, c103 int, c104 int, c105 int, c106 int, c107 int, c108 int, c109 int, c110 int, c111 int, c112 int, c113 int, c114 int, c115 int, c116 int, c117 int, c118 int, c119 int, c120 int, c121 int, c122 int, c123 int, c124 int, c125 int, c126 int, c127 int, c128 int, c129 int, c130 int, c131 int, c132 int, c133 int, c134 int, c135 int, c136 int, c137 int, c138 int, c139 int, c140 int, c141 int, c142 int, c143 int, c144 int, c145 int, c146 int, c147 int, c148 int, c149 int, c150 int, c151 int, c152 int, c153 int, c154 int, c155 int, c156 int, c157 int, c158 int, c159 int, c160 int, c161 int, c162 int, c163 int, c164 int, c165 int, c166 int, c167 int, c168 int, c169 int, c170 int, c171 int, c172 int, c173 int, c174 int, c175 int, c176 int, c177 int, c178 int, c179 int, c180 int, c181 int, c182 int, c183 int, c184 int, c185 int, c186 int, c187 int, c188 int, c189 int, c190 int, c191 int, c192 int, c193 int, c194 int, c195 int, c196 int, c197 int, c198 int, c199 int, c200 int, c201 int, c202 int, c203 int, c204 int, c205 int, c206 int, c207 int, c208 int, c209 int, 
c210 int, c211 int, c212 int, c213 int, c214 int, c215 int, c216 int, c217 int, c218 int, c219 int, c220 int, c221 int, c222 int, c223 int, c224 int, c225 int, c226 int, c227 int, c228 int, c229 int, c230 int, c231 int, c232 int, c233 int, c234 int, c235 int, c236 int, c237 int, c238 int, c239 int, c240 int, c241 int, c242 int, c243 int, c244 int, c245 int, c246 int, c247 int, c248 int, c249 int, c250 int, c251 int, c252 int, c253 int, c254 int, c255 int, c256 int, c257 int
);

insert into t ( c1 ) values ( 1 );

update t
set    c257 = 257
where  c1 = 1;

commit;

select value 
from   v$mystat m
join   v$statname n
on     m.statistic# = n.statistic#
where  n.name = 'table fetch continued row';

VALUE   
       0 

select c2
from   t
where  c1 = 1;

C2       
   <null> 

select value 
from   v$mystat m
join   v$statname n
on     m.statistic# = n.statistic#
where  n.name = 'table fetch continued row';

VALUE   
       0 

select c3
from   t
where  c1 = 1;

C3       
   <null> 

select value 
from   v$mystat m
join   v$statname n
on     m.statistic# = n.statistic#
where  n.name = 'table fetch continued row';

VALUE   
       1 

select c257
from   t
where  c1 = 1;

C257   
    257 

select value 
from   v$mystat m
join   v$statname n
on     m.statistic# = n.statistic#
where  n.name = 'table fetch continued row';

VALUE   
       2 

truncate table chained_rows;
analyze table t list chained rows;

select table_name, head_rowid from chained_rows;

TABLE_NAME   HEAD_ROWID           
T            AAAUMRAAEAAAAR4AAA    


Note that "table fetch continued row" increases when fetching the third column as well as the last. So you could see chaining issues kick in much earlier than expected.

Again, demo is from 11.2. On higher versions you'll may need to fill the block with other data to see the chaining.

Jonathan Lewis points out some other issues that could arise:

https://jonathanlewis.wordpress.com/2015/02/19/255-columns/
https://jonathanlewis.wordpress.com/2012/03/30/quiz-night-17/#comment-45847

Summary

- Depending on version and space available, chaining might happen within the row
- The database chains all of the last 255 columns. Selecting these columns for chained rows will have to do more work
- The more often you insert rows with null values, then later update the chained columns, the more likely you are to have chained rows

So really you need to test on your application to see what impact chaining has!

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Hariharan Senthil pandiyan, June 14, 2019 - 4:22 pm UTC

Thanks a Ton :) Never expected with this wonderful testcase. i will check and update you, thanks again.


Chris Saxon
June 17, 2019 - 9:09 am UTC

You're welcome.

More to Explore

Administration

Need more information on Administration? Check out the Administrators guide for the Oracle Database