Written by Allen Wyatt (last updated March 16, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Tyler has a workbook with a Trends worksheet followed by a worksheet for each day of the year. He needs to populate the Trends worksheet with data from every other worksheet. The cell needed is constant within each sheet. Tyler wonders how he can grab that data without manually doing "=A23" for each of the 365 worksheets.
There are a couple of ways you can approach this task, depending on exactly what you want to do. If you just want to get a sum for all of the 365 worksheets, you could use a formula such as the following:
=SUM('Day1:Day365'!A23)
This assumes that your worksheets are named Day1 through Day365. An easy way to remove all doubt, however, is to follow these steps:
Of course, you may not want to sum a cell across worksheets. You may, in fact, simply want to list all 365 values in the Trends worksheet. In that case, the easiest method is to list all of the worksheet names just to the left of where you want the values listed. For instance, you might include all the worksheet names in column A. You can then use the INDIRECT function in a formula in column B:
=INDIRECT("'"&A7&"'!A23")
Copy this down as many cells as necessary, and you end up with the desired values pulled from those other worksheets into column B. (See Figure 1.)
Figure 1. Pulling values into the Trends worksheet.
You can do away with the worksheet names in column A if you make sure your worksheets are named with some sort of pattern. For instance, you might have them named something like "Jan 01" through "Dec 31". In that case, you just modify the formula in column B, to something like this:
=INDIRECT("'"& TEXT(DATE(2019,1,ROW()-6), "mmm dd")&"'!A23")
Copy the formula down as many cells as necessary, and you have the values you want. (See Figure 2.)
Figure 2. Pulling values into the Trends worksheet using dates.
Note that the formula subtracts 6 from what the ROW function returns because it is being entered into cell B7. If you are actually putting this formula into a different row, you'll want to adjust what you actually subtract.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6089) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
When analyzing data, you may need to distill groupings from that data. This tip examines how you can use formulas and ...
Discover MoreThe FIND and SEARCH functions are great for finding the initial occurrence of a character in a text string, but what if ...
Discover MoreOperators are used in formulas to instruct Excel what to do to arrive at a result. Not all operators are evaluated in the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-03-16 10:29:38
Allen
The use of the $ (to keep the row static) doesn't really matter in this case because ";!A23" is, by nature, a static value. Every analysis of the INDIRECT function will use A23 with or without the $ sign.
-Allen
2019-03-16 08:54:52
Elliot Penna
=INDIRECT("'"&A7&"'!A23")
Did you mean ...
=INDIRECT("'"&A7&"'!A$23")
?
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