Written by Allen Wyatt (last updated December 7, 2020)
This tip applies to Excel 2007, 2010, 2013, and 2016
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, A10 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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11525) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Summing Based on Formatting in Adjacent Cells.
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!
Postal codes in Canada consist of six characters, separated into two groups. This tip explains the format and then shows ...
Discover MoreIf you have a mixture of numbers and letters in a cell, you may be looking for a way to access and use the numeric ...
Discover MoreTwo rather common trigonometric functions are secants and cosecants. Excel doesn't provide functions to calculate these, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-07-07 02:37:36
Prasanna Kant
That is very helpful. Thanks
Just one thing what if I need to add different columns based on single column color e.g. Based on Color of Column A and I can add numbers for column B by the said formula but what if I also need sum of column C and D and others
Thanks
PK
2017-02-10 10:34:04
Luca Marcato
Is it possible to update the SUM after an adjacent changes its color?
2017-01-29 18:35:51
John Mann
Is the format in the adjacent cell the result of conditional formating? If so, would it not be possible to use the same conditions in the Sumif function as is used for the conditional formating?
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 © 2023 Sharon Parq Associates, Inc.
Comments