Обсуждение: char columns, space padding, and the "like" operator

Поиск
Список
Период
Сортировка

char columns, space padding, and the "like" operator

От
"Haszlakiewicz, Eric"
Дата:
I recently got very confused by the operation of the like operator and
it's interaction with "char" type columns.  i.e.:

create table foo ( col1 char(10) );
insert into foo values ('SOMEVALUE');
select * from foo where col1 like 'SOME% %';
-- The above returns the column
select 'SOMEVALUE' like 'SOME% %';
-- but this returns false

Once I realized that the value in the table actually got extended to
'SOMEVALUE ', things started making sense, since the equivalent quick
select is actually:
select 'SOMEVALUE ' like 'SOME% %';

Unfortunately, my app has a whole bunch of places where it uses
constructs like this against char columns.  Other databases (such as
Informix), automatically strip spaces off char column so queries like
the above behave in a more intuitive fashion.  That causes it's own
problems, so I'm not suggesting adding feature to postgres, but I was
wondering if it already exists, and if so how do I turn it on?

eric


Re: char columns, space padding, and the "like" operator

От
Tom Lane
Дата:
"Haszlakiewicz, Eric" <EHASZLA@transunion.com> writes:
> Once I realized that the value in the table actually got extended to
> 'SOMEVALUE ', things started making sense, since the equivalent quick
> select is actually:
> select 'SOMEVALUE ' like 'SOME% %';

> Unfortunately, my app has a whole bunch of places where it uses
> constructs like this against char columns.  Other databases (such as
> Informix), automatically strip spaces off char column so queries like
> the above behave in a more intuitive fashion.

Cast the char(n) column to text or varchar, and it should work more
like you're expecting.
        regards, tom lane


Re: char columns, space padding, and the "like" operator

От
"Haszlakiewicz, Eric"
Дата:
>-----Original Message-----
>From: Tom Lane [mailto:tgl@sss.pgh.pa.us]
>
>"Haszlakiewicz, Eric" <EHASZLA@transunion.com> writes:
>> Once I realized that the value in the table actually got extended to
>> 'SOMEVALUE ', things started making sense, since the equivalent quick
>> select is actually:
>> select 'SOMEVALUE ' like 'SOME% %';
>
>> Unfortunately, my app has a whole bunch of places where it uses
>> constructs like this against char columns.  Other databases (such as
>> Informix), automatically strip spaces off char column so queries like
>> the above behave in a more intuitive fashion.
>
>Cast the char(n) column to text or varchar, and it should work more
>like you're expecting.

Yeah, I figured that much.  I was hoping for a connection-wide or
database-wide setting, so I wouldn't have to go change all my SQL
statements.

eric


Re: char columns, space padding, and the "like" operator

От
Tom Lane
Дата:
"Haszlakiewicz, Eric" <EHASZLA@transunion.com> writes:
>> Cast the char(n) column to text or varchar, and it should work more
>> like you're expecting.

> Yeah, I figured that much.  I was hoping for a connection-wide or
> database-wide setting, so I wouldn't have to go change all my SQL
> statements.

Well, you could experiment with removing the char(n) variant of the ~~
operator, but if it breaks you get to keep both pieces.
        regards, tom lane