Referencing Every Third External Cell

Written by Allen Wyatt (last updated February 24, 2024)
This tip applies to Excel


3

Michael has a workbook named Fred.xlsx. He wants to reference cells from that workbook in a new workbook. In cell A1 of the new workbook, he enters =[Fred.xlsx]Sheet1!C340. In cell A2 he enters =[Fred.xlsx]Sheet1!C343, and in cell A3 he enters =[Fred.xlsx]Sheet1!C346. Michael wants to fill downward, continuing to reference every third cell in Fred.xlsx. However, the Fill Handle won't do this, and he's at a loss as to how to get the external references he wants without entering each one manually.

Michael is correct; you cannot use the Fill Handle to populate cells properly when those formulas reference external cells. Instead, you'll need to take a formulaic approach to get the data you want. Here's a formula you could use in cell A1 to reference the desired cells in Fred.xlsx:

=INDEX([Fred.xlsx]Sheet1!$C:$C,(337+(ROW(A1)*3)))

This formula uses the INDEX function to calculate the proper cell to access in column C of Sheet1 in Fred.xlsx. The ROW function returns the row number of cell A1, meaning 1. This is multiplied by 3 and then added to 337. This means that in cell A1 you would grab cell C340, in cell A2 you would grab cell C343, and in cell A3 you'd get C346. Copy it down as many cells as needed, and you'll have the data you want.

Another related approach is to use the INDIRECT function instead of INDEX, as shown here:

=INDIRECT("[Fred.xlsx]Sheet1!C" & (337+ROW(A1)*3))

The formula uses the same sort of approach, using ROW, to calculate the offset to which cell you want to access. And, speaking of "offset," you can use the OFFSET function in a similar formula:

=OFFSET([Fred.xlsx]Sheet1!C$337,3*ROW(A1),0)

Finally, if you don't want to use any of these formulas and would, instead, prefer to do a direct reference to cells in Fred.xlsx (as Michael tried to do), then you can change the process slightly. In cells A1:A3 enter the following:

#[Fred.xlsx]Sheet1!C340
#[Fred.xlsx]Sheet1!C343
#[Fred.xlsx]Sheet1!C346

Notice that the only difference between these formulas and the ones Michael originally entered is that the leading equal sign (=) has been replaced with a hash mark (#). There is nothing special about the hash mark here; you could have used other leading characters, if you prefer, such as a vertical bar (|) or a left brace ({). The idea is to use some character that forces Excel to treat your entry as text.

Now you can select A1:A3 and use the Fill Handle to copy downwards as far as you need. Excel handles this properly because it recognizes the pattern and can replicate it because it thinks you are just dealing with text. Once you have these pseudo-references done, just use Find and Replace to replace each instance of the hash mark (#) with an equal sign (=). Now the references will work just fine.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11511) applies to Microsoft Excel .

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

Understanding Mirror Margins

Rather than have the margins of your documents always be the same, you can use what Word calls "mirror margins." Here's ...

Discover More

Turning Off Error Checking

A little green triangle in the corner of a cell means that Excel thinks there is an error with the cell contents. If ...

Discover More

Changing the Color of Worksheet Gridlines

Want the gridlines in your worksheet to be a different color? You aren't limited to stodgy black; Excel lets you make ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Strange Formula Conversions

When you are getting the hang of how to put together formulas in Excel, you might run into a situation where you open a ...

Discover More

Summing Digits in a Value

Want to add up all the digits in a given value? It's a bit trickier than it may at first seem.

Discover More

Summing Based on Formatting in Adjacent Cells

It is easy to use Excel functions to sum values based on criteria you establish, unless those criteria involve the ...

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 7?

2024-02-26 09:59:29

Shreepad SM Gandhi

Appreciate the following block

#[Fred.xlsx]Sheet1!C340
#[Fred.xlsx]Sheet1!C343
#[Fred.xlsx]Sheet1!C346

It worked wonderfully. Happy. Thanks.


2024-02-24 10:32:21

J. Woolley

@Alex Blakenburg
Excellent comment. Also, INDIRECT and OFFSET are both volatile functions.
See https://exceljet.net/glossary/volatile-function


2024-02-24 06:04:13

Alex Blakenburg

You need to be mindful of the fact that out of Index, Indirect & Offset, only INDEX will work on a Closed Workbook.
INDIRECT returns #REF! and OFFSET returns #VALUE! if the linked workbook is closed.
For more example, see > https://excelribbon.tips.net/T006035_Functions_that_Can_Access_Closed_Workbooks.html


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.