Written by Allen Wyatt (last updated December 24, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
Tim has a worksheet in which cell B1 contains the formula =SUM(A1:A7). He wants to copy this formula down and have the range incremented by 7 rows, so that cell B2 would contain the formula =SUM(A8:A14), cell B3 would contain =SUM(A15:A21), etc. The problem is that when he copies it down, each "end" of the range is only incremented by 1 where it should be incremented by 7 to fulfill his need. He wonders how he can make Excel do the proper incrementing.
You can't make Excel do the proper incrementing using copy and paste; it just won't do it. The reason is simple—there are times when incrementing by 1 makes sense from a formulaic perspective. Since Excel can't read your mind (at least until the next version :>)), it makes the assumption that it should only increment by 1.
The solution is to change your formula. Using a couple of worksheet functions you can have Excel construct the desired range for the summation. Consider the following example of a formula that will provide the desired sum:
=SUM(INDIRECT("A" & (ROW()-1)*7+1 & ":A" & (ROW()-1)*7+7))
If you put this formula into cell B1, it works because it takes a look at the row number (returned by the ROW function) of the row in which the formula is contained. Since it is in row 1, then the formula is evaluated in this manner by Excel:
=SUM(INDIRECT("A" & (ROW()-1)*7+1 & ":A" & (ROW()-1)*7+7)) =SUM(INDIRECT("A" & (1-1)*7+1 & ":A" & (1-1)*7+7)) =SUM(INDIRECT("A" & 0*7+1 & ":A" & 0*7+7)) =SUM(INDIRECT("A" & 0+1 & ":A" & 0+7)) =SUM(INDIRECT("A" & 1 & ":A" & 7)) =SUM(INDIRECT("A1:A7")) =SUM(A1:A7)
What you end up with in B1 is the sum you desired. (The INDIRECT function uses the value in the string as if it was a real range, which is what you want.) When you copy the formula down the column, as the row number increments the formula provides the proper increments of 7 on both ends of the range.
There are other variations on this technique that you can use. The only difference is that the variations use different worksheet functions to accomplish the same task. For instance, the following variation still uses the ROW function, but then ultimately relies on the OFFSET function to calculate the desired range:
=SUM(OFFSET(A1,((ROW()-1)*6),0):OFFSET(A7,((ROW()-1)*6),0))
A shorter approach that uses OFFSET is as follows:
=SUM(OFFSET($A$1,ROW()*7-7,0,7,1))
Regardless of the approach, you can probably tell that the idea is to come up with a formula that uses the row in which the formula appears in order to construct the range that you really want. Each of the examples so far assumes that you are starting in cell B1. If you want to start in cell B2, then you'll need to modify the formulas to account for whatever row you are starting on. To give you just an idea of how this works, if you were starting in cell B2, instead, the three formulas presented in this tip would be modified in the following ways:
=SUM(INDIRECT("A" & (ROW()-2)*7+2 & ":A" & (ROW()-2)*7+8)) =SUM(OFFSET(A2,((ROW()-2)*6),0):OFFSET(A8,((ROW()-2)*6),0)) =SUM(OFFSET($A$2,(ROW()-1)*7-7,0,7,1))
Start at a different location, and you'll need to make further modifications to the formula you choose to use.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8385) 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: Incrementing References by Multiples when Copying Formulas.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Reference a cell in a macro, and if that cell is blank Excel normally equates that to a zero value. What if you don't ...
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 MoreIf you have a lot of values in a single row, you might want to pull the last non-zero value from that row. There are a ...
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 © 2025 Sharon Parq Associates, Inc.
Comments