|
Current Special! Complete Excel
Excel
Training Course
for Excel 97 - Excel 2003, only $145.00.
$59.95 Instant
Buy/Download,
30 Day Money Back Guarantee & Free
Excel Help for LIFE!
Got any Excel Questions? Free Excel Help
Find the Nth Occurrence of Specified Value <See Also: Extract nth Word From Text in Excel Custom Function/Formula || Count Words in Excel || Excel Formulas for Text, Dates & Numbers | Advanced Excel Find | Excel Find & Replace>
As you may already know, we can use
VLOOKUP
, or
INDEX/MATCH to locate
the first occurrence of a specified value in a list, or table of data.
However, Excel has no ready made formula that allows us to locate say
the second, or third occurrence etc of a specified value. To do this
would normally the use of a Custom Excel VBA Function, or a horribly
inefficient A
rray formula . Below you will find
2 ways to locate the nth
occurrence of a specified value and return the value on the same row but
in another column. One is straight forward and requires no VBA, while
the second does make use of Excel VBA. Neither need array formulas!
Find the Nth Occurrence of Specified
Value Non VBA Method.
I will use the table of data as shown below for the example,
sorted only
for easier reading. Note the formula that resides in the selected cell
A2 (see Formula bar) is: =B2&" "&COUNTIF($B$2:$B2,B2) and is used to
obtain a count of each occurrence. It is vital to note the Absolute of
$B$2 and the relative row reference of $B2. This is vital so when you
copy the formula down, it will extend the COUNTIF range accordingly.
Note also that this extra column can be hidden from view to make for
less clutter. If you have not already guessed, we now simply use a
standard VLOOKUP, or INDEX/MATCH to obtain the occurrence we want, for
example;
=VLOOKUP("Bill 3",$A$1:$C$22,3,FALSE)
Would yield a return value of "Bill # 3"
Find the Nth Occurrence of Specified
Value Custom VBA Function
The custom function/formula below was written in Excel 2003 and may not
work in earlier Excel versions.
Function Nth_Occurrence(range_look As Range, find_it As String, _ occurrence As Long, offset_row As Long, offset_col As Long) Dim lCount As Long Dim rFound As Range Set rFound = range_look.Cells(1, 1) For lCount = 1 To occurrence Set rFound = range_look.Find(find_it, rFound, xlValues, xlWhole) Next lCount Nth_Occurrence = rFound.offset(offset_row, offset_col) End Function
The custom function/formula can now be used like shown below
=Nth_Occurrence($B$1:$B$22,"Harry",3,0,1)
The syntax is
=Nth_Occurrence(range_look,find_it,occurrence,offset_row,offset_col)
Where $B$1:$B$22 (range_look) is the range to find the 3rd occurrence (occurrence) of "Harry" (find_it). When found, it will return the value by offsetting 0 rows (offset_row) and 1 column (offset_col) to the right. The offset_row and offset_col arguments can be negative values if that is what is needed.
<See Also: Extract nth Word From Text in Excel Custom Function/Formula || Count Words in Excel || Excel Formulas for Text, Dates & Numbers | Advanced Excel Find | Excel Find & Replace>
Excel Dashboard Reports & Excel Dashboard Charts 50% Off Become an ExcelUser Affiliate & Earn Money
Special! Free Choice of Complete Excel Training Course OR Excel Add-ins Collection on all purchases totaling over $64.00. ALL purchases totaling over $150.00 gets you BOTH! Purchases MUST be made via this site. Send payment proof to [email protected] 31 days after purchase date.
Instant Download and Money Back Guarantee on Most Software
Excel Trader Package Technical Analysis in Excel With $139.00 of FREE software!
Microsoft � and Microsoft Excel � are registered trademarks of Microsoft Corporation. OzGrid is in no way associated with Microsoft
Some of our more popular products are below...
Convert Excel Spreadsheets To Webpages | Trading In Excel | Construction Estimators | Finance Templates & Add-ins Bundle | Code-VBA | Smart-VBA | Print-VBA | Excel Data Manipulation & Analysis | Convert MS Office Applications To...... | Analyzer Excel | Downloader Excel
| MSSQL Migration
Toolkit |
Monte Carlo Add-in |
Excel
Costing Templates
FREE Excel Help