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: Labeling X-Y Scatter Plots.
Martin has a worksheet containing 50 rows of data, each row describing a single object. Column A contains the name of the object, column B contains its X coordinate, and column C contains its Y coordinate. When he creates an X-Y scatter chart (column B against column C) the result, as desired, is a graph showing an array of points showing the location of the objects. However, Martin can't seem to label the data points with their individual names (from column A). When he tries to label the data points the only available options are to label each point with its X value, Y value, or Series Name. Martin wonders if there is a way he can easily use Column A to label the plotted data points.
This can be done manually, but it is tedious at best. For 50 rows it would quickly be brutal, so it is best to look at a macro-oriented approach. One idea is to use a macro similar to the following, which steps through the data points in the X-Y chart and reads the label values from column A.
Sub DataLabelsFromRange() Dim Cht As Chart Dim i, ptcnt As Integer Set Cht = ActiveSheet.ChartObjects(1).Chart On Error Resume Next Cht.SeriesCollection(1).ApplyDataLabels _ Type:=xlDataLabelsShowValue, _ AutoText:=True, _ LegendKey:=False ptcnt = Cht.SeriesCollection(1).Points.Count For i = 1 To ptcnt Cht.SeriesCollection(1).Points(i).DataLabel.Text = _ ActiveSheet.Cells(i + 1, 1).Value Next i End Sub
The macro assumes that the first row of the worksheet contains header information and that the actual data begins in row 2. If the data really begins in row 1, then change "i + 1" to simply "i". (This macro approach is actually a variation of a macro found on pages 570-571 of John Walkenbach's excellent book Excel 2003 Power Programming with VBA.)
One rather unique non-macro approach is to use Excel's custom formats. All you need to do is set up a bunch of custom formats that contain only the text you want to be displayed. For example, if you have the values Age, 15, and 23 in cells A3 to C3, you can format either cell B3 or C3 to show the word "Age" even though the value will remain 15 or 23, respectively. Just enter "Age" (including the quotation marks) for the Custom format for the cell. Then format the chart to display the label for X or Y value.
When you do this, the X-axis values of the chart will probably all changed to whatever the format name is (i.e., Age). However, after formatting the X-axis to Number (with no digits after the decimal in this case) rather than General, the chart should display correctly.
This approach can obviously still take a bit of time to implement as you set up and apply a bunch of custom formats for each value in your data series. If you don't want to mess with writing and testing your own macros or creating a bunch of custom formats, you can always turn to add-ins written by others. Microsoft MVP Rob Bovey has created an excellent (free) add-in for Excel which includes an X-Y labeling feature among several others. It can be downloaded at this address:
http://www.appspro.com/Utilities/ChartLabeler.htm
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3503) 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: Labeling X-Y Scatter Plots.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Place a chart on a worksheet and you may not be satisfied with its size. Changing the size of a chart is a simple process ...
Discover MoreWhen creating charts that will be used by other people, you may need to take some liberties with the presentation of your ...
Discover MoreNeed to add a text box to your charting masterpiece? There are a couple of ways you can do so.
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