How to use a macro to add labels to data points in an xy scatter chart or in a bubble chart in Excel (213750)
The information in this article applies to:
- Microsoft Office Excel 2003
- Microsoft Excel 2002
- Microsoft Excel 2000
- Microsoft Excel 97 for Windows
- Microsoft Excel X for Mac
- Microsoft Excel 2001 for Mac
- Microsoft Excel 98 Macintosh Edition
This article was previously published under Q213750 SUMMARY In Microsoft Excel , there is no built-in command that
automatically attaches text labels to data points in an xy (scatter) or Bubble
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 on
an XY Scatter chart but the same code can be used for a Bubble
Chart.MORE INFORMATIONMicrosoft
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 a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft
Certified Partners, please visit the following Microsoft Web site: For more information about the support options that are available
and about how to contact Microsoft, visit the following Microsoft Web site: The sample code in this article assumes that the
data and associated labels are arranged in a worksheet according to the
following format:
- The first column contains the data labels.
- The second column contains the x values for the xy
(scatter) chart.
- The third and subsequent columns contain the y values for
the xy (scatter) chart.
NOTE: Although the example provided contains only one column of data
for y values, you can use more than one series of data. To use the
macros in this article, create a chart using the following data:
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 in exactly 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, follow these steps:
- On the worksheet that contains the sample data, select the
cell range B1:C6, and then click Chart on the Insert menu.
- In the Chart Wizard - Step 1 of 4 - Chart
Type dialog box, click the Standard Types tab. Under Chart type, click XY (Scatter), and then click Next.
- In the Chart Wizard - Step 2 of 4 - Chart Source
Data dialog box, click the Data Range tab. Under Series in, click Columns, and then click Next.
- In the Chart Wizard - Step 3 of 4 - Chart
Options dialog box, click Next.
- In the Chart Wizard - Step 4 of 4 -Chart
Location dialog box, click the As new sheet option,
and then click Finish.
- Press ALT+F11 to start the Visual Basic Editor.
- On the Insert menu, click Module.
- Type the following sample code in the module sheet:
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 - Press ALT+Q to return to Microsoft Excel.
- Switch to the chart sheet.
- On the Tools menu, point to Macro, and then click Macros. Click AttachLabelsToPoints, and then click Run to run the macro.
The macro attaches the labels in
cells A2:A6 to the data points on the chart.
Modification Type: | Minor | Last Reviewed: | 10/11/2006 |
---|
Keywords: | kbchart kbdtacode kbhowto kbinfo kbProgramming KB213750 |
---|
|