Chart - vba to color scatter plot based on cells color

mfarr76

New Member
Joined
Jan 3, 2014
Messages
36
Hello,

I have a macro that will create a scatter plot and then color all the curve to a specific color that I hard code in.

I would like more freedom with this and have the macro color the curves based on the cell color that the series name resides in. The example below would plot the "Michael" curve in blue and so forth.

The vba code below is what I am currently working with.

Any help would be greatly appreciated!!!

Excel 2012
CDEF
1DaysMichaelAshleyChris
211582.932779.21731.09
324340.137057.534774.47
434837.47449.114869.77

<tbody>
</tbody>


Code:
Sub CreateChart()

    Dim c As Object
    Dim d As Object
    Dim i As Integer
    
    With activecell.CurrentRegion.Select
        ActiveSheet.Shapes.AddChart2 201, xlXYScatterSmoothNoMarkers
        ActiveSheet.ChartObjects(ActiveSheet.ChartObjects.Count).Name = "Chart1"
        ActiveSheet.ChartObjects("Chart1").Activate
        ActiveChart.Axes(xlValue).Select
        ActiveChart.Axes(xlValue).MinimumScale = 0
        ActiveChart.Legend.Select
        Selection.Delete
    End With
'alternate series colors
    i = 0
    For Each c In ActiveSheet.ChartObjects
        For Each d In c.Chart.SeriesCollection
            If i Mod 2 = 0 Then
                d.Border.ColorIndex = 15
            Else
                d.Border.ColorIndex = 15
            End If
            i = i + 1
            Next d
            Next c
End Sub



 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
Maybe something like this...

Code:
[color=darkblue]Option[/color] [color=darkblue]Explicit[/color]

[color=darkblue]Sub[/color] CreateChart()

    [color=darkblue]Dim[/color] rChrtData [color=darkblue]As[/color] Range
    [color=darkblue]Dim[/color] rChrtXVals [color=darkblue]As[/color] Range
    [color=darkblue]Dim[/color] rChrtVals [color=darkblue]As[/color] Range
    [color=darkblue]Dim[/color] rSeriesName [color=darkblue]As[/color] Range
    [color=darkblue]Dim[/color] lCol [color=darkblue]As[/color] [color=darkblue]Long[/color]
    
    [color=darkblue]Set[/color] rChrtData = ActiveCell.CurrentRegion
    
    [color=darkblue]With[/color] rChrtData
        [color=darkblue]Set[/color] rChrtXVals = .Offset(1, 0).Resize(.Rows.Count - 1, 1)
        [color=darkblue]Set[/color] rChrtVals = .Offset(1, 1).Resize(.Rows.Count - 1, .Columns.Count - 1)
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=darkblue]With[/color] ActiveSheet.Shapes.AddChart2(201, xlXYScatterSmoothNoMarkers)
        .Name = "Chart1"
        [color=darkblue]With[/color] .Chart
            [color=darkblue]Do[/color] [color=darkblue]While[/color] .SeriesCollection.Count > 0
                .SeriesCollection(1).Delete
            [color=darkblue]Loop[/color]
            [color=darkblue]For[/color] lCol = 1 [color=darkblue]To[/color] rChrtVals.Columns.Count
                [color=darkblue]With[/color] .SeriesCollection.NewSeries
                    .XValues = rChrtXVals
                    .Values = rChrtVals.Columns(lCol)
                    [color=darkblue]Set[/color] rSeriesName = rChrtVals.Columns(lCol).Offset(-1).Resize(1)
                    .Name = rSeriesName.Value
                    .Format.Line.ForeColor.RGB = rSeriesName.Interior.Color
                [color=darkblue]End[/color] [color=darkblue]With[/color]
            [color=darkblue]Next[/color] lCol
            .Legend.Delete
        [color=darkblue]End[/color] [color=darkblue]With[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]

[color=darkblue]End[/color] [color=darkblue]Sub[/color]

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,215,528
Messages
6,125,342
Members
449,218
Latest member
Excel Master

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