Written by Allen Wyatt (last updated June 24, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Jeff has a worksheet with quite a bit of text in it, in column C. He would like to count occurrences of a specific string within column C, but only for odd rows (1, 3, 5, etc.) in the data. The string he's looking for may not be the entire cell contents, and it may occur multiple times within a particular cell. (If it occurs 2 or 3 times in a cell, it should count as 2 or 3 occurrences.) He wonders if there is a formulaic way to do this, without resorting to a macro.
One way to approach this is through the use of a helper column. For instance, let's say that you can use column D as a helper column, and the first cell containing data is cell C2. (Perhaps cell C1 has a column heading in it.) You could use the following formula in cell D2:
=IF(MOD(ROW(),2)=1,(LEN(C2)-LEN(SUBSTITUTE(C2,"my text","")))/LEN("my text"),"")
All you would need to do is replace the search string ("my text") with whatever you are searching for. The LEN function is used twice, first to find the length of whatever is in cell C2 and then to subtract from it the length of the text with all instances of "my text" removed. This value is then divided by the length of what you are searching for, resulting in how many instances of the search text was in the cell. Note that the IF function ensures that a numeric value is returned only if the row is an odd-numbered row.
You can copy this formula down as many rows as necessary, and then sum the column. The result is the number of times the string appear in odd-numbered rows.
If the layout of your worksheet does not allow you to use a helper column, then you can rely on a formula that works on arrays of data. Here's one that does the trick:
=SUMPRODUCT((LEN(C:C)-LEN(SUBSTITUTE(C:C,"my text","")))/LEN("my text")*ISODD(ROW(C:C)))
This formula essentially does the same as the previous formula, except that the SUMPRODUCT function does the calculation internally for each cell in column C. You should realize that since the formula examines all of column C, that means if your search text ("my text") occurs within any non-data cells in the column (such as a column header), then it will also be included in the total returned.
If you do decide to use a macro, you could easily create a user-defined function that examines a range of cells and determines the count. The following is an example of the type of macro you could use:
Function CountInst(rSource As Range, sSearch As String, bCaseInsensitive As Boolean) As Integer Dim c As Range Dim iCount As Integer Dim sTemp1 As String Dim sTemp2 As String sTemp2 = sSearch If bCaseInsensitive Then sTemp2 = LCase(sTemp2) iCount = 0 For Each c In rSource If c.Row Mod 2 = 1 Then sTemp1 = c.Text If bCaseInsensitive Then sTemp1 = LCase(sTemp1) iCount = iCount + (Len(sTemp1) - _ Len(Replace(sTemp1, sTemp2, ""))) / Len(sTemp2) End If Next c CountInst = iCount End Function
To use this, all you need to do is provide a range, what you want to search for, and whether you want the matching to be case insensitive or not. For instance, if you want to search for "my text" and have the case not matter, you would use the following:
=CountInst(C2:C99,"my text",TRUE)
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1514) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
When working with data in Excel, you might want to figure out which rows of data represent duplicates of other rows. If ...
Discover MoreSearching for a value using Excel's Find tool is easy; searching for that same value using a formula or a macro is more ...
Discover MoreAt the heart of working with Excel is the process of creating formulas that calculate results based on information within ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments