Thread: postgres sql help
<div dir="ltr"> hi, i am fairly new in postgresql, so if anyone can help me would be great<br /><br /> if i simply do:<br/><br /> select ver_no<br /> from version<br /> order by ver_no<br /><br /> the result will be something like this:<br/><br /> .1.3.1<br /> .1.3.2.5.<br /> .1.4.1.7.12<br /> .1.4.11.14.7.<br /> .1.4.3.109.1.<br /> .1.4.8.66.<br /><br/> so as you can see first 3 lines are ok, but how to make 1.4.3.109 come before 1.4.11 because the third level "3"is smaller than "11". i understand they are stored as char so i used split_part function to separate each numbers between"." in a separate column. but when i try to convert those column into integer, i am getting an error msg saying: ERROR:invalid input syntax for type numeric: " "<br /><br /> here is my code:<br /><br /> select ver_no, duedate, status,<br/> to_number(split_part(ver_no, '.', 2), '9999') a,<br /> to_number(split_part(ver_no, '.', 3), '9999') b,<br />to_number(split_part(ver_no, '.', 4), '9999') c,<br /> to_number(split_part(ver_no, '.', 5), '9999') d<br /><br /><br />from version<br /><br /> order by a,b,c,d<br /><br /> I am not sure if i am heading towards wrong direction but can someoneplease suggest or give me some other ideas to sort this. <br /><br /> PS: i found some good solution in SQL Serverbut those commands are not used in postgreSQL.<br /><br />Thanks in advance<br /><br />- James<br /><br /></div>
James Bond <coolofall@hotmail.com> wrote: > hi, i am fairly new in postgresql, so if anyone can help me would be great > > if i simply do: > > select ver_no > from version > order by ver_no > > the result will be something like this: > > .1.3.1 > .1.3.2.5. > .1.4.1.7.12 > .1.4.11.14.7. > .1.4.3.109.1. > .1.4.8.66. > > so as you can see first 3 lines are ok, but how to make 1.4.3.109 come before > 1.4.11 because the third level "3" is smaller than "11". i understand they are > stored as char so i used split_part function to separate each numbers between > "." in a separate column. but when i try to convert those column into integer, > i am getting an error msg saying: ERROR: invalid input syntax for type numeric: > " " > > here is my code: test=*# select * from o; t ---------------.1.3.1.1.3.2.5..1.4.1.7.12.1.4.11.14.7..1.4.3.109.1..1.4.8.66. (6 rows) Time: 0,262 ms test=*# select * from o order by split_part(t,'.',2)::int, split_part(t,'.',3)::int, split_part(t,'.',4)::int; t ---------------.1.3.1.1.3.2.5..1.4.1.7.12.1.4.3.109.1..1.4.8.66..1.4.11.14.7. (6 rows) Time: 0,403 ms Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
In article <SNT102-W49402A41C6B6599F082D35A8E10@phx.gbl>, James Bond <coolofall@hotmail.com> writes: > hi, i am fairly new in postgresql, so if anyone can help me would be great > if i simply do: > select ver_no > from version > order by ver_no > the result will be something like this: > .1.3.1 > .1.3.2.5. > .1.4.1.7.12 > .1.4.11.14.7. > .1.4.3.109.1. > .1.4.8.66. > so as you can see first 3 lines are ok, but how to make 1.4.3.109 come > before 1.4.11 because the third level "3" is smaller than "11". The query SELECT ver_no FROM version ORDER BY string_to_array(ver_no, '.', '')::int[] should do what you want.
Harald Fuchs <hari.fuchs@gmail.com> wrote: >> hi, i am fairly new in postgresql, so if anyone can help me would be great >> if i simply do: >> select ver_no >> from version >> order by ver_no >> the result will be something like this: >> .1.3.1 >> .1.3.2.5. >> .1.4.1.7.12 >> .1.4.11.14.7. >> .1.4.3.109.1. >> .1.4.8.66. >> so as you can see first 3 lines are ok, but how to make 1.4.3.109 come >> before 1.4.11 because the third level "3" is smaller than "11". > The query > SELECT ver_no > FROM version > ORDER BY string_to_array(ver_no, '.', '')::int[] > should do what you want. Really neat! :-) For pre-9.1, you have to "ORDER BY string_to_array(TRIM('.' FROM ver_no), '.')::int[];", though. Tim