XL: How to Return the Nth Word from a String

ID: Q152568


The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows
  • Microsoft Excel 98 Macintosh Edition


SUMMARY

This article contains a sample Microsoft Visual Basic for Applications function that extracts a particular word from a sentence.


MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft Support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

http://www.microsoft.com/support/supportnet/overview/overview.asp

To Create the Custom Function

Type the following in a new Visual Basic module:

    Function FindNthWord(WordStrg As Variant, occur)
       ' Declare variables where WordStrg is the string whose Nth word you
       ' want to extract and occur is the number of the word (or Nth word)
       ' you want to extract from the string.
       Dim y, z As Integer
       Dim WordSearch()

       y = (Len(WordStrg) - (Len(Application.Substitute(WordStrg, " ", _
           "")))) / 1
       ReDim WordSearch(1 To (y + 1))
       z = 1
       For SearchLoop = 1 To y
           z = (InStr(z, WordStrg, " "))
           WordSearch(SearchLoop) = Left(WordStrg, z)
           WordStrg = Application.Trim(Mid(WordStrg, z + 1))
           z = 1
       Next SearchLoop
       WordSearch(y + 1) = WordStrg
       ' Assigns the result to the function.
       FindNthWord = WordSearch(occur)
   End Function 

To Use the Custom Function

  1. Enter the following in a worksheet:
    
          A1: For a comparison of Dow Jones               B1:
          A2: Industrial Averages and the price of this   B2:
          A3: stock over the same quarter, refer to the   B3:
          A4: next section of the worksheet.              B4: 


  2. Type the following formula in cell B1:
    B1: =FindNthWord(A1,2)


  3. With cell B1 selected, grab the fill handle and fill the formula down through cell B4.


  4. The resulting worksheet looks like this:
    
          A1: For a comparison of Dow Jones               B1: a
          A2: Industrial Averages and the price of this   B2: Averages
          A3: stock over the same quarter, refer to the   B3: over
          A4: next section of the worksheet.              B4: section 



REFERENCES

For more information about the InStr function in Microsoft Excel 97, from the Visual Basic Editor, click the Office Assistant, type InStr, click Search, and then click to view "InStr Function."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If the Assistant is not able to answer your query, please see the following article in the Microsoft Knowledge Base:

Q176476 OFF: Office Assistant Not Answering Visual Basic Questions


"Visual Basic User's Guide," version 5.0, Chapter 3, "Creating a User- Defined Function"

Additional query words: 5.00a 5.00c 7.00a XL98 XL97 XL7 XL5 example

Keywords : kbprg kbdta kbdtacode PgmHowto KbVBA
Version : MACINTOSH:5.0,5.0a,98; WINDOWS:5.0,5.0c,7.0,7.0a,97
Platform : MACINTOSH WINDOWS
Issue type : kbhowto


Last Reviewed: November 9, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.