Ooops. Disregard previous post, had a tiresome day.
Ray Stell wrote: > > Need a trick to sort ip addresses into numerical order. I have them > stored as varchar2. If I select without a sort I get rows > in order of their character value: > > 10.0.112.1 > 10.0.113.1 > 10.0.113.2 > 10.0.12.1 > 10.0.78.1 > > I'd like to order them numerically within the octets: > > 10.0.12.1 > 10.0.78.1 > 10.0.112.1 > 10.0.113.1 > 10.0.113.2 > =============================================================== > Ray Stell [EMAIL PROTECTED] (540) 231-4109 KE4TJC 28^D > -- My previous post, like some other suggestions (translate, etc.) was too clever by half. This is uglier but works better. SQL> get iptest 1 select address 2 from ip 3 order by to_number(substr(address, 1, instr(address, '.', 1, 1) - 1)), 4 to_number(substr(address, instr(address, '.', 1, 1) + 1, 5 instr(address, '.', 1, 2) 6 - instr(address, '.', 1, 1))), 7 to_number(substr(address, instr(address, '.', 1, 2) + 1, 8 instr(address, '.', 1, 3) 9 - instr(address, '.', 1, 2))), 10* to_number(substr(address, instr(address, '.', 1, 3) + 1)) SQL> / ADDRESS -------------------- 10.0.12.1 10.0.78.1 10.0.112.1 10.0.113.1 10.0.113.2 -- Regards, Stephane Faroult Oriole Software -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Stephane Faroult INET: [EMAIL PROTECTED] Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
