XL: Macro to Add Labels to Points in an XY (Scatter) Chart

Last reviewed: February 3, 1998
Article ID: Q161513

The information in this article applies to:
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition

SUMMARY

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.

MORE INFORMATION

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 engineers 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/default.asp

Sample Data

The code example in this article assumes that data and associated labels are arranged on a worksheet in 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 contains the y values for the xy (scatter) chart.

NOTE: Although the example provided only contains 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, and then use the appropriate steps:

   A1: Labels       B1: X Values   C1: Y Values
   A2: DataPoint1   B2: 2          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.)

Microsoft Excel 97 and Microsoft Excel 98

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.

Microsoft Excel 5.0 or 7.0

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.

Sample Visual Basic Code

   Sub AttachLabelsToPoints()

      ' Dimension variables.
      Dim Counter As Integer, ChartName As Variant
      Dim SourceWorksheet As Variant, xVals As Variant, xCell As Variant
      Dim xLabel As Variant

      ' Disable screen updating while the subroutine is run.
      Application.ScreenUpdating = False

      ' Store the definition of the first series in "xVals."
      xVals = ActiveChart.SeriesCollection(1).Formula

      ' These lines extract the name of the source worksheet from xVals.
      SourceWorksheet = Left(xVals, InStr(1, xVals, "!") - 1)
      SourceWorksheet = Right(SourceWorksheet, Len(SourceWorksheet) - _
        InStr(1, SourceWorksheet, "("))
      If Left(SourceWorksheet, 1) = "," Then
         SourceWorksheet = Right(SourceWorksheet, Len(SourceWorksheet) - 1)
      End If

      ' Replace the actual source worksheet name with "xlSheet" so that the
      ' searches that follow work correctly when the worksheet name
      ' contains commas.
      xVals = Application.Substitute(xVals, SourceWorksheet, "xlSheet")

      ' More processing of the xVals name
      xVals = Right(xVals, Len(xVals) - InStr(1, xVals, ","))

      ' If the chart is using "assumed" x-values, display an alert
      ' message.
      If Left(xVals, 1) = "," Then

         ' NOTE: the following two lines should be typed
         ' as a single line.
         MsgBox "This X-Y scatter chart is using assumed X values." & _
           " The macro cannot continue."

         ' Quit the subroutine if "assumed" x-values are in use.
         Exit Sub
      End If

      ' More processing of the xVals name
      xVals = Left(xVals, InStr(1, xVals, ",") - 1)

      ' Put the original source worksheet name back into xVals, replacing
      ' "xlSheet."
      xVals = Application.Substitute(xVals, "xlSheet", SourceWorksheet)

      ' Initialize counter to number of series in chart.
      countseries = ActiveChart.SeriesCollection.Count

      ' Repeat procedure one time for each series in chart.
      For xSeries = 1 To countseries

      ' Initialize a counter.
      Counter = 1

      ' For each cell in the range xVals...
          For Each xCell In Range(xVals)

         ' Get the value of the label next to the current x value.
         xLabel = xCell.Offset(0, -1).Value

         ' Attach a label to the current data point in the chart.
         ActiveChart.SeriesCollection(xSeries).Points(Counter) _
           .HasDataLabel = True

         ' Put the text (DataPoint1, for example) into the attached
         ' label.

         ActiveChart.SeriesCollection(xSeries).Points(Counter) _
           .DataLabel.Text = xLabel

         ' Increment the counter.
         Counter = Counter + 1
         Next xCell                          ' Loop until finished.
      Next xSeries
      ' Ensures that nothing in the chart is selected.
      Application.ExecuteExcel4Macro "SELECT("""")"
   End Sub


Additional query words: XL97 vba vbe xy-scatter bubble
Keywords : kbcode kbprg xlvbainfo xlchart PgmLoop
Version : WINDOWS: 5.0, 5.0c, 7.0, 7.0a, 97; MACINTOSH: 5.0, 5.0a, 98
Platform : MACINTOSH WINDOWS
Issue type : kbinfo


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.