List:General Discussion« Previous MessageNext Message »
From:Adam Randall Date:October 12 2007 10:56pm
Subject:Re: Need help with a "natural sort order" for version numbers and release code names
View as plain text  
Here's my full test solution:

use test;

drop table if exists releases;
create temporary table releases
(
	releaseid int(10) unsigned not null auto_increment primary key,
	name varchar(255)
)engine=myisam;

insert into releases ( name ) values
( 'Unspecified' ),
( 'Next Patch' ),
( 'LOCset' ),
( 'Abashiri' ),
( '4.6.0 (Folsom)' ),
( '4.5.9' ),
( '4.5.6' ),
( '4.5.5 (Purdy)' ),
( '4.5.5' ),
( '4.5.4' ),
( '4.5.3' ),
( '4.5.2' ),
( '4.5.10' ),
( '4.5.1 Deferred' ),
( '4.5.1 (Leavenworth)' ),
( '4.2.7.4' ),
( '4.2.7.3' ),
( '4.2.7.2' ),
( '4.2.7.1' ),
( '4.2.7.0' );

select
	releaseid,
	name
from
	releases
order by
	case name
		when 'Unspecified' then 0
		when 'Next Patch' then 1
		when 'LOCset' then 2
		else 10
	end,
	if(
		locate( ' ', name ) > 0 and locate( '.', name ) > 0,
		inet_aton( substr( name, 1, locate( ' ', name ) - 1 ) ),
		if(
			locate( '.', name ) > 0,
			inet_aton( name ),
			4294967295 ) ) desc,
	if(
		locate( ' ', name ) > 0 and locate( '.', name ) > 0,
		replace( replace( substr( name, locate( ' ', name ) + 1 ), '(',  
'' ), ')', '' ),
		if(
			locate( '.', name ) = 0,
			name,
			null ) );

This is the end result after talking to Daevid and finding out what  
the ultimate goal was. I think it's kind of clever myself :)

Yes, there's no possibility of indexing here, but it gets the job done.

Adam.

On Oct 12, 2007, at 12:39 PM, Daevid Vincent wrote:

>
> I'm trying to get some 'release/version numbers' to sort properly.
>
> mysql> SELECT ReleaseID, Name FROM releases ORDER BY Name DESC;
> +-----------+---------------------+
> | ReleaseID | Name                |
> +-----------+---------------------+
> |        18 | Unspecified         |
> |        20 | Next Patch          |
> |        58 | LOCset              |
> |        74 | Abashiri            |
> |        54 | 4.6.0 (Folsom)      |
> 						  <-- 4.5.10 should be here
> |        99 | 4.5.9               |
> |        98 | 4.5.6               |
> |        93 | 4.5.5 (Purdy)       |
> |        97 | 4.5.4               |
> |        96 | 4.5.3               |
> |        94 | 4.5.2               |
> |       100 | 4.5.10              |   <-- should be ^ there
> |        91 | 4.5.1 Deferred      |
> |        78 | 4.5.1 (Leavenworth) |
> |        95 | 4.2.7.4             |
> |        92 | 4.2.7.3             |
> |        90 | 4.2.7.2             |
> |        87 | 4.2.7.1             |
> |        88 | 4.2.7.0             |
>
> I like this order, especially with the top four,
> except for that 4.5.10 should be higher up,
> just under 4.6.0, not under 4.5.2 as it is now.
>
> So I tried the " + 0 " trick which makes things even worse
> (notice the 4.2.6.1 and 4.2.6.0 -- yipes!):
>
> mysql> SELECT ReleaseID, Name FROM releases ORDER BY Name + 0 DESC;
> +-----------+---------------------+
> | ReleaseID | Name                |
> +-----------+---------------------+
> 						 ....(18,20,58,74) are moved
> :(
> |        54 | 4.6.0 (Folsom)      |
> |        78 | 4.5.1 (Leavenworth) |
> |       100 | 4.5.10              |
> |        91 | 4.5.1 Deferred      |
> |        93 | 4.5.5 (Purdy)       |
> |        94 | 4.5.2               |
> |        96 | 4.5.3               |
> |        97 | 4.5.4               |
> |        98 | 4.5.6               |
> |        99 | 4.5.9               |
> |        82 | 4.2.6.1             |  <<  ?
> |        76 | 4.2.2               |
> |        75 | 4.2.4               |
> |        72 | 4.2.1               |
> |        73 | 4.2.3               |
> |        67 | 4.2.6.0             |  <<  ?
>
>
> I'm pretty sure this is going to involve some sort of splitting the  
> version
> from the release codeword via some string functions, and then  
> operating on
> that part.
>
>
> D.Vin
> http://daevid.com
> ---
> eval() is my favorite templating engine.
>
>
>
> -- 
> MySQL General Mailing List
> For list archives: http://lists.mysql.com/mysql
> To unsubscribe:    http://lists.mysql.com/mysql?unsub=1
>


-- 
Adam Randall
randalla@stripped



Thread
Need help with a "natural sort order" for version numbers and release code namesDaevid Vincent12 Oct
  • Re: Need help with a "natural sort order" for version numbers andrelease code namesJay Pipes12 Oct
    • RE: Need help with a "natural sort order" for version numbers and release code namesDaevid Vincent12 Oct
  • Re: Need help with a "natural sort order" for version numbers and release code namesAdam Randall13 Oct
    • Re: Need help with a "natural sort order" for version numbers and release code namesAdam Randall13 Oct