VBA code to extract groups of numbers from strings

surya80

New Member
Joined
Feb 12, 2020
Messages
5
Office Version
  1. 2016
Platform
  1. Windows
Hello I've been trying to clean some data in cells and format the strings in a specific way e.g.

Input:
abcdef1234ghij5678klmn

Required format of string:
Part-1234, Section-5678

The sequence of letters preceding, in between and following the numeric digits can be of variable length and may include alphabets, spaces, hyphens, commas, periods and slashes ( "/" or "\" )

I'm just quite a novice in VBA programming I just don't know enough of it to get my head around this problem.
Thank you for any help and guidance towards solving this.
 
Nice one Juddaaaa. One small point - my (long-winded) solution returns a 0 if too large a group number is chosen, yours throws a #value! error.
Easily fixed ;)
VBA Code:
Function GetNumber(Inp As String, Pos As Integer) As Variant
    Dim matches As Object
    
    With CreateObject("VBScript.RegExp")
        .Pattern = "\d+"
        .Global = True
        .MultiLine = True
        Set matches = .Execute(Inp)
    End With
    
    If Pos > matches.Count Or Pos < 1 Then
        GetNumber = 0
        Exit Function
    End If
    
    GetNumber = matches(Pos - 1)
End Function
 
Upvote 0

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
Easily fixed ;)
VBA Code:
Function GetNumber(Inp As String, Pos As Integer) As Variant
    Dim matches As Object
   
    With CreateObject("VBScript.RegExp")
        .Pattern = "\d+"
        .Global = True
        .MultiLine = True
        Set matches = .Execute(Inp)
    End With
   
    If Pos > matches.Count Or Pos < 1 Then
        GetNumber = 0
        Exit Function
    End If
   
    GetNumber = matches(Pos - 1)
End Function
Thanks for this pretty elegant solution :)
 
Upvote 0

Forum statistics

Threads
1,223,977
Messages
6,175,753
Members
452,667
Latest member
vanessavalentino83

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