Thread: casting character varying to integer - order by numeric sort
How can I force a character field to sort as a numeric field? I've got something like this: Postgres=> SELECT username,last_name FROM eg_member ORDER BY username; ----------+-----------0120 | Foley1 | Sullivan10 | Guest11 | User (5 rows) (I can't change the field type). I tried: SELECT username,last_name FROM eg_member ORDER BY username::integer; But postgres 7 rejects this with "ERROR: cannot cast type character varying to integer". Is there a way to force numeric sort order? I tried a variety of functions, such as to_char() and convert() without any luck. Thanks for your insight!
Check out the function to_number() In particular here's an example... If a field named section is text containing numbers: ORDER BY to_number(t.section, text(99999999)) If the field can also contain non-numerals such as 3a, 3b, and you want 3a to show first then do this: ORDER BY to_number(t.section, text(99999999)), t.section And if the field section can actually START with an alpha, then to prevent to_number from failing do this: to_number(textcat('0', t.section), text(99999999)), t.section Terry Bryce W Nesbitt wrote: > How can I force a character field to sort as a numeric field? > I've got something like this: > > Postgres=> SELECT username,last_name > FROM eg_member ORDER BY username; > ----------+----------- > 0120 | Foley > 1 | Sullivan > 10 | Guest > 11 | User > (5 rows) > > (I can't change the field type). I tried: > > SELECT username,last_name > FROM eg_member ORDER BY username::integer; > > But postgres 7 rejects this with "ERROR: cannot cast type character > varying to integer". Is there a way to force numeric sort order? I > tried a variety of functions, such as to_char() and convert() without > any luck. Thanks for your insight! > > > ---------------------------(end of broadcast)--------------------------- > TIP 2: Don't 'kill -9' the postmaster > -- Terry Fielder terry@greatgulfhomes.com Associate Director Software Development and Deployment Great Gulf Homes / Ashton Woods Homes Fax: (416) 441-9085
Bryce W Nesbitt <bryce1@obviously.com> writes: > SELECT username,last_name > FROM eg_member ORDER BY username::integer; > But postgres 7 rejects this with "ERROR: cannot cast type character > varying to integer". As a general rule, you need to be more specific than that about which version you are working with ;-) You may find that username::text::integer will work, depending on which 7.x this actually is. regards, tom lane
Re: casting character varying to integer - order by numeric
From
"Bryce Nesbitt (mailing list account)"
Date:
Tom Lane wrote:<br /><blockquote cite="mid3687.1129779194@sss.pgh.pa.us" type="cite"><blockquote type="cite"><pre wrap="">Butpostgres 7 rejects this with "ERROR: cannot cast type character varying to integer". </pre></blockquote><pre wrap=""> As a general rule, you need to be more specific than that about which version you are working with ;-) You may find that username::text::integer will work, depending on which 7.x this actually is. regards, tom lane </pre></blockquote> Oooh, I'd be so happy to. But I don't know. Yes, I don't know.<br /><br />I know which version of "psql" is installed on my local machine, but the actual database is remote. Is there a commandto get the server version? As close as I can find is:<br /><br /> stage=> \copyright<br /> PostgreSQL Data BaseManagement System<br /><br /> Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group<br /><br /><br /> -Bryce<br /><br /> PS: If it's a hint, "select username from eg_member order by username::text::integer" worksfine. Thanks.<br />
Bryce Nesbitt (mailing list account) wrote: > Tom Lane wrote: >>As a general rule, you need to be more specific than that about which >>version you are working with ;-) > Oooh, I'd be so happy to. But I don't know. Yes, I don't know. > > I know which version of "psql" is installed on my local machine, but the actual > database is remote. Is there a command to get the server version? As close as > I can find is: > > stage=> \copyright SELECT version(); -- Richard Huxton Archonet Ltd
Re: casting character varying to integer - order by numeric
From
"Bryce Nesbitt (mailing list account)"
Date:
Cool, thanks. PostgreSQL 7.4.2 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.2.3 20030502 (Red Hat Linux 3.2.3-20) Richard Huxton wrote: > SELECT version();