Please Note: This article is written for users of the following Microsoft Excel versions: 2007 and 2010. 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

by Allen Wyatt
(last updated August 30, 2017)

7

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 and 2010. 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

Turning Off Paragraph Hyphenation

Need to make sure that a particular paragraph never has any hyphenated words in it? You can make sure that Word won't ...

Discover More

Creating Superscript and Subscript Buttons

Want a quick way to apply superscript and subscript to selected text within a cell? This tip shows how the formatting can be ...

Discover More

Adding Automatic Lines

Want an easy way to add lines in your document? You can do it by making sure Word is using one of its AutoFormat features.

Discover More

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!

More ExcelTips (ribbon)

Transposing and Linking

Sometimes it is helpful to look at data that is rotated 90 degrees. Excel allows you to use Paste Special to transpose data, ...

Discover More

Referencing the Last Six Items in a Formula

If you have a list of data in a column, you may want to determine an average of whatever the last few items are in the ...

Discover More

Compiling a List of Students in a Course

Need to pull just a limited amount of information from a large list? Here are a few approaches you might be able to use with ...

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}] 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 six more than 9?

2018-01-01 15:46:25

DocEE

This tip was just what I was looking for and I was able to make it work in a test workbook using a single worksheet. However, when I tried to use it in my production workbook that has multiple worksheets, I couldn't get it to work referencing cells on a different worksheet.

I have a worksheet called "RawData" that is basically a daily log. Column B is the date and columns I-AZ contain different types of numerical data collected for each day. There are a number of header rows and columns of descriptive information; the first real data starts on B10 with the date (Monday, 8/1/16) and actual data starts at I10-AZ10. On a second worksheet called WkAvg, columns B and C are the date ranges for the week to average starting with Monday, 8/1/16 - Sunday, 8/7/16. In cell WkAvg!D3, I want the formula: =AVERAGE(RawData!I10:I16). Below that in cell WkAvg!D4 I want: =AVERAGE(RawData!I17:I23), and so on. I want to be able to drag this formula down the rows and have it increment by 7 as I drag down the rows. I also want to drag this formula across the columns so only the column changes but the rows remain so cell WkAvg!E3 would have =AVERAGE(RawData!J10:J16) and so on.

I tried using the example above =SUM(INDIRECT("A" & (ROW()-2)*7+2 & ":A" & (ROW()-2)*7+8)) and changed SUM to AVERAGE. That worked fine in my test workbook when it was all on the same worksheet. Then I adjusted the Row to 3 and 4 and that worked fine but not when I adjusted it to row 10. Then when I tried to move the formula to another workbook and insert the first worksheet name things really went south. Here is the final formula that I ended up with but it returns #REF! error: =AVERAGE(INDIRECT("RawData!I" & (ROW()-10)*7+10 & "RawData!:I" & (ROW()-10)*7+16))

I think I'm close but can't get the syntax correct with adding in the sheet name. Appreciate the help.


2017-09-01 03:10:39

marjattanb

Hi Kate,

formula in Cell K11 would be: =SUM(E10:K10), select area E11:K11 and copy and paste to the right again as far as you need. It works.

You can make the formula on the data page and cut it and paste onto the second page, where you actually need the formula. Make sure that where you paste it has those 6 columns to the left of it:

e.g. =SUM(Sheet1!E10:K10) into cell G4 on Sheet2 (supposing you have 3 rows of title-area on top). Then select area A4:G4 and copy it onto right as far as you need.

Finally select row 4, Find Value, leave Find field empty, find all, select all (CTRL A) and delete all.

I believe it works.


2017-08-31 03:05:19

Marjatta N-B

Hi,

I use to do this by writing the wanted formula "=SUM(A1:A7)" into B7, then selecting the area B1:B7 and Copy/Paste down as far as necessary. The only trick is that the number of rows where you paste the 7-row copied area also must be divisible by 7.

Secondly I choose Col B, Find all empty cells (Find What - field is left empty), Select all (CTRL A), and Delete Cells/ Shift Cells Up.


2017-08-30 10:50:00

Frank

A quick and dirty way to accomplish this is to just copy the formula to a cell where it gives you the desired range, and then drag and drop that cell over to the cell where you want the formula. So for the example given, you could copy the formula =SUM(A1:A7) from B1 to B8 which results in =SUM(A8:A14) and then drag B8 into B2 which doesn't change the formula. This only works in certain limited scenarios where there is a small number of these needed, and the cells that you are copying the formula to "temporarily" have to be available, but I've found it to be a useful little trick on a number of occasions.


2015-09-17 12:46:55

Kate

How would this formula work if I wanted to look across columns for the data rather than down rows. I have figures per day across row E10:K10,L10:R10 etc and I want to sum on a separate totals page every 7 days of costs into w/e cost. I have tried amending but can't get it to work consistently


2015-08-20 04:21:49

Lau Hestbek

To make your formula independent of where you place it you can put "A1" or "1:1" in the row-function.

In your example [ =SUM(OFFSET($A$1,ROW()*7-7,0,7,1)) ] this means that you can write it as:

=SUM(OFFSET($A$1,ROW(1:1)*7-7,0,7,1))

Or

=SUM(OFFSET($A$1,ROW(A1)*7-7,0,7,1))


A huge problem with this (and your) approach though is that the formula changes if you insert a new row on top. Also as Bryan points out, the OFFSET- and INDIRECT-functions are volatile.


2013-12-02 11:20:39

Bryan

One thing to think about is whether a SUMIF or SUMIFS formula will help you here. If you are summing in groups of 7, I'm guessing there's a date invloved and you are summing by week.

However, taking the question at face value, there is another way to do it that doesn't use the volatile INDIRECT or OFFSET functions. The INDEX function also provides a reference to another cell, but is not volatile. Knowing that, you can use the following equation:

=SUM(INDEX(A:A,(ROW()-1)*7+1):INDEX(A:A,ROW()*7))

So to do the analysis like Allen did for row 1:

=SUM(INDEX(A:A,(ROW()-1)*7+1):INDEX(A:A,ROW()*7))
=SUM(INDEX(A:A,(1-1)*7+1):INDEX(A:A,1*7))
=SUM(INDEX(A:A,1):INDEX(A:A,7))
=SUM(A1:A7)


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.