Extract texts between []

eduzs

Well-known Member
Joined
Jul 6, 2014
Messages
704
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
I need to extract texts between [] in a string and save in a array:
For example: MyStr = "This is [name] and [number]"
Result array: MyArray = ["name","number"]
Any idea how to to this with vba?
Thanks!
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
VBA Code:
Sub Main()
Results = getBrackets("This is [name] and [number]")
End Sub

Function getBrackets(mySTR As String)
Dim SD As Object:   Set SD = CreateObject("Scripting.Dictionary")

With CreateObject("VBScript.RegExp")
    .Global = True
    .Pattern = "\[(\w+)\]"
    Set matches = .Execute(mySTR)
    For Each m In matches
        SD.Add m.submatches(0), Nothing
    Next m
End With

getBrackets = Application.Transpose(SD.keys())

End Function
 
Upvote 0
Here a variation

VBA Code:
Sub main()
Dim ar
ar = getBrackets("This is [name] and [number]")
End Sub

Function getBrackets(c As String) As Variant
  With CreateObject("vbscript.regexp")
    .Global = True
    .Pattern = "\[(\w+)\]"
    getBrackets = Split(Join(Filter(Split(.Replace(c, "#$1@#"), "#"), "@", 1), ""), "@")
 End With
End Function
 
Upvote 0
Yet another slight variation
Excel Formula:
Sub Between_Brackets()
  Dim MyArray As Variant
  Const MyStr As String = "This is [name] and [number]"
  
  With CreateObject("VBScript.RegExp")
    .Global = True
    .Pattern = "\][^[]*\["
    MyArray = .Replace("]" & MyStr & "[", "]")
    MyArray = Split(Mid(MyArray, 2, Len(MyArray) - 2), "]")
  End With
End Sub
 
Upvote 0
Yet another alternative ;)

VBA Code:
Function SplitBracketedText(InputText As String) As String()
   Dim parts
   parts = Filter(Split(InputText, "["), "]")
   Dim n As Long
   For n = LBound(parts) To UBound(parts)
      parts(n) = Split(parts(n), "]")(0)
   Next n
   SplitBracketedText = parts
End Function
 
Upvote 0
Here a one liner : )

VBA Code:
Function getBrackets(c As String) As Variant
getBrackets = Split(Replace(Replace(Join(Filter(Split(Replace(Replace(c, "[", "@["), "]", "]@"), "@"), "["), "@"), "[", ""), "]", ""), "@")
End Function
 
Upvote 0
This was the fastest version I could come up with.

VBA Code:
Function kk(ByVal s As String)
Dim res() As String
Dim beg As Integer
Dim lst As Integer

ReDim res(1 To Len(s) - Len(Replace(s, "[", "")))

For i = 1 To UBound(res)
    beg = InStr(s, "[") + 1
    lst = InStr(s, "]")
    res(i) = Mid(s, beg, lst - beg)
    s = Right(s, Len(s) - lst)
Next i

kk = res
End Function
 
Upvote 0

Forum statistics

Threads
1,215,174
Messages
6,123,451
Members
449,100
Latest member
sktz

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