Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Summing Based on Formatting in Adjacent Cells.

Summing Based on Formatting in Adjacent Cells

Written by Allen Wyatt (last updated July 22, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003


Srinivas has data in both columns A and B. He needs to sum the values in column B for which the cell format of the corresponding cells in column A are yellow. For instance, if the format in cell A17 is yellow, then the value in cell B17 should be included in the sum.

There are numerous macros available on the Internet (including at ExcelTips) that allow you to do conditional summing based on the color or other format of a cell. This need is different, however, in that it is not the color of the cell at issue, but the color of the cell one column to the left. This can still be done using a macro, as shown here:

Function SumNextYellow(ByVal r As Range)
    Dim c As Range
    Dim a As Double

    For Each c In r
        If c.Offset(0, -1).Interior.ColorIndex = 6 Then 'Yellow
            a = a + c.Value
        End If
    Next c
    SumNextYellow = a
End Function

The function can be used in a worksheet formula, and accepts a range reference as an argument. It then steps through each cell in the range, and if the cell just to the left is yellow, then the value is included in the sum. (You should note that the ColorIndex used in the macro should be tested with your version of Excel to make sure that it is applicable; it may be different in different versions.)

A much more robust example is shown in the following listing. This function accepts one or more ranges of cells, along with an argument that represents a sample of the formatting you want to use.

Function ColorConditionSum(cSample As Excel.Range, rng As Excel.Range)
' This Function returns sum of values in rng.Columns(2) if
' corresponding cell in rng.Columns(1) is colored with sample
' color (cSample cell)

' Arguments: cSample = cell colored by sample color
'            rng = cell range to be processed (2 columns)

    Dim rngCol2 As Excel.Range
    Dim rngConstants As Excel.Range
    Dim rngFormulas As Excel.Range
    Dim lColorIndex As Long
    Dim MySum As Double
    Dim area As Excel.Range
    Dim c As Excel.Range

    ColorConditionSum = False
    If Not TypeOf cSample Is Excel.Range Then Exit Function '>>>
    lColorIndex = cSample.Interior.ColorIndex

    MySum = 0
    Set rngCol2 = Nothing
    If TypeOf rng Is Excel.Range Then
        If rng.Columns.Count < 2 Then Exit Function '>>>
        On Error Resume Next
        For Each area In rng.Areas
            If rngCol2 Is Nothing Then
                Set rngCol2 = area.Columns(2).SpecialCells(xlCellTypeConstants, 1)
                If rngCol2 Is Nothing Then
                    Set rngCol2 = area.Columns(2).SpecialCells(xlCellTypeFormulas, 1)
                Else
                    Set rngCol2 = Application.Union( _
                        rngCol2, area.Columns(2).SpecialCells(xlCellTypeFormulas, 1))
                End If
            Else
                Set rngCol2 = Application.Union( _
                    rngCol2, area.Columns(2).SpecialCells(xlCellTypeConstants, 1))
                Set rngCol2 = Application.Union( _
                    rngCol2, area.Columns(2).SpecialCells(xlCellTypeFormulas, 1))
            End If
        Next area

        For Each area In rngCol2.Areas
            For Each c In area.Cells
                With c.Offset(0, -1)
                    If .Interior.ColorIndex = lColorIndex Then
                        MySum = MySum + c.Value
                    End If
                End With
            Next c
        Next area
    End If

    ColorConditionSum = MySum
End Function

You use this function in the following manner in a worksheet:

=ColorConditionSum(A10, A12:B22)

In this case, is a cell that has the interior color you want to match and A12:B22 is the range of cells to be evaluated. The values are pulled from the second column in the range and the formatting is checked on the cells in the first column.

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 (3298) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Summing Based on Formatting in Adjacent Cells.

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

Using Document Properties to Ensure Consistent References

If you need to refer to the same information over and over in a document, you may be interested in using custom document ...

Discover More

Screen Flip Flop with VBA

Word allows users to conveniently work with multiple documents at the same time. When writing macros, you may need to ...

Discover More

Ordering Search and Replace

The wildcard searching available in Word is very powerful. Here's how you can use ordering in your search efforts to make ...

Discover More

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!

More ExcelTips (menu)

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

Simulating Alt+Enter in a Formula

You can use the Alt+Enter keyboard shortcut while entering information in order to force your data onto multiple lines in ...

Discover More

Alphabetic Column Designation

Want to know the letters assigned by Excel to a particular column? Excel normally deals with column numbers, but you can ...

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 6 - 0?

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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.