Skip to Main Content

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, PARAG.

Asked: September 15, 2006 - 7:31 am UTC

Last updated: December 29, 2006 - 9:24 am UTC

Version: 9.2

Viewed 10K+ times! This question is

You Asked

Hi Tom,

I remember, for answering some questions you have strongly recommended not to use CHAR datatype. Will you pl summarize main reasons, why do not use CHAR data type and with few examples ?

thanks & regards
PJP


and Tom said...

<quote source=Expert Oracle Database Architecture>

Character Strings

There are four basic character string types in Oracle, namely CHAR, VARCHAR2, NCHAR, and NVARCHAR2. All of the strings are stored in the same format in Oracle. On the database block they will have a leading length field of 1 to 3 bytes followed by the data, or when they are NULL they will be represented as a single byte value of 0xFF.

Note Trailing NULL columns consume 0 bytes of storage in Oracle. This means that if the “last column” in a table is NULL, Oracle stores nothing for it. If the last two columns are both NULL, there will be nothing stored for either of them. But if any column after a NULL column in position is not null, then Oracle will use the null flag described in this section to indicate the missing value.
If the length of the string is less than or equal to 250 (0x01 to 0xFA), Oracle will use 1 byte for the length. All strings exceeding 250 bytes in length will have a flag byte of 0xFE followed by 2 bytes that represent the length. So, a VARCHAR2(80) holding the words Hello World might look like Figure 12-1 on a block.

Insert 5300f1201scrap.pdf

Figure 12-1. Hello World stored in a VARCHAR2(80)
A CHAR(80) holding the same data, on the other hand, would look like Figure 12-2.

Insert 5300f1202scrap.pdf
Figure 12-2. Hello World stored in a CHAR(80)

The fact that a CHAR/NCHAR is really nothing more than a VARCHAR2/NVARCHAR2 in disguise makes me of the opinion that there are really only two character string types to ever consider, namely VARCHAR2 and NVARCHAR2. I have never found a use for the CHAR type in any application. Since a CHAR type always blank pads the resulting string out to a fixed width, we discover rapidly that it consumes maximum storage both in the table segment and any index segments. That would be bad enough, but there is another important reason to avoid CHAR/NCHAR types: they create confusion in applications that need to retrieve this information (many cannot “find” their data after storing it). The reason for this relates to the rules of character string comparison and the strictness with which they are performed. Let’s use the 'Hello World' string in a simple table to demonstrate:

ops$tkyte@ORA10G> create table t
2 ( char_column char(20),
3 varchar2_column varchar2(20)
4 )
5 /
Table created.

ops$tkyte@ORA10G> insert into t values ( 'Hello World', 'Hello World' );
1 row created.

ops$tkyte@ORA10G> select * from t;
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World
ops$tkyte@ORA10G> select * from t where char_column = 'Hello World';
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World

ops$tkyte@ORA10G> select * from t where varchar2_column = 'Hello World';
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World

So far, the columns look identical but, in fact, some implicit conversion has taken place and the CHAR(11) literal has been promoted to a CHAR(20) and blank padded when compared to the CHAR column. This must have happened since Hello World……… is not the same as Hello World without the trailing spaces. We can confirm that these two strings are materially different:

ops$tkyte@ORA10G> select * from t where char_column = varchar2_column;
no rows selected

They are not equal to each other. We would have to either blank pad out the VARCHAR2_COLUMN to be 20 bytes in length or trim the trailing blanks from the CHAR_COLUMN, as follows:

ops$tkyte@ORA10G> select * from t where trim(char_column) = varchar2_column;
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World
ops$tkyte@ORA10G> select * from t where char_column = rpad( varchar2_column, 20 );
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World

Note There are many ways to blank pad the VARCHAR2_COLUMN, such as using the CAST() function.

The problem arises with applications that use variable length strings when they bind inputs, with the resulting “no data found” that is sure to follow:

ops$tkyte@ORA10G> variable varchar2_bv varchar2(20)
ops$tkyte@ORA10G> exec :varchar2_bv := 'Hello World';
PL/SQL procedure successfully completed.

ops$tkyte@ORA10G> select * from t where char_column = :varchar2_bv;
no rows selected

