Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 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: Incrementing References by Multiples when Copying Formulas.

Incrementing References by Multiples when Copying Formulas

Written by Allen Wyatt (last updated July 15, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021


2

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 (8387) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Incrementing References by Multiples when Copying Formulas.

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

Swapping Two Cells

If you need to swap the contents of two cells in your worksheet, Excel provides a number of ways you can approach the ...

Discover More

Maximum Length Limit for a Macro

Make your macros too long, and Excel may just refuse to run them at all. This tip explains what the limit is for macros ...

Discover More

Excluding Values from Averaging

Calculating an average of a group of numbers is easy. What if you want to exclude a couple of the numbers from the group ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Indirectly Referencing a Cell on a Different Worksheet

Excel includes the powerful INDIRECT function which can be used to assemble references to other cells in your workbook. ...

Discover More

Calculating a Geometric Standard Deviation

One of the areas in which Excel provides worksheet functions is in the arena of statistical analysis. You may want to ...

Discover More

Counting Non-Blank Cells

Need to count the number of cells in a range that are not blank? You can use the COUNTA function of a more complex ...

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 two more than 2?

2020-11-16 10:30:16

Brooks

Hello, Will either Indirect or Index (suggested below) work with Sumif/s or countif/s? I have a situation where one sheet is using sumif and countif to calculate data from another sheet and each time the formula goes down one line I need the sumif/countif cell references to increase by 12 lines. A example of the formulas is here: =SUMIF(Sheet1!$F$6:$AB$6, "<>",Sheet1!$F$4:AB$4). That formula occurs on row 5 of the second sheet so thus row 6 of the second sheet would need the formula =SUMIF(Sheet1!$F$18:$AB$18, "<>",Sheet!$F$16:AB$16) and so on. I couldn't get INdex or Indirect to do this but wanted to ask if I was missing something.


2019-05-11 05:33:07

Robert H. Gascon

Instead of using the volatile INDIRECT or OFFSET, I suggest using INDEX in B1, copied down rows, this way:
=SUM(INDEX(A:A,ROW()*7-6):INDEX(A:A,ROW()*7))


This Site

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.

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.