MySQL Forums
Forum List  »  Newbie

Re: "Natural" Sort
Posted by: Chris Stubben
Date: July 25, 2005 01:18PM

So here's one way to sort alphanumeric values without a delimiter - I'm not sure if it's the best.


drop table tmp;
create table tmp (name char(10));
insert into tmp values ('AIYC1'), ('AIYC10'), ('AIYC2'), ('ABC1'), ('ABC2'), ('ABC10'), ('ABC30');
insert into tmp values ('tmp.10'), ('tmp.3'), ('emp-22'),('emp-7'),('emp-6a'),('emp-6b'),(45),(7);

--check the maximum length of the field

select max(length(name)) from tmp;

-- and then write a conditional up to that number


select name from tmp
ORDER BY left(name,
(CASE when substr(name,1) between '0' and '9' then 1
when substr(name,2) between '0' and '9' then 2
when substr(name,3) between '0' and '9' then 3
when substr(name,4) between '0' and '9' then 4
when substr(name,5) between '0' and '9' then 5 ELSE 6 end)-1),
0+substr(name,
CASE when substr(name,1) between '0' and '9' then 1
when substr(name,2) between '0' and '9' then 2
when substr(name,3) between '0' and '9' then 3
when substr(name,4) between '0' and '9' then 4
when substr(name,5) between '0' and '9' then 5 ELSE 6 end);

+--------+
| name |
+--------+
| 7 |
| 45 |
| ABC1 |
| ABC2 |
| ABC10 |
| ABC30 |
| AIYC1 |
| AIYC2 |
| AIYC10 |
| emp-6a |
| emp-6b |
| emp-7 |
| emp-22 |
| tmp.3 |
| tmp.10 |
+--------+



Chris

Options: ReplyQuote


Subject
Written By
Posted
July 18, 2005 12:42PM
July 18, 2005 04:12PM
July 19, 2005 07:41AM
July 19, 2005 12:16PM
July 19, 2005 12:59PM
July 19, 2005 02:03PM
July 19, 2005 07:40PM
July 19, 2005 07:48PM
July 19, 2005 08:37PM
July 22, 2005 07:48AM
July 22, 2005 06:23PM
July 25, 2005 06:56AM
Re: "Natural" Sort
July 25, 2005 01:18PM


Sorry, you can't reply to this topic. It has been closed.

Content reproduced on this site is the property of the respective copyright holders. It is not reviewed in advance by Oracle and does not necessarily represent the opinion of Oracle or any other party.