The VBA InStr function is one of the most used functions in VBA. It is used to find a string within a string and indeed it does a very fine job.
However, it is often used to help extract part of a string and for this task it performs badly.
If you have found string extraction in VBA to be a painful process, then read on. This post will show you a simpler and better way using three real world examples!
Contents
- 1 A Quick Guide to this Post
- 2 Quick Reference Notes
- 3 Introduction
- 4 Â When VBA InStr, Left, Right and Mid are useful
- 5 Dealing with Strings of Varying Lengths
- 6 The Split Function
- 7 Example 1: Getting part of a file name
- 8 Example 2: IP Address Range
- 9 Example 3: Check if a filename is valid
- 10 Conclusion
- 11 What’s Next?
A Quick Guide to this Post
The following table provides a quick reference guide to what is covered in this post.
String | Type | Task | How to |
---|---|---|---|
1234ABC334 | Fixed size | get left 4 chars | Left(s,4) |
1234ABC334 | Fixed size | get right 3 chars | Right(s,3) |
1234ABC334 | Fixed size | get chars 5,6,7 | Mid(s,5,3) |
"John Henry Smith" | Variable size | get first name | Split(s," ")(0) |
"John Henry Smith" | Variable size | get second name | Split(s," ")(1) |
"John Henry Smith" | Variable size | get third name | Split(s," ")(2) |
"John Henry Smith" | Variable size | Get last name | Dim v As Variant v = Split(s, " ") lastname= v(UBound(v)) |
Quick Reference Notes
To find out more about the items referenced in the post check out the following links
If you would like to know more about the InStr or InStrRev functions then please read Searching within a string.
If you would like to know more about Mid, Left or Right functions then check out Extracting Part of a String.
For more about the Split function check out String to Array using Split.
The Like operator is covered in Pattern Matching
I use Debug.Print in my examples. It prints values to the Immediate Window which you can view by pressing Ctrl and G (or select View->Immediate Window)
Introduction
In this post, I’m going to show you a better way to extract values from a string than using then VBA InStr function with Left, Right or Mid.
This post is broken down as follows
- Section 1: How to extract from fixed sized strings.
- Section 2: How to extract from variable sized strings.
- Section 3: How to extract from variable sized string using the Split function.
- Sections 4 to 6: Some real world examples.
 When VBA InStr, Left, Right and Mid are useful
