Sort number data within a cell

sscls

New Member
Joined
Oct 26, 2011
Messages
3
[h=2]Sorting Data (Numbers) Within a Single Cell[/h]
I'm using a spreadsheet to input a series of digits into a particular cell. I want to be able to use formula 。
For example, I input the numbers: 21, 10, 37, 2, 5, 44 into cell A1; the numbers will be separted by a space not a comma (,).
After formula, cell B2 (or whatever cell) should show: 2 5 10 21 37 44. Please help!

if I input the numbers: 21,21, 10, 37, 2, 2,5, 44,37 into cell A1, the B1 should also cannot duplicated ,so should still be 2 5 10 21 37 44


Regards.

i use the url https://www.ozgrid.com/forum/forum/...298-sorting-data-numbers-within-a-single-cell
but the different is
1.to Remove duplicate numbers
2.use real formula not vba
3.if use VBA how to?
thanks a lot
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Here is a VBA solution... it is a UDF (user defined function)... see installation instructions below:
Code:
Function SortNumbers(Text As String) As String
  Dim X As Long, Max As Long, Data As Variant
  Text = Replace(Application.Trim(Replace(Text, ",", " ")), " ", ",")
  Max = Evaluate("MAX(" & Text & ")")
  Data = Split(Text, ",")
  With CreateObject("System.Collections.ArrayList")
    For X = 0 To UBound(Data)
      .Add Application.Trim(Format(Data(X), String(Len(Max), "0")))
    Next
    .Sort
    Data = .ToArray
  End With
  With CreateObject("Scripting.Dictionary")
    For X = 0 To UBound(Data)
      .Item(CLng(Data(X))) = 1
    Next
    SortNumbers = Join(.keys)
  End With
End Function

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use SortNumbers just like it was a built-in Excel function. For example, if cell A1 contains your number list, then put this in cell B1...

=SortNumbers(A1)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
Just another UDF

Code:
Function Sorting_Num(r As Range)
    Dim n As New Collection, e As Boolean, cad As String, i As Long, c As Variant
    On Error Resume Next
    For Each c In Application.Trim(Split(r.Value, ","))
        e = False
        For i = 1 To n.Count
            If Val(c) < n(i) Then n.Add Val(c), c, i: e = True
        Next
        If e = False Then n.Add Val(c), c
    Next
    For i = 1 To n.Count
        cad = cad & n(i) & " "
    Next
    Sorting_Num = Left(cad, Len(cad) - 1)
End Function
 
Upvote 0
Yet another way.

Code:
Function Sorted(val As String) As String
val = Replace(val, " ", "")
Dim s() As String: s = Split(val, ",")
Dim AL As Object: Set AL = CreateObject("System.Collections.ArrayList")
Dim tmp As Long

For i = LBound(s) To UBound(s)
    tmp = s(i)
    If Not AL.contains(tmp) Then AL.Add tmp
Next i

AL.Sort
Sorted = Join(AL.toArray, " ")

End Function
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,557
Latest member
richa mishra

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