Rank order a sequence of numbers WITHIN A CELL

xmbwd

New Member
Joined
Sep 15, 2006
Messages
5
I have a series of numbers inside a cell that are not in order.
For example:

[33, 22, 2, 9, 1, 45].

Is there any way (other than simply retyping the numbers) to automatically reorder the numbers so that they are listed sequentially??

The result would look like this (again, inside a single cell):

[1, 2, 9, 22, 33, 45]

Although these numbers are in one cell, I have the same issue with thousands of cells, so retyping is not an option.

Thanks so much for any help.
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Hi
Paste the code onto Standard module and use in cell like

=OrderNum(A1,",")
Code:
Function OrderNum(txt As String,delim As String) As String
Dim x
x = Split(Replace(txt,Chr(32),""),delim)
SortA x, 0, UBound(x)
OrderNum = Join(x,delim & Chr(32))
End Function

Sub SortA(ary, LB, UB)
Dim M As Variant, temp, i As Long, ii As Long
i = UB : ii = LB
M = ary(Int((LB + UB) / 2))
Do While ii <= i
      Do While ary(ii) < M
            ii = ii + 1
      Loop
      Do While ary(i) > M
           i = i - 1
      Loop
      If ii <= i Then
           temp = ary(ii) : ary(ii) = ary(i) : ary(i) = temp
           ii = ii + 1 : i = i - 1
      End If
Loop
If LB < i Then SortA ary, LB, i
If ii < UB Then SortA ary, ii, UB
End Sub
 
Upvote 0
Thanks, jindon, for the great code. I haven't had a chance to implement it yet, but I will in the morning.

Quick question: will your code work for a cell with a varying set of numbers? For example, a column of three cells might have [3, 35, 44, 33, 8] and the next [4, 33, 2] and the next [3, 35].

Thanks again.
 
Upvote 0
I tried the code and it works, sort of.

Here is the problem. It rank orders as if the number 12 follows the number 1 before the number 2 does.

That is, the module is using the first digit in any number as the sorter, rather than the number itself. Below is an example of how it is sorting, with a before column and an after column.

Before
25, 17, 33, 3, 5
25, 17, 27, 2, 3
25, 17, 27, 2, 3, 5

After Code
17, 25, 3, 33, 5
17, 2, 25, 27, 3
17, 2, 25, 27, 3, 5

Is this a problem with it being in text rather than numbers?

If anyone has a solution, please share. :) :)

Thanks again jindon and agihcam. - M.
 
Upvote 0
xmbwd

The reason is probably because the values are getting treated as text rather than numbers.

I've altered Jindon's code slightly.
Code:
Sub SortA(ary, LB, UB)
Dim M As Variant, temp, i As Long, ii As Long
    i = UB: ii = LB
    M = Val(ary(Int((LB + UB) / 2)))
    Do While ii <= i
          Do While Val(ary(ii)) < M
                ii = ii + 1
          Loop
          Do While Val(ary(i)) > M
               i = i - 1
          Loop
          If ii <= i Then
               temp = ary(ii): ary(ii) = ary(i): ary(i) = temp
               ii = ii + 1: i = i - 1
          End If
    Loop
    If LB < i Then SortA ary, LB, i
    If ii < UB Then SortA ary, ii, UB
End Sub
This gives the following results, is that what you expected/required?

3, 5, 17, 25, 33
2, 3, 17, 25, 27
2, 3, 5, 17, 25, 27

Jindon

Hope you don't mind me altering your code.:)

By the way what type of sort is that?

I seem to vaguely recognise it from university, but that was a long time ago.
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,207
Members
448,554
Latest member
Gleisner2

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top