Hi, John:
Sorry to be so tardy in getting back to you. I guess I missed your message
on Monday.
You have a couple of problems here.
1. The line
Option Explicit
must occur at the very top of the module, outside of any Sub/End Sub or
Function/End Function block.
2. You can't nest one procedure inside another. Remove the lines
Sub NoDupes()
at the very top and
End Sub
at the very bottom.
3. If you want to change the name of the function that I wrote, you can
change BOTH occurrences of RemoveDuplicatesAndSort to something else, i.e.
maybe what you want is the modification I've made below.
To use the *function* NoDupes in a formula in a worksheet cell, the syntax
is =NoDupes(A1), where A1 is the cell containing the original text.
If you want a Sub procedure that will change the data in-place, you could do
it by selecting the cells in question, then running the new sub,
RemoveDupes, that I added.
BTW, this code requires Excel 2000 or later (the Split and Join functions
were added then). It won't run in XL97.
Option Explicit
Function NoDupes(sText As String) As String
Dim a() As String
Dim b() As String
Dim i As Long
Dim j As Long
a = Split(sText, ",")
ReDim b(0 To UBound(a))
b(0) = a(0)
'transfer unique entries from a() to b()
j = 0
For i = 1 To UBound(a)
If IsError(Application.Match(a(i), b(), 0)) Then
j = j + 1
b(j) = a(i)
End If
Next i
ReDim Preserve b(0 To j)
SortStrings b()
NoDupes = Join(b, ",")
End Function
Sub RemoveDupes()
Dim SaveCalc As Long
Dim Cell As Range
With Application
.ScreenUpdating = False
SaveCalc = .Calculation
.Calculation = xlCalculationManual
End With
For Each Cell In Selection
Cell.Value = NoDupes(Cell.Value)
Next Cell
With Application
.ScreenUpdating = True
.Calculation = SaveCalc
End With
End Sub
Sub SortStrings(sArray() As String)
Dim i As Long
Dim j As Long
Dim Lo As Long
Dim Hi As Long
Dim sTemp As String
Lo = LBound(sArray())
Hi = UBound(sArray())
For i = Lo + 1 To Hi
sTemp = sArray(i)
For j = i - 1 To Lo Step -1
If sArray(j) > sTemp Then
sArray(j + 1) = sArray(j)
Else
Exit For
End If
Next j
sArray(j + 1) = sTemp
Next i
End Sub 'SortStrings