vba to get name of series collection point on chart

dodger7

Board Regular
Joined
Mar 19, 2009
Messages
137
Hi Guys

Ive got a workbook with 5 sheets, all having at least 3 charts on each sheet. Im writing a bit code to change the color of each series point, depending on the name of the point.

Each point will always end in either Q1, Q2, Q3 or Q4.
Ive pretty much got the code, except I cant get the syntax for the variable 'ptname':


Code:
For Each sh In ActiveWorkbook.Worksheets
For Each ch In c.ChartObjects
For Each sc In p.Chart.SeriesCollection
For Each pt In m.Points
 
ptname = WorksheetFunction.Index(sh.ch.sc.XValues, pt)
 
Select Case Right(ptname, 2)
 
Case Is = "Q1"
'color for Q1
 
Case Is = "Q2"
'color for Q2
 
Case Is = "Q3"
'color for Q3
 
Case Is = "Q4"
'color for Q4
 
End Select
 
 
 
Next pt
Next sc
Next ch
Next sh

Any suggestions greatly appreciated!
Thanks
Jamie
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Hi Jamie

I'll assume that you want in ptname the XValue of the point.

Try:
Code:
Sub FormatPoints()
Dim sh As Worksheet
Dim ch As ChartObject
Dim sc As Series
Dim pt As Point
Dim lpt As Long
Dim ptname As String
 
For Each sh In ActiveWorkbook.Worksheets
    For Each ch In sh.ChartObjects
        For Each sc In ch.Chart.SeriesCollection
            For lpt = 1 To sc.Points.Count
 
                Set pt = sc.Points(lpt)
                ptname = sc.XValues(lpt)
                 
                Select Case Right(ptname, 2)
                 
                Case Is = "Q1"
                'color for Q1
                 
                Case Is = "Q2"
                'color for Q2
                 
                Case Is = "Q3"
                'color for Q3
                 
                Case Is = "Q4"
                'color for Q4
                 
                End Select
            Next lpt
        Next sc
    Next ch
Next sh
End Sub
 
Upvote 0
Here's an example:

Code:
Sub Test()
    Dim Ser As Series
    Dim i As Integer
    Dim ptname As String
    With ActiveSheet.ChartObjects(1).Chart
        For Each Ser In .SeriesCollection
            For i = 1 To Ser.Points.Count
                ptname = WorksheetFunction.Index(Ser.XValues, i)
                MsgBox ptname
            Next i
        Next Ser
    End With
End Sub
 
Upvote 0
this doesn't work for me. when I run this the 1st value returns a 1 and the subsequent values return the xvalue value. any ideas on what may be causing this?

Here's an example:

Code:
Sub Test()
    Dim Ser As Series
    Dim i As Integer
    Dim ptname As String
    With ActiveSheet.ChartObjects(1).Chart
        For Each Ser In .SeriesCollection
            For i = 1 To Ser.Points.Count
                ptname = WorksheetFunction.Index(Ser.XValues, i)
                MsgBox ptname
            Next i
        Next Ser
    End With
End Sub
 
Upvote 0
I have used an adodb recordset to load the hard coded values into the chart and the xvalues series.
 
Upvote 0
the recordset contains 2 columns. one contains the labels which are used as the xvalues series entries and the second is integer value. the values are then loaded into 2 arrays and the charts are set using fullseriescollection.xvalues = "{" & strArrayVals & "}". thanks for your help on this.
 
Upvote 0
apologies, a correction to the above, the labels and values are loaded into their separate arrays and input into the chart using their relevant .xvalues or .values properties.
 
Upvote 0

Forum statistics

Threads
1,213,527
Messages
6,114,148
Members
448,552
Latest member
WORKINGWITHNOLEADER

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