Skip to Main Content
  • Questions
  • Why are bind variables treated differently in sql compare statement?

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Jonathon.

Asked: February 06, 2008 - 11:35 am UTC

Last updated: February 07, 2008 - 1:08 pm UTC

Version: 10.0.2

Viewed 1000+ times

You Asked

Why does the following select not work? I know one would never want to use a char as an id but I found this interesting and would like to know the underlying reason why apparently oracle strips the extra chars in one case and not in the other.
Thanks
Jon

create table t (id char(20), value varchar2(100));
insert into t values('1', 'some test value');

declare

v_bind    varchar2(10) := '1';
v_value   varchar2(30);
begin

 select value
   into v_value
   from t
 where id = '1';

 dbms_output.put_line('value = ' || v_value); -- the value is populated and the display is "some test value"
 v_value := '';

 begin
 select value
   into v_value
   from t
 where id = v_bind;
 exception when NO_DATA_FOUND then
  dbms_output.put_line('We got a no data found exception');
 end; 

end;

and Tom said...

ANSI has a rule that says "character string literals will be promoted to the type they are being compared to"

So, when you use "where id = '1'", the '1' literal is promoted to a char(20)

ANSI also has a rule that says "respect what the programmer binds - if they bind a varchar2(10) - that is what they meant to do, we believe they know what they are doing"

It would be wrong if the varchar2 containing '1'
matched the char containing '1 '

It is right that the literal '1', which is by definition promoted to '1 '
matches it.

From my last book Expert Oracle Database Architecture:
<quote>


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.


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

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