Thread: Ordering by field using lower()

Ordering by field using lower()

From
speedboy
Date:
Hi, please view the output from some queries below. My question is, why is
the ordering apparently wrong when using the lower() function?

The field "pid" is of type int2 and there is no need to use lower(), but I
will need to put a test clause in php if my order type is pid so I do not
use lower() in the query. Which is not a problem but I am interested as to
why lower() returns a different set of results when being used on int2.

Thanks.

logs=# select max(pid) from syslogd; max
-------31924
(1 row)

logs=# select min(pid) from syslogd;min
-----548
(1 row)

logs=# select pid from syslogd order by pid asc limit 10;pid
------ 548 548 548 548 548 876 876398339833983
(10 rows)

logs=# select pid from syslogd order by lower(pid) asc limit 10; pid
-------25272253892617026323299583029430294305043050431770
(10 rows)

logs=# select pid from syslogd order by pid desc limit 10; pid
-------31924319243192431924319243192331923319233192331922
(10 rows)

logs=# select pid from syslogd order by lower(pid) desc limit 10;pid
------90889088 876 876 548 548 548 548 5485158
(10 rows)

logs=# 



Re: Ordering by field using lower()

From
Tom Lane
Date:
speedboy <speedboy@nomicrosoft.org> writes:
> Hi, please view the output from some queries below. My question is, why is
> the ordering apparently wrong when using the lower() function?

You're getting a textual sort, not a numeric sort.

> The field "pid" is of type int2 and there is no need to use lower(), but I
> will need to put a test clause in php if my order type is pid so I do not
> use lower() in the query.

That would be a good plan anyway.  It's pure luck for you that there is
an implicit int2->text coercion path that allows the text function
lower() to be applied to an int2 field.  If your app expects to be able
to apply lower() to any datatype at all, I'd say your app is broken.
        regards, tom lane