Find only numerics after a special character and separate with a comma

dkreisb

New Member
Joined
Jul 1, 2014
Messages
7
Hello,

I'm new here, but I have reviewed dozens of responses regarding the title of this post. Unfortunately, I haven't been able to get the results I desire. I am looking for numbers that appear after a special character, I only want to retain those numbers and I want to separate them with a comma. Here are some samples of my data and desired results.

Data:
BIGBOY2;#138;#BIGBOY2SAVE;#2478;#SHARED ENVIRONMENT;#7613
TEA1BAG;#1234;#BIGBOY2;#1388;#SHARED ENVIRONMENT3;#7615
TINCUP;#2;#BIG88BOY;#1233

Desired Results:
138,2478,7613 (notice the number 2 from BIGBOY2 and BIGBOY2SAVE was not retained)
1234,138,7615 (notice the numbers 1, 2 & 3 in TEA1BAG, BIGBOY2 and SHARED ENVIRONMENT3 were not retained)
2,1233 (notice the number 88 in BIG88BOY was not retained)

The numbers following the pound sign could be of length 1-6. I've tried various text clipping functions and UDFs, but I haven't been able to crack it. Thoughts?
 
OK, now I need the opposite. I need to remove all occurrences of the ;# and only the numbers following the ;#. The desired results would be as follows (notice the numbers in the names aren't removed):

BIGBOY2, BIGBOY2SAVE, SHARED ENVIRONMENT
TEA1BAG, BIGBOY2, SHARED ENVIRONMENT3
TINCUP, BIG88BOY
 
Upvote 0

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
You just have to change below code in UDF,

If IsNumeric(Split(sStr, ",")(i)) = False Then
 
Upvote 0
Bingo! I found at least 4 occurrences of the sequence in some of my data, and the UDF worked on those.
Here is another UDF you can consider using...
Code:
Function GetNums(S As String) As String
  Dim X As Long, Hashes() As String
  Hashes = Split(S, "#")
  For X = 1 To UBound(Hashes) Step 2
    GetNums = GetNums & Hashes(X)
  Next
  GetNums = Replace(GetNums, ";", ", ")
End Function
 
Upvote 0
OK, now I need the opposite. I need to remove all occurrences of the ;# and only the numbers following the ;#. The desired results would be as follows (notice the numbers in the names aren't removed):

BIGBOY2, BIGBOY2SAVE, SHARED ENVIRONMENT
TEA1BAG, BIGBOY2, SHARED ENVIRONMENT3
TINCUP, BIG88BOY
This UDF should do that for you...
Code:
Function GetNums(S As String) As String
  Dim X As Long, Hashes() As String
  Hashes = Split(S, "#")
  For X = 0 To UBound(Hashes) - 1 Step 2
    GetNums = GetNums & Hashes(X)
  Next
  GetNums = Replace(GetNums, ";", ", ")
  GetNums = Left(GetNums, Len(GetNums) - 2)
End Function
 
Upvote 0
Here is the Single UDF for both operations,

Suppose you have in A1

BIGBOY2;#138;#BIGBOY2SAVE;#2478;#SHARED ENVIRONMENT;#7613

=SplitData(A1,FALSE) will return BIGBOY2,BIGBOY2SAVE,SHARED ENVIRONMENT

=SplitData(A1,TRUE) will return 138,2478,7613

Code:
Function SplitData(Rng As Range, bVal As Boolean) As String
    Dim Cnt As Integer
    Dim sStr As String
    sStr = Replace(Rng.Value, ";#", ",")
    For i = 0 To UBound(Split(sStr, ","))
        If IsNumeric(Split(sStr, ",")(i)) = bVal Then
            If SplitData = "" Then
                SplitData = Split(sStr, ",")(i)
            Else
                SplitData = SplitData & "," & Split(sStr, ",")(i)
            End If
        End If
    Next i
End Function
 
Upvote 0
Here is the Single UDF for both operations,

Suppose you have in A1

BIGBOY2;#138;#BIGBOY2SAVE;#2478;#SHARED ENVIRONMENT;#7613

=SplitData(A1,FALSE) will return BIGBOY2,BIGBOY2SAVE,SHARED ENVIRONMENT

=SplitData(A1,TRUE) will return 138,2478,7613

Code:
Function SplitData(Rng As Range, bVal As Boolean) As String
    Dim Cnt As Integer
    Dim sStr As String
    sStr = Replace(Rng.Value, ";#", ",")
    For i = 0 To UBound(Split(sStr, ","))
        If IsNumeric(Split(sStr, ",")(i)) = bVal Then
            If SplitData = "" Then
                SplitData = Split(sStr, ",")(i)
            Else
                SplitData = SplitData & "," & Split(sStr, ",")(i)
            End If
        End If
    Next i
End Function

Two points about your code... first, you declare the Cnt variable, but then use I as the loop counter instead; second, I would consider making the name of the second argument more meaningful, for example, changing it to something like GetNumbers would make remembering which Boolean settings to use for it (TRUE or FALSE) easier to remember.
 
Upvote 0
Thanks Rick. I just forgot about Cnt which i would use it for storing Ubound of array sStr. Anyway here is the more corrected version of UDF..

Code:
Function GetNumbers(Rng As Range, bVal As Boolean) As String
    Dim i As Integer
    Dim sStr As String
    sStr = Replace(Rng.Value, ";#", ",")
    For i = 0 To UBound(Split(sStr, ","))
        If IsNumeric(Split(sStr, ",")(i)) = bVal Then
            If SplitData = "" Then
                SplitData = Split(sStr, ",")(i)
            Else
                SplitData = SplitData & "," & Split(sStr, ",")(i)
            End If
        End If
    Next i
End Function
 
Upvote 0

Forum statistics

Threads
1,223,246
Messages
6,170,999
Members
452,373
Latest member
TimReeks

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