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 Every Fourth Cell in a Row.
Written by Allen Wyatt (last updated December 11, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
Kevin needs to create a formula that sums every fourth cell in a row. He knows he can use a formula such as =A6+E6+I6+M6, etc., but this becomes cumbersome if there are a lot of columns in the worksheet.
There are several ways you can approach this problem. One way is to add some additional information to the worksheet to designate which cells should be included in the sum. For instance, in the example you are interested in summing cells in row 6 of the worksheet. If you can add some indicators in row 5, these could then be used a "triggers" in a formula. Put the number 1, for example, above each cell you want included in the sum (columns A, E, I, M, etc.). Then, you can use a formula such as the following:
=SUMPRODUCT(A5:X5, A6:X6)
The formula basically multiples whatever is in row 5 against row 6, and then sums the results. Since there are only 1s in the columns you want summed, these are all that are included in the final sum.
If you don't want to add an indicator row to your worksheet, then you need to look at different solutions. You could still use the SUMPRODUCT function in a formula such as the following:
=SUMPRODUCT((MOD(COLUMN(6:6),4)=1)*(6:6))
This formula relies on the MOD function to return the remainder of a division. In this case, what is being divided is the column number of a cell by the value 4. This will result in a remainder of either 0, 1, 2, or 3. Every fourth cell in a row will have the same remainder. Thus, column A (also known as column 1) will have a MOD value of 1 (1 divided by 4 is 0, with 1 left over), as will columns E, I, M, etc.
Note that the formula compares whether the MOD value is 1 or not. If it is, then the comparison returns True (1); if it isn't, then it returns False (0). This is then multiplied against the cell in the sixth row. Finally, SUMPRODUCT sums all these multiplications and gives the desired result.
While this formula provides the sum of every fourth cell in the sixth row, it could easily be changed to provide the sum for every third cell, fifth cell, or whatever interval you want. Simply change the 4 in the MOD function to the interval desired.
If you wanted to select a different cell in each "cluster" of four cells to be summed, then all you need to do is change the value being compared in the MOD function. In this example, only the first cell in each cluster of four will have a MOD of 1 (A, E, I, M, etc.). If you instead want to sum every fourth cell starting with, say, cell C, then you would change the comparison value from 1 to 3. Why? Because C is the third cell in the cluster and will have a MOD of 3, as will each fourth cell thereafter (G, K, O, etc.).
The only "gottcha" to this general rule is if you want to sum the fourth cell in each four-cell cluster. For instance, you might want to sum cells D, H, L, P, etc. In this case the comparison value used wouldn't be 4 since there will never be a remainder of 4 when doing a MOD operation that involves dividing by 4. Instead, the comparison value would be 0, as in the following:
=SUMPRODUCT((MOD(COLUMN(6:6),4)=0)*(6:6))
If you prefer to work with array formulas, you can use a slightly shorter variation on the above formula:
=SUM(IF(MOD(COLUMN(6:6),4)=1,6:6))
Note that the formula should be entered by pressing Ctrl+Shift+Enter. It will then appear in the Formula bar with braces ({ }) around the formula. The same modification notes relative to the MOD divisor and comparison value apply here as they did with the SUMPRODUCT function.
Both of these formulaic approaches (SUMPRODUCT and the array formula) sum every fourth cell in the entire row. If you instead want to limit the cells from which the sum is derived to a portion of the row, then simply replace 6:6 (both instances) with the proper range. Thus, if you wanted to only sum every fourth cell in the range of A6:Z6, you would use that range in the formula.
If you do a lot of summing in this manner, and you apply it not only to ranges in a row but ranges in a column, you may want to consider creating a user-defined function to do the summing. The following simple function will do the trick:
Function SumEveryFourth(MyRange As Range) Dim x As Integer SumEveryFourth = 0 For x = 1 To MyRange.Cells.Count If (x Mod 4) = 1 Then SumEveryFourth = SumEveryFourth + MyRange.Cells(x).Value End If Next x End Function
The function examines the range passed to it, and then sums every fourth cell starting with the first cell in the range. If you prefer to have it sum every second cell in the range, then change the comparison value in the If statement, as discussed earlier in this tip. (Since the Mod operation is used in this function, and it operates the same as the MOD worksheet function, then the same comparison values come into play for determining which cell in each cluster should be summed.)
The user-defined function will work just fine on either cells in a row or cells in a column. You simply need to make sure that you pass it the range you want, as demonstrated here:
=SumEveryFourth(C3:C57)
You can, if desired, make the macro even more flexible by making the "step" value a variable that is passed to the function. This altered macro could then be used to sum by every 2, 3, 4, 5, etc. cell.
Function SumEveryNth(MyRange As Range, N As Integer) Dim x As Integer SumEveryFourth = 0 For x = 1 To MyRange.Cells.Count If (x Mod N) = 1 Then SumEveryNth = SumEveryNth + MyRange.Cells(x).Value End If Next x End Function
This function is called the same as the previous function, with the exception that you add the desired step value. For instance, this will result in every third cell in the range C3:C57 being summed:
=SumEveryNth(C3:C57, 3)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3234) 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 Every Fourth Cell in a Row.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
If you use serial numbers that include both letters and numbers, you might wonder how you can increment the numeric ...
Discover MoreOperators are used in formulas to instruct Excel what to do to arrive at a result. Not all operators are evaluated in the ...
Discover MoreConvert a numeric value to text and you may be surprised by how Excel displays the value. Here's a run-down on exactly ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
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