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 .
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
When working with large amounts of data, it is a good idea to make sure that the data all consistently follows a pattern. ...
Discover MoreNeed a bit of help in figuring out how Excel is evaluating a particular formula? It's easy to figure out if you use the ...
Discover MoreIf you convert a PDF file to an Excel worksheet, you may end up with some text values that need to have some conversion ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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
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.
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