Обсуждение: How to get the max on a char column?

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

How to get the max on a char column?

От
Rodrigo Carvalhaes
Дата:
Hi !

I am quite confused of the results on a SELECT max...

My environment:
Conectiva Linux 10, PostgreSQL 7.4.6 (compiled from the sources)

My problem is the "select max(id) FROM test" the result is 20 but the 
right is 1020. Is this a BUG or I am crazy ??

Cheers,

Rodrigo Carvalhaes

The SQL...

teste=# CREATE TABLE test ( id char(15), name char(80) );
CREATE TABLE
teste=# \d test     Table "public.test"
Column |     Type      | Modifiers
--------+---------------+-----------
id          | character(15) |
name   | character(80) |

teste=# INSERT INTO test VALUES ( '10', 'luidgi');
INSERT 15303727 1
teste=# INSERT INTO test VALUES ( '20', 'luis');
INSERT 15303728 1
teste=# INSERT INTO test VALUES ( '1010', 'ruan');
INSERT 15303729 1
teste=# INSERT INTO test VALUES ( '1020', 'lion');
INSERT 15303730 1
teste=# SELECT * FROM test;    id        |                                       name
-----------------+---------------------------------------------------------------------------------- 

10              | luidgi
20              | luis
1010            | ruan
1020            | lion
(4 rows)

teste=# SELECT max(id) FROM test;
max
-----
20
(1 row)

teste=# select max(id) FROM test;
max
-----
20
(1 row)





---------------------------(end of broadcast)---------------------------
TIP 1: subscribe and unsubscribe commands go to majordomo@postgresql.org



Re: How to get the max on a char column?

От
Jeff Eckermann
Дата:
--- Rodrigo Carvalhaes <grupos@carvalhaes.net> wrote:

> Hi !
> 
> I am quite confused of the results on a SELECT
> max...
> 
> My environment:
> Conectiva Linux 10, PostgreSQL 7.4.6 (compiled from
> the sources)
> 
> My problem is the "select max(id) FROM test" the
> result is 20 but the 
> right is 1020. Is this a BUG or I am crazy ??

For a char() column, '20' is the maximum of the values
that you have inserted, because the comparison is
text-based, not numeric.  If you want numeric sorting,
you will need to cast the value, like:

select max(cast(id as integer)) from test;

I'm not sure offhand whether in fact a direct cast
from char() to integer is available; you may need to
cast to "text" first.

But if you expect to be able to sort numerically, why
are you not using a numeric datatype?

> 
> Cheers,
> 
> Rodrigo Carvalhaes
> 
> The SQL...
> 
> teste=# CREATE TABLE test ( id char(15), name
> char(80) );
> CREATE TABLE
> teste=# \d test
>       Table "public.test"
> Column |     Type      | Modifiers
> --------+---------------+-----------
> id          | character(15) |
> name   | character(80) |
> 
> teste=# INSERT INTO test VALUES ( '10', 'luidgi');
> INSERT 15303727 1
> teste=# INSERT INTO test VALUES ( '20', 'luis');
> INSERT 15303728 1
> teste=# INSERT INTO test VALUES ( '1010', 'ruan');
> INSERT 15303729 1
> teste=# INSERT INTO test VALUES ( '1020', 'lion');
> INSERT 15303730 1
> teste=# SELECT * FROM test;
>      id        |                                    
>   name
>
-----------------+----------------------------------------------------------------------------------
> 
> 
> 10              | luidgi
> 20              | luis
> 1010            | ruan
> 1020            | lion
> (4 rows)
> 
> teste=# SELECT max(id) FROM test;
> max
> -----
> 20
> (1 row)
> 
> teste=# select max(id) FROM test;
> max
> -----
> 20
> (1 row)
> 
> 
> 
> 
> 
> ---------------------------(end of
> broadcast)---------------------------
> TIP 1: subscribe and unsubscribe commands go to
> majordomo@postgresql.org
> 
> 
> ---------------------------(end of
> broadcast)---------------------------
> TIP 1: subscribe and unsubscribe commands go to
> majordomo@postgresql.org
> 


    
__________________________________ 
Do you Yahoo!? 
Meet the all-new My Yahoo! - Try it today! 
http://my.yahoo.com 



Re: How to get the max on a char column?

От
Rodrigo Carvalhaes
Дата:
Dear Jeff,

Thank you for your help.

I tried :  select max((id::text)::integer) from test; 

and works perfectly!

Greetings from Brazil!

Rodrigo Carvalhaes

Jeff Eckermann wrote:

>--- Rodrigo Carvalhaes <grupos@carvalhaes.net> wrote:
>
>  
>
>>Hi !
>>
>>I am quite confused of the results on a SELECT
>>max...
>>
>>My environment:
>>Conectiva Linux 10, PostgreSQL 7.4.6 (compiled from
>>the sources)
>>
>>My problem is the "select max(id) FROM test" the
>>result is 20 but the 
>>right is 1020. Is this a BUG or I am crazy ??
>>    
>>
>
>For a char() column, '20' is the maximum of the values
>that you have inserted, because the comparison is
>text-based, not numeric.  If you want numeric sorting,
>you will need to cast the value, like:
>
>select max(cast(id as integer)) from test;
>
>I'm not sure offhand whether in fact a direct cast
>from char() to integer is available; you may need to
>cast to "text" first.
>
>But if you expect to be able to sort numerically, why
>are you not using a numeric datatype?
>
>  
>
>>Cheers,
>>
>>Rodrigo Carvalhaes
>>
>>The SQL...
>>
>>teste=# CREATE TABLE test ( id char(15), name
>>char(80) );
>>CREATE TABLE
>>teste=# \d test
>>      Table "public.test"
>>Column |     Type      | Modifiers
>>--------+---------------+-----------
>>id          | character(15) |
>>name   | character(80) |
>>
>>teste=# INSERT INTO test VALUES ( '10', 'luidgi');
>>INSERT 15303727 1
>>teste=# INSERT INTO test VALUES ( '20', 'luis');
>>INSERT 15303728 1
>>teste=# INSERT INTO test VALUES ( '1010', 'ruan');
>>INSERT 15303729 1
>>teste=# INSERT INTO test VALUES ( '1020', 'lion');
>>INSERT 15303730 1
>>teste=# SELECT * FROM test;
>>     id        |                                    
>>  name
>>
>>    
>>
>-----------------+----------------------------------------------------------------------------------
>  
>
>>10              | luidgi
>>20              | luis
>>1010            | ruan
>>1020            | lion
>>(4 rows)
>>
>>teste=# SELECT max(id) FROM test;
>>max
>>-----
>>20
>>(1 row)
>>
>>teste=# select max(id) FROM test;
>>max
>>-----
>>20
>>(1 row)
>>
>>
>>
>>
>>
>>---------------------------(end of
>>broadcast)---------------------------
>>TIP 1: subscribe and unsubscribe commands go to
>>majordomo@postgresql.org
>>
>>
>>---------------------------(end of
>>broadcast)---------------------------
>>TIP 1: subscribe and unsubscribe commands go to
>>majordomo@postgresql.org
>>
>>    
>>
>
>
>
>        
>__________________________________ 
>Do you Yahoo!? 
>Meet the all-new My Yahoo! - Try it today! 
>http://my.yahoo.com 
> 
>
>  
>