ID: Q161513
In Microsoft Excel, there is no built-in command that automatically attaches text labels to data points in an xy (scatter) chart. However, you can create a Microsoft Visual Basic for Applications macro that does this. This article contains a sample macro that performs this task.
Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/refguide/
The code example in this article assumes that data and associated labels are arranged on a worksheet in the following format:
To use the macros in this article, create a chart using the following data, and then use the appropriate steps:
A1: Labels B1: X Values C1: Y Values
A2: DataPoint1 B2: 12 C2: 5
A3: DataPoint2 B3: 9 C3: 7
A4: DataPoint3 B4: 5 C4: 3
A5: DataPoint4 B5: 4 C5: 8
A6: DataPoint5 B6: 1 C6: 4
NOTE: The table should not contain empty columns, and the column that
contains the data labels should not be separated from the column that
contains the x values. The labels and values must be laid out EXACTLY in
the format described in this article. (The upper-left cell does not have to
be cell A1.)
To attach text labels to data points in an xy (scatter) chart in Excel 97 and Excel 98, follow these steps:
1. On the worksheet that contains the sample data, select the cell range
B1:C6, and then click Chart on the Insert menu.
2. In the "Chart Wizard - Step 1 of 4" dialog box, click the Standard
Types tab. Under Chart Type, click XY (Scatter), and then click Next.
3. In the "Chart Wizard - Step 2 of 4" dialog box, click the Data Range
tab. Under Series In, click Columns, and then click Next.
4. In the "Chart Wizard - Step 3 of 4" dialog box, click Next.
5. In the "Chart Wizard - Step 4 of 4" dialog box, click As New Sheet, and
then click Finish.
6. Press ALT+F11 to start the Visual Basic Editor.
7. On the Insert menu, click Module. Type the sample code found in the
"Sample Visual Basic Code" section of this article.
8. Press ALT+Q to return to Microsoft Excel.
9. Switch to the chart sheet.
10. On the Tools menu, point to Macro, and then click Macros. Click the
AttachLabelsToPoints macro, and then click Run to run the macro.
The macro attaches the labels in cells A2:A6 to the data points on the
chart.
To attach text labels to data points in an xy (scatter) chart in Microsoft Excel 5.0 or 7.0, follow these steps:
1. On the worksheet that contains the sample data, select the cell range
B1:C6. On the Insert menu, point to Chart, and then click As New Sheet.
2. In the "Chart Wizard - Step 1 of 5" dialog box, click Next.
3. In the "Chart Wizard - Step 2 of 5" dialog box, click XY (Scatter), and
then click Next.
4. In the "Chart Wizard - Step 3 of 5" dialog box, click Next.
5. In the "Chart Wizard - Step 4 of 5" dialog box, select the following
options:
Data Series in: Columns
Use First 1 Column(s) for X Data
Use First 1 Row(s) for Legend Text
and then click Finish.
6. On the Insert menu, point to Macro, and then click Module. In the
module, type the macro in the "Sample Visual Basic Code" section of this
article.
7. Switch to the chart sheet.
8. On the Tools menu, click Macro. Click the AttachLabelsToPoints macro,
and then click Run to run the macro.
The macro attaches the labels in cells A2:A6 to the data points on the
chart.
Sub AttachLabelsToPoints()
'Dimension variables.
Dim Counter As Integer, ChartName As String, xVals As String
' Disable screen updating while the subroutine is run.
Application.ScreenUpdating = False
'Store the formula for the first series in "xVals".
xVals = ActiveChart.SeriesCollection(1).Formula
'Extract the range for the data from xVals.
xVals = Mid(xVals, InStr(InStr(xVals, ","), xVals, _
Mid(Left(xVals, InStr(xVals, "!") - 1), 9)))
xVals = Left(xVals, InStr(InStr(xVals, "!"), xVals, ",") - 1)
Do While Left(xVals, 1) = ","
xVals = Mid(xVals, 2)
Loop
'Attach a label to each data point in the chart.
For Counter = 1 To Range(xVals).Cells.Count
ActiveChart.SeriesCollection(1).Points(Counter).HasDataLabel = _
True
ActiveChart.SeriesCollection(1).Points(Counter).DataLabel.Text = _
Range(xVals).Cells(Counter, 1).Offset(0, -1).Value
Next Counter
End Sub
Additional query words: XL97 vba vbe xy-scatter bubble
Keywords : kbprg kbdta kbdtacode PgmLoop KbVBA xlchart
Version : WINDOWS: 5.0, 5.0c, 7.0, 7.0a, 97; MACINTOSH: 5.0, 5.0a, 98
Platform : MACINTOSH WINDOWS
Issue type : kbinfo
Last Reviewed: May 18, 1999