Capture x and y values from excel chart.

davidam

Active Member
Joined
May 28, 2010
Messages
474
Office Version
  1. 2021
Platform
  1. Windows
Hello All,
Does anyone know if it is possible to capture the values of x and y on a chart after mousing to the point in question on a chart. Looking for ideas; perhaps it can be done with a special mouse command or something.
Many thanks,
David
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
The following code will allow you to click on a data point, with the corresponding X and Y values being displayed in a message box. It assumes that the chart is an embedded chart, and that it's the first embedded chart in "Sheet1". Change the sheet name and chart reference, accordingly.

First, insert a Class module (Insert > Class Module), and put the following code in the module...

Code:
[FONT=Courier New][COLOR=darkblue]Option[/COLOR] [COLOR=darkblue]Explicit[/COLOR]

[COLOR=darkblue]Public[/COLOR] [COLOR=darkblue]WithEvents[/COLOR] clsChart [COLOR=darkblue]As[/COLOR] Chart


[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] clsChart_Select([COLOR=darkblue]ByVal[/COLOR] ElementID [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR], [COLOR=darkblue]ByVal[/COLOR] Arg1 [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR], [COLOR=darkblue]ByVal[/COLOR] Arg2 [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR])
    [COLOR=darkblue]Dim[/COLOR] x [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] y [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] Msg [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]String[/COLOR]
    [COLOR=darkblue]If[/COLOR] ElementID = xlSeries [COLOR=darkblue]Then[/COLOR]
        [COLOR=darkblue]If[/COLOR] Arg2 > 0 [COLOR=darkblue]Then[/COLOR]
            [COLOR=darkblue]With[/COLOR] ActiveChart
                x = .SeriesCollection(Arg1).XValues
                y = .SeriesCollection(Arg1).Values
                Msg = "X = " & x(Arg2) & vbCrLf
                Msg = Msg & "Y = " & y(Arg2)
                MsgBox Msg, vbInformation
            [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
End [COLOR=darkblue]Sub[/COLOR]
[/FONT]

Then, insert a standard module (Insert > Module), and put the following code in the module...

Code:
[FONT=Courier New][COLOR=darkblue]Dim[/COLOR] MyChart [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]New[/COLOR] Class1

[COLOR=darkblue]Sub[/COLOR] CaptureXYValues()
    [COLOR=darkblue]Set[/COLOR] MyChart.clsChart = Worksheets("Sheet1").ChartObjects(1).Chart [COLOR=#008000]'change the sheet name and chart reference accordingly[/COLOR]
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]
[/FONT]

Lastly, run the macro called "CaptureXYValues". Now, select the series, and then select the data point of interest.
 
Upvote 0
Thanks Domenic,
This looks great but I need to study up on class modules before I can fully grasp this. I will post back when I have had a chance to do so.
David
 
Upvote 0
Just a couple of quick notes...

When you insert a class module (Insert > Class Module), it names it Class1, Class2, Class3, etc. Therefore, make sure that the class name in the following declaration...

Code:
[COLOR=#00008B][FONT=Courier New]Dim [/FONT][/COLOR][COLOR=#574123][FONT=Courier New]MyChart [COLOR=#222222][FONT=Verdana][COLOR=#00008B][FONT=Courier New]As [/FONT][/COLOR][COLOR=#00008B][FONT=Courier New]New [/FONT][/COLOR][COLOR=#574123][FONT=Courier New]Class1[/FONT][/COLOR][/FONT][/COLOR][/FONT][/COLOR]

...matches the name of the class module. Actually, for clarity and something more meaningful, you might want to change the name of the class module (via the Properties window) to EmbChartClass and the declaration to...

Code:
[COLOR=#00008B][FONT=Courier New]Dim [/FONT][/COLOR][COLOR=#574123][FONT=Courier New]MyChart [COLOR=#222222][FONT=Verdana][COLOR=#00008B][FONT=Courier New]As [/FONT][/COLOR][COLOR=#00008B][FONT=Courier New]New [/FONT][/COLOR][/FONT][/COLOR][/FONT][/COLOR][COLOR=#574123][FONT=Courier New]EmbChartClass[/FONT][/COLOR]

Also, the macro "CaptureXYValues" can automatically be run when the workbook is opened. Or, alternatively, you can place a CheckBox on your worksheet, which you can check and uncheck in order to enable and disable the chart events.
 
Upvote 0

Forum statistics

Threads
1,214,534
Messages
6,120,084
Members
448,943
Latest member
sharmarick

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top