filtering duplicate fields

klimerit

New Member
Joined
Nov 29, 2017
Messages
1
I've got a field in excel which a program spits out the account name and number concatenated.

For example:

abc100
abc200
abc300
defg
defg100
defg200
defg300


There is no standard formatting so the account name, or number don't always contain the same number of characters.

What i'm trying to achieve is removing the account number, and displaying the account name without any duplicates.

Is this possible, considering that formatting is inconsistent?

Thanks!
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Assuming your data is in column A starting in row 2, try this macros and functions. The name will be place in column B and the number in column c.
Code:
Sub SplitVals()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim rng As Range
    For Each rng In Range("A2:A" & LastRow)
        rng.Offset(0, 1) = RetNonNum(rng.Value)
        rng.Offset(0, 2) = RetNum(rng.Value)
    Next rng
    Application.ScreenUpdating = True
End Sub
    
Function RetNum(AnyStr As String)
    Dim RegEx
    Set RegEx = CreateObject("vbscript.regexp")
    With RegEx
        .Global = True
        .Pattern = "[^\d]+"
    End With
    RetNum = RegEx.Replace(AnyStr, "")
    Set RegEx = Nothing
End Function

Function RetNonNum(AnyStr As String)
    Dim RegEx
    Set RegEx = CreateObject("vbscript.regexp")
    With RegEx
        .Global = True
        .Pattern = "[\d]+"
    End With
    RetNonNum = RegEx.Replace(AnyStr, "")
    Set RegEx = Nothing
End Function
Unfortunately, this doesn't remove the duplicate names, though.
 
Last edited:
Upvote 0
Try these. The macros will do the same as described in my previous post but will remove the duplicates in column B.
Code:
Sub SplitVals()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim x As Long
    Dim rng As Range
    For Each rng In Range("A2:A" & LastRow)
        rng.Offset(0, 1) = RetNonNum(rng.Value)
        rng.Offset(0, 2) = RetNum(rng.Value)
    Next rng
    For x = LastRow To 2 Step -1
        If Cells(x, 2) = Cells(x - 1, 2) Then
            Cells(x, 2).ClearContents
        End If
    Next x
    Application.ScreenUpdating = True
End Sub
    
Function RetNum(AnyStr As String)
    Dim RegEx
    Set RegEx = CreateObject("vbscript.regexp")
    With RegEx
        .Global = True
        .Pattern = "[^\d]+"
    End With
    RetNum = RegEx.Replace(AnyStr, "")
    Set RegEx = Nothing
End Function

Function RetNonNum(AnyStr As String)
    Dim RegEx
    Set RegEx = CreateObject("vbscript.regexp")
    With RegEx
        .Global = True
        .Pattern = "[\d]+"
    End With
    RetNonNum = RegEx.Replace(AnyStr, "")
    Set RegEx = Nothing
End Function
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,310
Members
452,634
Latest member
cpostell

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