I am trying to create a UDF within VBA which go through some function syntax and treat it as Text.
The function will look like :
FunctionA( Param1 , Param2 , Param3 , Param 4 )
I am trying to develop a UDF which will pull out the value of the Param based on the position I input into my UDF function.
GetN( FunctionA , 3 ) = "Param3"
GetN FunctionA , 1 ) = "Param1"
Here's my function so far but it's off....
It's behaving like :
GetN( FunctionA , 0 ) = Param2
Here's my function:
Function GetN(sInputString As String, n As Integer) As String
Dim sFindWhat As String
Dim j, FindA, FindB As Integer
Application.Volatile
sFindWhat = ","
FindA = 0
For j = 0 To n
FindA = InStr(FindA + 1, sInputString, sFindWhat)
FindB = InStr(FindA + 1, sInputString, sFindWhat)
If FindB = 0 Then FindB = InStr(FindA + 1, sInputString, ")")
If FindA = 0 Then Exit For
Next
GetN = Trim(Mid(sInputString, FindA + 1, FindB - FindA - 1))
End Function
Thank you for help
Split
should work, though to correctly handle the case of nested functions, a preliminary hack is to first replace commas at the top level by a safe delimiter (e.g. [[,]]
) and then splitting on that delimiter:
Function GetParameterN(func As String, n As Long) As String
Dim args As Variant
Dim safeArgs As String
Dim c As String
Dim i As Long, pdepth As Long
func = Trim(func)
i = InStr(func, "(")
args = Mid(func, i + 1)
args = Mid(args, 1, Len(args) - 1)
For i = 1 To Len(args)
c = Mid(args, i, 1)
If c = "(" Then
pdepth = pdepth + 1
ElseIf c = ")" Then
pdepth = pdepth - 1
ElseIf c = "," And pdepth = 0 Then
c = "[[,]]"
End If
safeArgs = safeArgs & c
Next i
args = Split(safeArgs, "[[,]]")
GetParameterN = Trim(args(n - 1))
End Function
For example,
Sub test()
Dim i As Long
For i = 1 To 3
Debug.Print GetParameterN("f(x,g(x,y,z),z)", i)
Next i
End Sub
Produces:
x
g(x,y,z)
z
I see no good reason to make this function volatile.