Results 1 to 5 of 5
  1. #1
    Star Lounger
    Join Date
    Feb 2003
    Location
    near Blairgowrie, Perthshire, Scotland
    Posts
    72
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Excel string function (2000 upwards)

    Tell me I'm not taking a sledgehammer to crack the proverbial nut. I have been asked for the best means of splitting up a string based on the last occurrence of a specified character in it, for example, 'John Edward Brown' to be split into forenames and surname by checking for the last space. I have the uncomfortable feeling there's an easier way, although I can't find it in any threads. So I wrote the function below, based on the assumption that the string to contain the last bit of the string is in the same row as the full name. It can also cope with strings not containing the specified character. The function goes like this, assuming you enter it in J3, the search is for the last space and the full string is in H3:

    =findright(" ",-3)

    Function findright(findstring, location) As String

    Dim thiscell As Range
    Dim contents As String
    Dim righthandbit As String
    Dim count As Integer

    For Each thiscell In Selection
    contents = thiscell.Offset(0, location)
    contentslength = Len(contents)
    For count = contentslength To 1 Step -1
    If Mid(contents, count, 1) = findstring Then
    contents = Right(contents, contentslength - count)
    findright = contents
    Exit Function
    End If

    Next count

    Next thiscell

    End Function


    Any ideas, please?

    Rex Last

  2. #2
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts

    Re: Excel string function (2000 upwards)

    You can do it with formulas using something like:
    <code>=MID(A2,SEARCH("#",SUBSTITUTE(A2," ","#",LEN(A2)-LEN(SUBSTITUTE(A2," ",""))))+1,LEN(A2))</code>
    or in VBA:
    <pre>Function GetLast(strDelim as String, rngInput as Range) As String
    Dim varData
    varData = Split(rngInput.Value, strDelim)
    GetLast = varData(Ubound(varData))
    End Function
    </pre>

    Called using <code>=GetLast(" ",A1)</code>

    HTH
    Regards,
    Rory

    Microsoft MVP - Excel

  3. #3
    Platinum Lounger
    Join Date
    Jan 2001
    Posts
    3,788
    Thanks
    0
    Thanked 1 Time in 1 Post

    Re: Excel string function (2000 upwards)

    It can be done without using VBA. The following comes from a John Walkenbach book.

    <code>=RIGHT(A1,LEN(A1)-FIND("*",SUBSTITUTE(A1," ","*",LEN(A1)-LEN(SUBSTITUTE(A1," ","")))))</code>

    It will fail if the sting you are checking contains an asterisk.

  4. #4
    Star Lounger
    Join Date
    Feb 2003
    Location
    near Blairgowrie, Perthshire, Scotland
    Posts
    72
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Excel string function (2000 upwards)

    Thanks a lot. That's a sharper approach. I knew there had to be a better way...

    Rex Last

  5. #5
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts

    Re: Excel string function (2000 upwards)

    Incidentally, if you are writing a function and need to refer to the cell the function is in, you should use <code>Application.Caller</code> or <code>Application.ThisCell</code> rather than <code>Selection</code> as the selected cell may not be the one with the function in!
    Regards,
    Rory

    Microsoft MVP - Excel

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •