Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Easily Changing Chart Data Ranges.
Written by Allen Wyatt (last updated May 15, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
Excel is great when it comes to creating charts based on data in a data table. The Chart Wizard can quickly identify an entire data table, or you can select a portion of a data table and use the Chart Wizard to create a chart based just on that portion.
If you change the data range for your chart quite often, it can get tiresome to continually pull up the Chart Wizard and change the data range reference. For instance, if you have a data table that includes several years worth of data, you may want to view a chart that is based on the first five years of data, and then change the data range so the chart refers to a different subset of the data. Make the changes often enough in the Chart Wizard, and you'll start casting about for ways to make the changes easier (and more reliably) than with the wizard.
One way to do this is with the use of named ranges and several worksheet functions. Let's say that your chart is embedded on a worksheet, but the worksheet is different than the one where the source data is located. On the same sheet as the chart, create two input cells which will serve as "from" and "to" indicators. Name these two cells something like FromYear and ToYear.
On your data worksheet (the one without the chart; I'll call it "Source Data"), the data is arranged with each year in a separate column and a series of cost factors in each row. Start your table in column F and place your years in row 2. Place the cost factors in column E, starting at row 3. Above the years place a capital letter that is the same as the column letter, and in column D place a number that is the same as the row number of the data. (See Figure 1.)
Figure 1. First phase of data preparation.
In this example, the chart that is embedded on the other worksheet is based on the data in the rangeF2:I5. There is nothing special about the chart, but the changes you are getting ready to make will make it dynamic, and therefore much more useful.
Start by placing the following formula in cell B1:
="Trends For " & IF(FromYear=ToYear,FromYear,FromYear & " to " & ToYear)
This formula provides a dynamic title that you will later use for your chart. Give cell B1 the name addrTitle, then place the following formula in cell B2:
="'Source Data'!$" & INDEX($F$1:$I$1,1,MATCH(FromYear,$F$2:$I$2)) & "$" & D2 & ":$" & INDEX($F$1:$I$1,1,MATCH(ToYear,$F$2:$I$2)) & "$" & D2
Copy the formula in B2 to the cells B3:B5. The formula returns address strings that represent the desired ranges for the X-axis values and the data series. The actual ranges returned by the formulas will vary, based on the values you enter in the FromYear and ToYear cells on the other worksheet. To make things clearer you can enter some labels into column A. (See Figure 2.)
Figure 2. Second phase of data preparation.
Now you need to name each of the cells in the range B2:B5. Select B2 and in the Name Box (just above column A) enter the name "addrXVal" (without the quotes). Similarly name B3 as addrCost1, B4 as addrCost2, and B5 as addrCost3.
The next step is to create a couple of named formulas that you can use in creating the charts. Choose Insert | Name | Define to display the Define Name dialog box. (See Figure 3.)
Figure 3. The Define Name dialog box.
In the name area, at the top of the dialog box, type "rngXVal" (without the quotes), then type the following in the Refers To box:
=INDIRECT(addrXVal)
Using the same dialog box, define additional names (rngCost1, rngCost2, and rngCost3) that use the same type of INDIRECT formula to refer to the ranges addrCost1, addrCost2, and addrCost3, respectively.
Now you are finally ready to update the references in your chart. Right-click the chart and select Source Data, then make sure the Series tab is displayed. (See Figure 4.)
Figure 4. The Series tab of the Source Data dialog box.
For each of the data series listed at the left side of the dialog box, enter the Name and Values according to the names you defined. Thus, for the Cost1 series you would enter a Name of ='Source Data'!addrCost1 and a Values of ='Source Data'!rngCost1. You would use the similar references and names for each of the other data series, as well.
Note that you must include the name of your worksheet (Source Data), within apostrophes, in the references you enter. In the Category (X) Axis Labels reference you can enter ='Source Data'!rngXVal.
Once this is done, you can change the starting and ending years in the FromYear and ToYear cells, and Excel automatically and immediately updates the chart to represent the data you specified.
For an extra touch, if you haven't already added a chart title, go ahead and do so. Right-click the chart and select Chart Options, then display the Titles tab. (See Figure 5.)
Figure 5. The Titles tab of the Chart Options dialog box.
Enter anything you'd like in the Chart Title box (you'll replace it in a moment), then click OK. The chart title should already be selected, but if it isn't, click on it once. You should see the selection box around the title. In the Formula bar enter the following:
='Source Data'!addrTitle
The chart title is now linked back to the cell containing the title string, which in turn is dynamically updated each time you change the FromYear and ToYear values.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2376) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Easily Changing Chart Data Ranges.
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!
Excel provides lots of ways you can create charts. This tip provides some pointers on how you can combine stacked column ...
Discover MoreIf you have a lot of records in a data table, you may want to create individual charts based on the information in those ...
Discover MoreHaving problems working with data labels in your charts? That's not unusual; here's an idea of an add-in that could help ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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