Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Counting Wins and Losses.

Counting Wins and Losses

Written by Allen Wyatt (last updated June 18, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


In Excel, Graham has created a matrix of player names for his league. Cells B2:H2 contain the names of the players, as do cells A3:A9. At each intersection in the matrix, Graham places a "W" or "L" to indicate whether the match-up resulted in a win or loss for the player in each row. If a player plays another person more than once, then a cell contains a "W" or "L" for each game. Graham was wondering what formula could be used, starting in column I, to indicate the number or wins and losses for each player.

You might think you could use the COUNTIF function to count whether cells contain a "W" or "L." If that is all it was possible to contain in the cells, then you could use that function. However, a cell could contain multiple "W" or "L" characters (such as "WWL" or even "WLWWWLW") if the players played multiple games. COUNTIF would tell you that the cell contains "W" or "L," but not how many "W" or "L" characters are within the cell.

There are a number of ways you can get the desired information. One is to use this type of formula:

=LEN(SUBSTITUTE(B3&C3&D3&E3&F3&G3&H3,"L",""))

This formula calculates the number of non-L characters in row 3—in other words, the number of wins. It does this by concatenating the contents of B3:H3, and then using the SUBSTITUTE function to remove all the Ls. This leaves the Ws, which are counted by the LEN function. You could also use the CONCATENATE function, in the following manner, for the same result:

=LEN(SUBSTITUTE(CONCATENATE(B3,C3,D3,E3,F3,G3,H3),"L",""))

To calculate the number of losses, simply replace "L" in each formula with "W".

You can also use an array formula, which allows you to specify a range of cells to examine, rather than needing to specify every single cell:

=SUM(LEN(SUBSTITUTE(B3:H3, "L","")))

This array formula, entered by pressing Shift+Ctrl+Enter, returns the number of wins (W characters) in the range B3:H3.

Finally, you can use a user-defined function to return the occurrences of a specific character within a given range. The following macro will do the trick:

Function CharNums(r, chr) As Integer
    Dim c As Range
    Dim strX As String
    Dim J As Integer

    Application.Volatile
    CharNums = 0
    For Each c In r.Cells
        strX = c.Value
        For J = 1 To Len(strX)
            If Mid(strX, J, 1) = chr Then CharNums = CharNums + 1
        Next J
    Next c
End Function

To use the function, you would us a formula like this in your worksheet:

=CharNums(B3:H3;"W")

The function returns the number of uppercase W characters in the range. All other characters (including lowercase w characters) are ignored. To count losses, simply substitute L for W in the formula.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11650) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Counting Wins and Losses.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Generating Unique Sequential Numbers

Using Excel to generate unique sequential numbers for invoices or company statements can be a challenge. Here's ...

Discover More

Conditional Page Breaks

Need to have your worksheet printout start on a new page every time a value in a column changes? There are a couple of ...

Discover More

Recovering Password-Protected Documents

Got a locked document you just need to get into? It may be quite easy (or next to impossible) using the ideas in this tip.

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Summing Only Positive Values

If you have a series of values and you want to get a total of just the values that meet a specific criteria, then you ...

Discover More

Returning the Minimum of Integers of a Range

If you have a range of numbers that contain both integers and decimal numbers, you may have a need to determine the ...

Discover More

Throwing Out the Lowest Score

Want to add up a bunch of scores, without including the lowest one in the bunch? You can make a small change to your ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is five less than 5?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.