Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. 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: Easily Changing Chart Data Ranges.

Easily Changing Chart Data Ranges

by Allen Wyatt
(last updated July 7, 2018)

6

Excel is great when it comes to creating charts based on data in a data table. You can use the tools on the Insert tab of the ribbon to quickly identify an entire data table or you can select a portion of a data table and use the same tools 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 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 and you'll start casting about for ways to make the changes easier (and more reliably).

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 name the worksheet "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 range F2: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.

Still working on the "Source Data" worksheet, 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

Remember that this is a single formula, although it is shown on two lines here for clarity. 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. Display the Formulas tab of the ribbon and click the Define Name tool to display the New Name dialog box. (See Figure 3.)

Figure 3. The New 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)

Click OK and the name is defined. Then, using the same New Name 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 choose Select Source or Select Data, depending on your version of Excel. Excel displays the Select Data Source dialog box. (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, click the Edit button and 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. If you are using Excel 2007 or Excel 2010, select the chart, display the Layout tab of the ribbon, click the Chart Title tool, and choose the way you want the title to appear. The title should appear immediately in the chart.

If you are using Excel 2013 or Excel 2016, click the Chart Elements icon, near the upper-right corner of your chart. (It looks like a plus sign.) Excel displays a "fly-out" menu that lists various elements you can add to your chart. (See Figure 5.)

Figure 5. Adding titles to a chart in Excel 2016.

Make sure you a check mark appears beside the Chart Title element. The title should appear immediately in the chart.

Regardless of the version of Excel you are using, click the title (within the chart itself) once to select it. 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 (8667) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Easily Changing Chart Data Ranges.

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

Controlling the Behavior of the Mouse Wheel

The mouse wheel, by default, controls scrolling vertically through your worksheet. If you don't want the wheel to control ...

Discover More

Changing Outline Structure

When working with the outline of a document, you can easily move whole sections of your document. It is as easy as ...

Discover More

Determining the Week of the Year

If you are working with dates in a macro, you may need to determine which week of the year a date falls within. This can ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Unwanted Weekend Dates in Chart

If you chart data that includes dates along one of the axes, you might be surprised to find out that the chart includes ...

Discover More

Controlling the Plotting of Empty Cells

When creating a chart from information that contains empty cells, you can direct Excel how it should proceed. This tip ...

Discover More

Colorizing Charts

Need to change the color of different parts of your chart? It's easy to do when you apply the technique described in this ...

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 one less than 6?

2018-07-02 17:23:43

Renwick Wright

Hi Allen,
Reading this tip reminded me of a formula pattern that I was shown years ago and have found very useful over the years. We have a number of spreadsheets that have data automatically added to them on a daily basis so we need to dynamically determine what the new data range is. This formula pattern works where data is being added/deleted to a table, it obviously won't work for data added randomly throughout a workbook.

For this example, create a table in the range A1:E6 with the first row containing headers.
Use the following formula to create a Range Name:
=OFFSET(MySheet!$A$2,0,0,COUNTIF(MySheet!$A:$A, "<>")-1, COUNTIF(MySheet!$1:$1, "<>"))

In the above formula, I want the dynamic selected range to start at row 2 so I exclude the headers; I check row 1 to determine the range width because my table may have empty data cells.
This range will now dynamically expand/contract as data is added/deleted from the table. If the table grows wider/narrower with additional columns being added/deleted to the table, it will handle that as well.

Note that the cell, column and row references must be made absolute ($) otherwise the range formula will change in crazy ways every time data is added to the table!!!

Hope this helps someone.


2018-06-25 18:54:46

Ruthie A. Ward

Hi David Rabbit: When I want to see a rolling set of data, I add a column to my data source. In that column I create a formula to return a value depending on what condition I'm checking. For example, I only want to see the last 45 days of data so if the data's date is in that window return a "Y" and filter my pivot chart to only show those data points.

In your case:
1) Enter a formula above your data that finds the row number for the last row of your data.
2) Add a column to your data source. In it, calculate the row number for each line of data.
3) Construct a formula that returns a "Y" if the row number for each line is within 100 of the value calculated in step 1.
4) Filter your pivot chart to only show those data' then each time you refresh the pivot, you'll see only the data in those 100 rows.

This method works similarly with other indicators: biggest n sales, top n% scores, only even values, etc. In some cases, you just need to add a column and a formula to determine which rows of data to show. Sometimes, you may need to add a helper cell like the one in step 1.

Hope this helps!


2016-12-08 15:45:32

BJ Gray

Never mind. I finally realized that the letter row and number columns you put in are to fool Excel into thinking that the index function is returning a cell address. Got it sorted.


2016-12-08 13:36:32

BJ Gray

I am really interested in implementing this method, but have been banging my head for the past day and a half.

I can't get the named formulas to work on the graph at all. I have checked and rechecked how I named the cells and established the named formulas with the indirect function.

Oddly, I can get the chart title to appear.

Any suggestions?

Thank you.


2014-11-11 19:58:47

David Rabbit

What I want is a chart that works like a simple moving average works, and charts the latest N data points. As a new data point is added the first one drops off, so I always have the last (eg.) 100 data points automatically


2013-12-13 11:31:33

DEB

I SEE WHERE TO PULL UP THE DATASOURCE
TO CHANGE CHART DATA,

FROM THERE IT APPEARS TO BE A JOKE,
I HAVE TRIED REPEATEDLY TO JUST GET THE CURSOR TO THE RIGHT POSITION WITH THE RIGHT ARROW KEY, IT ONLY PUTS IN NEW FIELDS, NOT AT ALL WHAT I WANT.

THIS WAS SO SIMPLE BEFORE, I HAVE WASTED 1/2 HOUR TRYING TO FIGURE THIS OUT. GEESH


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.