Finding Odd Values Greater Than 50

by Allen Wyatt
(last updated December 12, 2018)

Amol has 1,000 values in an Excel worksheet, occupying 100 rows of 10 columns each. Each value in this range is an integer value between 0 and 99. Amol needs a way to count and display all the values which are odd and greater than 50.

There are a few ways you can go about counting and displaying, but it is important to understand that these are different tasks. Perhaps the best way to display those values that fit the criteria is to use conditional formatting. You can add a conditional formatting rule to each cell that will make bold or otherwise highlight the desired values. Follow these steps:

  1. Select the cells that contain your data.
  2. Display the Home tab of the ribbon.
  3. Click the Conditional Formatting tool in the Styles group. Excel displays a palette of options related to conditional formatting.
  4. Click New Rule. Excel displays the New Formatting Rule dialog box. (See Figure 1.)
  5. Figure 1. The New Formatting Rule dialog box.

  6. In the Select a Rule Type area at the top of the dialog box, choose Use a Formula To Determine Which Cells to Format.
  7. In the formula box enter the formula =AND(MOD(A1,2),A1>50).
  8. Click the Format button. Excel displays the Format Cells dialog box. (See Figure 2.)
  9. Figure 2. The Format Cells dialog box.

  10. Use the controls in the dialog box to modify the formatting, as desired.
  11. Click OK to close the Format Cells dialog box.
  12. Click OK to close the New Formatting Rule dialog box. The formatting is applied to the range of cells you selected in step 1.

If you prefer, you could also use the following formula in step 6:

=AND(ISODD(A1),A1>50)

To get the count of cells that fit the criteria, you could use an array formula:

=SUM(MOD(MyCells,2)*(MyCells>50)

This formula assumes that the range of cells you want to analyze are named MyCells. Don't forget to enter the cell using Ctrl+Shift+Enter. If you don't want to use an array formula, you could use the following:

=SUMPRODUCT((MOD(MyCells,2)*(MyCells>50))

You could also use a macro to derive both the cells and the count. The following is a simple version of such a macro; it places the values of the cells matching the criteria into column M and then shows a count of how many cells there were:

Sub SpecialCount()
    Dim c As Range
    Dim i As Integer

    i = 0
    For Each c In Range("A2:J101")
        If c.Value > 50 And c.Value Mod 2 Then
            i = i + 1
            Range("L" & i).Value = c.Value
        End If
    Next c

    MsgBox i & " values are odd and greater than 50", vbOKOnly
End Sub

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 (12597) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365.

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

Counting Unique Values with Functions

Using Excel to maintain lists of information is not unusual. When working with the list you may need to determine how ...

Discover More

Preventing Printing

Want to prevent your worksheet from being printed? You may be out of luck, as a determined person may be able to find a ...

Discover More

Pasting Numeric Values in Other Programs

When you paste information from Excel into other programs, you may get more than you actually want. It is not unusual for ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Replacing Dashes with Periods

Replacing one character in a text value with another character is easy. All you need to do is use the SUBSTITUTE ...

Discover More

Checking for Proper Entry of Array Formulas

Excel allows you to enter two different types of formulas in a cell: A regular formula or an array formula. If you need ...

Discover More

Transposing and Linking

Sometimes it is helpful to look at data that is rotated 90 degrees. Excel allows you to use Paste Special to transpose ...

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}] 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 nine more than 3?

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.