A reader, January 05, 2011 - 12:35 pm UTC
"if the last column however is NULL - we have to use storage for EVERY column in the table) "
you mean to say NOT NULL in above right?
Thanks
January 05, 2011 - 12:45 pm UTC
correct and... corrected!
Date when column was added ??
Ankit, January 24, 2012 - 11:25 pm UTC
Hi Tom
I need to know when a particular column was added to a table.
I know about dba_objects which give the time of last DDL but that didn't solve my purpose.
I came across last_analyzed column in dba_tab_columns, but as the name suggests, its gives the date when that column was last analyzed. I added a column on 24 Jan 2012. And this column was also found set to 24 Jan 2012. Does it mean that Oracle immediately analyses a column when it is added ?
I developed this hunch while trying to know when a particular column was added to a table.
Thanks.
January 25, 2012 - 10:35 am UTC
we do not track such minutiae. You would have to enable auditing or use a DDL event trigger to track such events.
Loz, January 26, 2012 - 5:06 pm UTC
Surely you meant to say
"refer to your change control preocedure and documentation"
:)
How new bytes are stored
Rashid, January 26, 2012 - 9:38 pm UTC
'.......if the last N columns of a given row are NULL - we use zero bytes of storage for them.......'
Hi Tom,
what happens in case we have millions of records in table and 80% of data-rows where last 10 columns are NULL. So we used zero bytes for storage.
Now when we update few rows to have proper values in those columns. what happens when extra bytes are needed to store these values,
does the following data rows are shifted ?
January 31, 2012 - 3:24 pm UTC
It will depend on whether the rows still fit on the block or not.
When you create a table, by default the pctfree will be 10% - meaning, we'll insert into that block until there is 10% of the block only left free - then we stop inserting.
The 10% is left behind for future updates. As long as the aggregate size of the rows stored on the block do not increase more than 10% - everything will stay more or less "put" - where it is.
But - what if you increase the size of the rows on a given block so that they need more space altogether than is available on that one block? Now you have to move (we call it migrating) some of the rows - since they won't fit anymore.
so, what we do is find another block where that updated row will in fact fit and put it there. On the original block - we leave behind a forwarding address (rowid) so that anyone that comes to that block looking for the row will know it moved (migrated). This allows us to skip updating every index (which has the rows rowid in it) when this happens.
The downside however is when you access this row later via an index - you'll have the original rowid and will have to go to that block to read the forwarding address to go and read another block. You'll have to do two table accesses to retrieve the row instead of just one.
In the future, if you *know* this is going to happen, you should plan ahead by setting the pctfree on this segment higher when you create it - that way you'll avoid the operation of migrating the row.
Thomas, February 06, 2012 - 3:46 am UTC
How does Oracle handle a row update if the row requires more space than before and the block as enough space left?
Am I right to assume that the whole block data can be rearranged (moving row start offsets around) when one or more rows of a block are updated, as long as the relative row order is left unchanged?
stats on columns access
shubi, February 06, 2012 - 2:53 pm UTC
Is there a way to know which column is most access/filter
so i can organize my table accordingly?
February 06, 2012 - 9:05 pm UTC
But in general, the difference is so tiny, so unmeasurable in real life that I would not worry about it. Put the columns in the order that makes the most sense.
please take that to heart. there are so many other much more important things to worry about in life.