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: Summing Based on Formatting in Adjacent Cells.
Written by Allen Wyatt (last updated June 10, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Summing Based on Formatting in Adjacent Cells.
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!
You can easily use the COMBIN worksheet function to determine the number of combinations that can be made from a given ...
Discover MoreExcel provides a variety of tools that allow you to perform operations on your data based upon the characteristics of ...
Discover MoreIt is not unusual to use worksheets to collect information over time. As you keep adding information to the worksheet, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-06-13 14:54:31
J. Woolley
Re. the ColorConditionSum function in my previous comment:
1. Both versions of the function use the ColorIndex property to identify a cell's interior color. This represents an approximation of a limited number of colors (56) in the current color palette. A more specific representation is provided by the Color property. To implement this improvement, use Ctrl+H in the VB Editor to remove Index from each instance of ColorIndex; there are 5 instances (including variable lColorIndex).
2. In the simplified version of the function, if its first argument is a range like A10:B22, its first cell (A10) determines the target color. The original version improperly ignores this issue.
3. The function's second argument can be a parenthesized non-contiguous range like (A12:B15,A17:B22,D12:F20). In this case each subrange (area) must have at least two columns; if there are more than two, only the first two apply. Each cell in the second column of each area is summed if its adjacent cell in the first column matches the target color.
4. The original version of the function used the Range.SpecialCells method to identify cells with numeric values, but that method is unreliable in a user-defined function (UDF) that is referenced in a cell formula. It is not used in the simplified version.
2023-06-12 15:03:16
J. Woolley
The Tip's ColorConditionSum function is unnecessarily complex. Here's a simplified version:
Function ColorConditionSum(cSample As Range, rng As Range)
'Return the sum of each cell in rng.Columns(2) if the corresponding
'cell in rng.Columns(1) has the same color as the first cell in cSample
Dim lColorIndex As Long, MySum As Double, area As Range, c As Range
Const sTypes As String = "Double/Date/Currency" 'types to sum
ColorConditionSum = CVErr(xlErrValue)
lColorIndex = cSample.Cells(1).Interior.ColorIndex
For Each area In rng.Areas
If area.Columns.Count < 2 Then Exit Function '>>>
For Each c In area.Columns(2).Cells
If c.Offset(0, -1).Interior.ColorIndex = lColorIndex _
And InStr(sTypes, TypeName(c.Value)) > 0 _
Then MySum = MySum + c.Value
Next c
Next area
ColorConditionSum = MySum
End Function
Notice cells with numeric values (not text, logical, or empty) generally have VBA type Double. However, numeric cells with Number format Date, Currency, or Accounting (equivalent to Currency) are exceptions. These are included in Excel's SUM function and in both versions of the ColorConditionSum function.
For further interest, see https://sites.google.com/view/MyExcelToolbox/
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