You Asked
<Fred Feuerstein writes>
I recently received an email from a puzzled developer. So...what's wrong with the following scenario?
SQL> SELECT 'SQL IN trimmed trailing blanks!'
2 FROM DUAL
3 WHERE 'CA ' IN ( 'CA', 'US' )
4 /
'TRIMMEDTRAILINGBLANKS!'
------------------------
SQL IN trimmed trailing blanks!
Isn't that odd? I asked if the string "CA " (CA followed by three spaces) was in the list of 'CA' and 'US' -- and Oracle said yes!
I checked the documentation but could not find anything about automatically trimming blanks when you use the IN clause. So I experimented some more:
....
Does not trim leading spaces:
SQL> SELECT 'SQL IN does not trim leading blanks!'
2 FROM DUAL
3 WHERE ' CA' IN ( 'CA', 'US' )
4 /
no rows selected
- And most important of all: does not trim anything at all when you execute the same query inside a PL/SQL block or simply use the native PL/SQL IN clause:
DECLARE
PROCEDURE exec_in ( message_in IN VARCHAR2, value_in IN VARCHAR2 )
IS
l_dummy VARCHAR2 ( 32767 );
BEGIN
BEGIN
SELECT message_in
INTO l_dummy
FROM DUAL
WHERE value_in IN ( 'CA', 'US' );
DBMS_OUTPUT.put_line ( message_in );
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ( message_in || ' did not happen.' );
END;
IF value_in IN ( 'CA', 'US' )
THEN
DBMS_OUTPUT.put_line ( '"PL/SQL IN ' || SUBSTR ( message_in, 9 ));
ELSE
DBMS_OUTPUT.put_line ( '"PL/SQL IN '
|| SUBSTR ( message_in, 9 )
|| ' did not happen.'
);
END IF;
END;
BEGIN
exec_in ( '"SQL IN trimmed trailing blanks."', 'CA ' );
exec_in ( '"SQL IN trimmed leading blanks."', ' CA' );
END;
/
"SQL IN trimmed trailing blanks." did not happen.
"PL/SQL IN trimmed trailing blanks." did not happen.
"SQL IN trimmed leading blanks." did not happen.
"PL/SQL IN trimmed leading blanks." did not happen.
The lesson we learn once again: write everything in PL/SQL!
Ah, just kidding. You should continue to choose the best tool for the challenge at hand. But in this case, avoid funkiness with IN by executing your query within a PL/SQL block!
</Fred Feuerstein writes>
So, I still don't understand this.
Is it a bug ?
(I can reproduce it in 9.2)
and Tom said...
This is not a bug.
This is expected. By default 'CA' and 'CA ' are 'char' types - not varchar2 types.
When comparing char to char - SQL says to promote the type - so we would be comparing all char(3) to all char(3) - taking the 2 character char's and making them char(3)'s which blank pads at the end.
Hence
ops$tkyte@ORA9IR2> select * from dual where 'CA ' = 'CA';
D
-
X
returns a row since both literals are CHAR(3)'s by SQL definition and 'CA' becomes 'CA ', but:
ops$tkyte@ORA9IR2> select * from dual where ' CA' = 'CA';
no rows selected
doesn't return a thing because it is equivalent to:
ops$tkyte@ORA9IR2> select * from dual where ' CA' = 'CA ';
no rows selected
the blanks are added to the END of the string
if you use varchar2 types
ops$tkyte@ORA9IR2> select * from dual where cast( 'CA ' as varchar2(3) ) = 'CA';
no rows selected
this doesn't happen This is why I don't like the char type AT ALL and never use it. From Expert Oracle Database Architecture, I wrote:
<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. Lets 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 dont 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, youll 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 reasonsthe fixed-width storage, which tends to make the tables and related indexes much larger than normal, coupled with the bind variable issuethat 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
(15 ratings)
Is this answer out of date? If it is, please let us know via a Comment