If you want to check if a string contains a value then InStr is fine for the job. If you want to do a simple extraction then Left, Right and Mid also fine to use.
Using InStr to check if string contains text
In the following example, we check if the name contains “Henry”. If the return value of InStr is greater than zero then the string contains the value we are checking for.
' Check if string contains Henry If InStr("John Henry Smith", "Henry") > 0 Then Debug.Print "Found" End If
Extracting with Left, Right and Mid
The Left function is used to get characters from the left of a string.
The Right function is used to get characters from the right of a string.
The Mid function is used for the middle of the string. It is the same as Left except that you give it a starting position.
' https://excelmacromastery.com/ Sub ExtractString() Dim s As String: s = "ABCD-7789.WXYZ" Debug.Print Left(s, 2) ' Prints AB Debug.Print Left(s, 4) ' Prints ABCD Debug.Print Right(s, 2) ' Prints YZ Debug.Print Right(s, 4) ' Prints WXYZ Debug.Print Mid(s, 1, 2) ' Prints AB Debug.Print Mid(s, 6, 4) ' Prints 7789 End Sub
These three functions work fine if the text you require is always the same size and in the same place. For other scenarios, they require the use of InStr to find a particular position in the string. This makes using them complicated.
Use Left, Right or Mid when the characters will always be in the same position. |
Dealing with Strings of Varying Lengths
Many of the strings you will deal with will be of different lengths. A simple example is when you are dealing with a list of names. The string length and part you require(e.g. the first name) may be of different each time. For example
Brooke Hilt
Pamela Jurado
Zack Kinzel
Eddy Wormley
Kaitlyn Rainer
Jacque Trickett
Kandra Stanbery
Margo Hoppes
Berenice Meier
Garrett Hyre
Using the VBA InStr Function with Left
In the following example, we are going to get the first name from a string. In this string the first name is the name before the first space.
We use the VBA InStr function to get the position of the first space. We want to get all the characters before the space. We subtract one from the position as this gives us the position of the last letter of the name.
' https://excelmacromastery.com/ Sub GetFirstname() Dim s As String, lPosition As Long s = "John Henry Smith" ' Prints John lPosition = InStr(s, " ") - 1 Debug.Print Left(s, lPosition) s = "Lorraine Huggard" ' Prints Lorraine lPosition = InStr(s, " ") - 1 Debug.Print Left(s, lPosition) End Sub
Let’s look at the first example in the above code. The first space is at position 5. We substract 1 so which gives us position 4. This is the position of the last letter of John i.e.n.
We then give 4 to the Left function and it returns the first four characters e.g.  “John”
We can perform the same task in one line by passing the return value from InStr to the Left function.
Dim s As String s = "John Henry Smith" ' Prints John Debug.Print Left(s, InStr(s, " ") - 1)
Using the VBA InStr Function with Right
In this example, we will get the last word in the string i.e. Smith. We can use the InStrRev function to help us. This is the same as InStr except it searches from the end of the string.
It’s important to note that InStrRev gives us the position from the start of the string . Therefore, we need to use it slightly differently than we used InStr and Left.
' https://excelmacromastery.com/ Sub GetLastName() Dim s As String: s = "John,Henry,Smith" Dim Position As Long, Length As Long Position = InStrRev(s, ",") Length = Len(s) ' Prints Smith Debug.Print Right(s, Length - Position) ' Alternative method. Prints Smith - do in one line Debug.Print Right(s, Len(s) - InStrRev(s, ",")) End Sub
How this the above example works
- We get the position of the last space using InStrRev: 11
- We get the length of the string: 16.
- We subtract the position from the length: 16-11=5
- We give 5 to the Right function and get back Smith
Using the VBA InStr Function with Mid
In the next example, we will get “Henry” from the string. The word we are looking for is between the first and second space.
We will use the Mid function here.
' https://excelmacromastery.com/ Sub GetSecondName() Dim s As String: s = "John Henry Smith" Dim firstChar As Long, secondChar As Long Dim count As Long ' Find space position plus 1. Result is 6 firstChar = InStr(s, " ") + 1 ' find 2nd space position. Result is 11 secondChar = InStr(firstChar, s, " ") ' Get numbers of characters. Result is 5 count = secondChar - firstChar ' Prints Henry Debug.Print Mid(s, firstChar, count) End Sub
You can see this is tricky to do and requires a bit of effort to figure out. We need to find the first space. Then we need to find the second space. Then we have to substract one from the other to give us the number of characters to take.
If have a string with a lot of words then this can get very tricky indeed. Luckily for us there is a much easier was to extract characters from a string. It’s called the Split function.
The Split Function
We can use the Split function to perform the above examples. The Split function splits a string into an array. Then we can easily access each individual item.
Let’s try the same three examples again and this time we will use Split.
Dim s As String: s = "John Henry Smith" Debug.Print Split(s, " ")(0) ' John Debug.Print Split(s, " ")(1) ' Henry Debug.Print Split(s, " ")(2) ' Smith
Boom! What a difference using Split makes. The way it works is as follows
- The Split function splits the string wherever there is a space.
- Each item goes into an array location starting at location zero.
- Using  the number of a location  we can access an array item.
The following table shows what the array might look like after Split has been used.
Note: the first position in the array  is zero. Having zero based arrays is standard in programming languages.
0 | 1 | 2 |
---|---|---|
John | Henry | Smith |
In the above code we split the string each time we used it. We could also split the string once and store it in an array variable. Then we can access it when we want.
' https://excelmacromastery.com/ Sub SplitName() Dim s As String: s = "John Henry Smith" Dim arr() As String arr = Split(s, " ") Debug.Print arr(0) ' John Debug.Print arr(1) ' Henry Debug.Print arr(2) ' Smith End Sub
If you would like to know more about arrays then I wrote an entire post about them called The Complete Guide to Using Arrays in Excel VBA.
In the next sections, we will look at some real-world examples. You will see the benefit of using Split instead of the InStr function.
Please feel free to try these yourself first. It is a great way to learn and you may have fun trying to figure them out(or maybe that’s just me!)
Example 1: Getting part of a file name
Imagine we want to extract the numbers from the following filenames
“VB_23476_Val.xls”
“VV_987_Val.txt”
“VZZA_12223_Val.doc”
This is similar to the example of where we get the second item. To get the values here we use the underscore(i.e. “_”) to split the string. See the code example below
' https://excelmacromastery.com/ Sub GetNumber() ' Prints 23476 Debug.Print Split("VB_23476_Val.xls", "_")(1) ' Prints 987 Debug.Print Split("VV_987_Val.txt", "_")(1) ' Prints 12223 Debug.Print Split("ABBZA_12223_Val.doc", "_")(1) End Sub
In the real world you would normally read strings like these from a range of cells. So let’s say these filenames are stored in cells A1 to A3. We will adjust the code above slightly to give us:
' https://excelmacromastery.com/ Sub ReadNumber() Dim c As Range For Each c In Range("A1:A3") ' Split each item as you read it Debug.Print Split(c, "_")(1) Next c End Sub
Example 2: IP Address Range
The example here is taken from a question on the StackOverflow website.
The user has a string with an IP address in the format “BE-ABCDDD-DDS 172.16.23.3”.
He wants an IP of the range 172.16 to 172.31 to be valid. So for example
“BE-ABCDDD-DDS 172.16.23.3″ is valid
“BE-ABCDDD-DDS 172.25.23.3″ is valid
“BE-ABCDDED-DDS 172.14.23.3″ is not valid
“BE-ABCDDDZZ-DDS 172.32.23.3″ is not valid
This is how I would do this. First I split the string by the periods. The number we are looking for is between the first and second period. Therefore, it is the second item. When we split the string it is placed at position one in the array (remember that the array starts at position zero).
The resulting array will look like this
0 | 1 | 2 | 3 |
---|---|---|---|
BE-ABCDDD-DDS 172 | 31 | 23 | 3 |
The code below shows how to do this
' https://excelmacromastery.com/ Sub IPAdd() ' Check the number to test different ip addresses Dim s1 As String: s1 = "BE-ABCDDD-DDS 172.31.23.3" ' Split the string using the period symbol Dim num As Long num = Split(s1, ".")(1) ' Check the number is valid Debug.Print num >= 16 And num <= 31 End Sub
Example 3: Check if a filename is valid
In this final example, we want to check that a file name is valid. There are three rules
- It must end with .pdf
- It must contain AA
- It must contain 1234 after AA
The following tables shows some valid and invalid items
Filename | Status |
---|---|
AA1234.pdf | valid |
AA_ljgslf_1234.pdf | valid |
AA1234.pdf1 | Not valid - doesn't end with .pdf |
1234 AA.pdf | Not valid - AA does not come before 1234 |
12_AA_1234_NM.pdf | Valid |
First we will do this using the InStr and Right functions.
' https://excelmacromastery.com/ Sub UseInstr() Dim f As String: f = "AA_1234_(5).pdf" ' Find AA first as the 1234 must come after this Dim lPos As Long: lPos = InStr(f, "AA") ' Search for 1234 and ensure last four chars are .pdf Debug.Print InStr(lPos, f, "1234") > 0 And Right(f, 4) = ".pdf" End Sub
This code is very messy. Luckily for us, VBA has Pattern Matching. We can check the pattern of a string without having to search for items and positions etc. We use the Like operator in VBA for pattern matching. The example below shows how to do it.
' https://excelmacromastery.com/ Sub UsePattern() Dim f As String: f = "AA_1234_(5).pdf" ' Define the pattern Dim pattern As String: pattern = "*AA*1234*.pdf" ' Check each item against the pattern Debug.Print f Like pattern ' True End Sub
In the above example, the asterisk in the pattern refers to any number of characters.
Let’s break down this pattern *AA*1234*.pdf
* – Â any group of characters
AA – Â the exact characters AA
* – Â any group of characters
1234 – the exact characters 1234
* – Â any group of characters
.pdf – the exact characters .pdf
To show this works correctly, let’s try it on all the example names in the table
' https://excelmacromastery.com/ Sub UsePatternTest() ' Create a collection of file names Dim coll As New Collection coll.Add "AA1234.pdf" coll.Add "AA_ljgslf_1234.pdf" coll.Add "AA1234.pdf1" coll.Add "1234 AA.pdf" coll.Add "12_AA_1234_NM.pdf" ' Define the pattern Dim pattern As String: pattern = "*AA*1234*.pdf" ' Check each item against the pattern Dim f As Variant For Each f In coll Debug.Print f Like pattern Next f End Sub
The output is
True
True
False
False
True
To find out more about Pattern Matching and the Like keyword please check out this post.
Conclusion
InStr and InStrRev are really only useful for simple tasks like checking if text exists in a string.
Left, Right and Mid are useful when the position of the text is always the same.
The Split function is the best way to extract from a variable string.
When trying to check the format of a string that is not fixed in size, the Like keyword(i.e. Pattern Matching) will generally provide an easier solution.
What’s Next?
Free VBA Tutorial If you are new to VBA or you want to sharpen your existing VBA skills then why not try out the The Ultimate VBA Tutorial.
Related Training: Get full access to the Excel VBA training webinars and all the tutorials.
(NOTE: Planning to build or manage a VBA Application? Learn how to build 10 Excel VBA applications from scratch.)
If you are serious about mastering VBA then you may want to check out The Excel VBA Handbook
Hallo Paul,
what a great post about this problem.
I learned a lot this.
Now I will use cost of subscription with RSS.
Greatings
Gerhard
Thanks Gerhard, Glad you found it useful.
Paul
Hey, John here whatever you shared online its really great
Not only for vba programmers but also non vba programmers
I really thank you to for such great work you have done
Thanks John, glad you like it.
Regards
Paul
Extraordinary resource – clearly written and on point.
I today incorporated your Split approach in a previous function that had used InStr. Function is repeatedly called, however, and I am curious if there is any need to clear the identical array created in Split after each use. Cannot find a name associated with array created in Split. (Assume name would be necessary for using Erase).
Hi Bruce,
That’s a good question.
If you are using a large number of items then it is a good idea to do this
The following code is from the split section
This code uses Split once and stores the result to an array.
[sourcecode language=”vb”]
Sub SplitName()
Dim s As String: s = "John Henry Smith"
Dim arr() As String
arr = Split(s, " ")
Debug.Print arr(0) ‘ John
Debug.Print arr(1) ‘ Henry
Debug.Print arr(2) ‘ Smith
End Sub
[/sourcecode]
Imagine we were reading a large number of items e.g. the range A1 to A5000. Then we should use erase each time we finish with the array. The following code shows an example
[sourcecode language=”vb”]
Sub SplitNameWithErase()
Dim s As String
Dim arr() As String
Dim c As Range
For Each c In Range("A1:A5000")
arr = Split(c, " ")
Debug.Print arr(0) ‘ first name
Debug.Print arr(1) ‘ second name
Debug.Print arr(2) ‘ surname
Erase arr
Next c
End Sub
[/sourcecode]
This is awesome. In the <> work great, but how can the result be written in the worksheet?
Sub SplitNameWithErase()
Dim ws As Worksheet
Set ws = ThisWorkbook.Worksheets(“sheet1”)
Const columIndex As Integer = 1
Dim arrRng As Range
Set arrRng = ws.Range(“A1”, Range(“A1″).End(xlDown))
Dim c As Range
Dim arr() As String
Dim i As Integer
For Each c In arrRng
arr = Split(c, ” “)
For i = LBound(arr) To UBound(arr)
c.Offset(0, i + columIndex).Value = arr(i)
Next i
Erase arr
Next c
End Sub
HI Paul,
Paul,
This site is a great resource. I appreciate your work and I’m glad I stumbled across it.
Using the SPLIT technique (which is awesome) how do you extract just the first name from a list of names that may or may not have last or middle names? I’ve got a worksheet containing a list of contact names that is edited by several people. Some names have only a first name. Some have first and last and a few have first, middle and last.
Hi Jim,
Glad you like the site. If the first name is the first word then it will always be at position 0. For example to read all the first names from cell A1 to A5.
[sourcecode language=”vb”]
Dim c As Range, arr As Variant
For Each c In Sheet1.Range("A1:A5")
arr = Split(c, " ")
Debug.Print arr(0)
Next c
[/sourcecode]
Paul, really great post. I have used the InStr with Mid method for a long time, and never thought of using split like this. Also you have a great site here with a lot of great information. Thanks!
You’re welcome David.
Very nicely done! You saved my life and lots of time. Kudos for a great article!
Hi Paul,
Good post again!
The result of your Sub UsePattern should be True instead of False
Thanks Dany, I updated the code.
I need to check a specific text in website and print the result if it matches the whole word.
FOR EXAMPLE
i need to check “red” in aaaaaa.com and print only if red is present. i used INSTR but it scrapes from the word occured ,undelivered,semiretired,unchartered,unconquered…..
You can using pattern matching with the Like operator.
Hi Paul
I Have an Excel Database of nearly 4,500 songs of the 60’s, 70’s, 80’s and 90’s, chronologically and alphabetically sorted as are the mp3 files, eg…
c:\Music Collection\2 – SEVENTIES\1974\74 – Billy Preston – Nothing From Nothing.mp3
I can currently parse the above through to the Windows Object library, but only one mp3 at a time.
I’ve tried to use ‘Collections’ to parse multiple mp3’s to no avail. an multiple mp3’s be parsed through to Media Player? Will Arrays work.
Below is my code. (Please forgive me, but I am only a beginner, but quickly turning into a VBA addict).
If you coild help me overcome this hurdle, I’d be most appreciative.
Cheers
Geoff
Sub PlaySong()
Dim DriveName, FullPathSongTitle, Decade, Year, HalfYear, Artist, Song, Answer, CurrentCell, MP3_Title As String
On Error Resume Next
Application.ScreenUpdating = False
CurrentCell = ActiveCell.Address
Range(“A” & ActiveCell.Row).Offset(0, 5).Select
DriveName = Range(“L3”).Text
Select Case (Mid(ActiveCell.Offset(0, 1), 3, 1))
Case Is = 5, 6: Decade = “1 – SIXTIES”
Case Is = 7: Decade = “2 – SEVENTIES”
Case Is = 8: Decade = “3 – EIGHTIES”
Case Is = 9: Decade = “4 – NINETIES”
End Select
Year = ActiveCell.Offset(0, 1).Value: If Year < 1960 Then Year = 1950
HalfYear = Right(ActiveCell.Offset(0, 1), 2)
Artist = ActiveCell.Offset(0, -1).Value
Song = ActiveCell.Value
MP3_Title = HalfYear & " – " & Artist & " – " & Song & ".mp3"
FullPathSongTitle = DriveName & "\" & Decade & "\" & Year & "\" & MP3_Title
ActiveSheet.OLEObjects.Add(Filename:=FullPathSongTitle, Link:=True).Select
If Err.Number 0 Then
msgbox “Cannot Locate…” & vbNewLine & FullPathSongTitle, vbExclamation, ” ERROR!”
Range(CurrentCell).Select
Exit Sub
End If
Selection.Verb: Selection.Delete
Range(CurrentCell).Select
End Sub
This example does something very similar to what you are doing.
Outstanding resource… this page has quickly become a “go to” for understanding VBA principles. Rarely do you find explanations that are clear enough that they make sense to someone that doesn’t specialize in this field.
Thank you for all your efforts Paul! Keep up the fantastic work!
Thanks Richard.
a space is the default split character. therefore split(s,” “) is the same as split(s).
Hi Paul, very good learning from your post.
Thanks Dinesh
Hi Paul,
You have a lot of great information here. What if you are trying to find the set up numbers in a text string that are in groups in 2-3 locations? i.e. “This is 33D54=7500 to finish”. I need to split these up into 3 sets of numbers.
Thanks for any help.
Hi Michael. I wounder what Paul would recommend. I’d do it the following way:
Use ASCII codes to distinguish between numeric and non-numeric chars
https://www.ascii-code.com/
1) Go through the string and replace all the chars out of the ASCII range [48:57] with particular symbol e.g. “|”
2) In case it can be more than 1 non-numeric char between your numbers – replace all “||” with “|”
3) use Split function with “|” as the splitter
Thank you very much, this is really great