ops$tkyte@ORA10G> select * from t where varchar2_column = :varchar2_bv;
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World

So here, the search for the VARCHAR2 string worked, but the CHAR column did not. The VARCHAR2 bind variable will not be promoted to a CHAR(20) in the same way as a character string literal. At this point, many programmers form the opinion that “bind variables don’t work; we have to use literals.” That would be a very bad decision indeed. The solution is to bind using a CHAR type:

ops$tkyte@ORA10G> variable char_bv char(20)
ops$tkyte@ORA10G> exec :char_bv := 'Hello World';

PL/SQL procedure successfully completed.
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> select * from t where char_column = :char_bv;
CHAR_COLUMN VARCHAR2_COLUMN
-------------------- --------------------
Hello World Hello World
ops$tkyte@ORA10G> select * from t where varchar2_column = :char_bv;
no rows selected

However, if you mix and match VARCHAR2 and CHAR, you’ll be running into this issue constantly. Not only that, but the developer is now having to consider the field width in her applications. If the developer opts for the RPAD() trick to convert the bind variable into something that will be comparable to the CHAR field (it is preferable, of course, to pad out the bind variable, rather than TRIM the database column, as applying the function TRIM to the column could easily make it impossible to use existing indexes on that column), she would have to be concerned with column length changes over time. If the size of the field changes, then the application is impacted, as it must change its field width.

It is for these reasons—the fixed-width storage, which tends to make the tables and related indexes much larger than normal, coupled with the bind variable issue—that I avoid the CHAR type in all circumstances. I cannot even make an argument for it in the case of the one-character field, because in that case it is really of no material difference. The VARCHAR2(1) and CHAR(1) are identical in all aspects. There is no compelling reason to use the CHAR type in that case, and to avoid any confusion, I “just say no,” even for the CHAR(1) field.
</quote>

Rating

  (5 ratings)

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

Comments

Why not use CHAR for Index Performance?

Robbie Lindsey, December 28, 2006 - 2:48 pm UTC

I understand and appreciate the Storage differences involved between CHAR and VARCHAR2, but was disappointed that this article didn't also address Index Performance differences, as it still seems that the length checks on variable length indices would slow down retrievals.

Tom Kyte
December 29, 2006 - 9:19 am UTC

umm, a char is just a varchar2 with a fixed length field.

it seems that a fixed width field would result in a larger index that would result in reduced performance due to being larger (and hence "taller"), due to increased block splits (less rows per leaf block), due to increased redo and undo generation.


So, if we were to talk about char vs varchar2 from a performance difference in indexing, the discussion would be counter to your premise.

Why not use CHAR for Index Performance? - Clarified

Robbie Lindsey, December 28, 2006 - 3:24 pm UTC

Just to clarify: when I wrote "Index Performance" above, I meant "Retrieval Speed".
Tom Kyte
December 29, 2006 - 9:24 am UTC

right, it would be negatively impacted using a fixed width (larger) field

Followup requested for a CHAR--VARCHAR2 brief in index blocks

Baba Piprani, January 04, 2007 - 3:44 pm UTC

Your comment provides good insight on what happens inside data blocks using CHAR and VARCHAR2 columns, and promotes efficient development and design. A similar treatise on what happens to the CHAR--VARCHAR2 data columns storagewise in index blocks would be useful indeed to complement this design approach. Thank you

Followup requested for a CHAR--VARCHAR2 brief in index blocks

Baba Piprani, January 04, 2007 - 3:48 pm UTC

Your comment provides good insight on what happens inside data blocks using CHAR and VARCHAR2 columns, and promotes efficient development and design. A similar treatise on what happens to the CHAR--VARCHAR2 data columns storagewise in index blocks would be useful indeed to complement this design approach. Thank you

modify char to varchar2

sagsag, January 22, 2007 - 4:23 am UTC

Hi Tom,

I'm testing the modify column option from varchar2 to char (dont ask why, application people)

when I
1.create the table.
2. modify the column from varchar2(10) to char(20)
3.and insert append the data .

it is slower then

1.create the table.
2. modify the column from varchar2(10) to varchar2(20)
3.and insert append the data .

why is that ? could be the blanks padding is taking longer.
thanks,


sagi

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library