Updating chart sourcedata range in VBA

tpmcavoy

New Member
Joined
Aug 27, 2009
Messages
2
I am relatively new to VBA and I am having trouble updating the sourecdata for a chart in VBA. Recording a macro for it yeilded:

Sheets("Rating Chart").Select
ActiveSheet.ChartObjects("Chart 1").Activate
ActiveChart.ChartArea.Select
ActiveChart.SetSourceData Source:=Sheets("Summary").Range("AA2:AB61"), _
PlotBy:=xlColumns

I want to dynamically determine how many rows of data I have and update the source range accordinly.

I locate the last row of data using:
FinalRow = Sheets("Summary").Cells(Rows.Count, 27).End(xlUp).Row

I then try to update the source range using the following:

ActiveChart.SetSourceData _
Source:=Sheets("Summary").Range(Cells(2, 27), Cells(FinalRow, 28)), _
PlotBy:=xlColumns

Using the Cells in the Range seems to be my problem but I don't know how to vary the range any other way. Any help would be greatly appreciated. Thank you.
 

mvptomlinson

Well-known Member
Joined
Mar 10, 2008
Messages
2,638
Perhaps:
Code:
FinalRow = Sheets("Summary").Cells(Sheets("Summary").UsedRange.Rows.Count, 27).End(xlUp).Row

ActiveChart.SetSourceData Source:=Sheets("Summary").Range("AA2:AB" & FinalRow), PlotBy:=xlColumns
 

wigi

Well-known Member
Joined
Jul 10, 2006
Messages
7,944
For instance,

Code:
ActiveChart.SetSourceData _
Source:=Sheets("Summary").Range("AA2:AB" & FinalRow), _
PlotBy:=xlColumns
 

Jon Peltier

MrExcel MVP
Joined
May 14, 2003
Messages
4,726
FWIW, the reason this didn't work

Code:
ActiveChart.SetSourceData _
    Source:=Sheets("Summary").Range(Cells(2, 27), Cells(FinalRow, 28)), _
    PlotBy:=xlColumns
is that VBA doesn't know what the Cells inside the parentheses refer to. This should work:


Code:
ActiveChart.SetSourceData _
    Source:=Sheets("Summary").Range(Sheets("Summary").Cells(2, 27), Sheets("Summary").Cells(FinalRow, 28)), _
    PlotBy:=xlColumns
 

Forum statistics

Threads
1,081,690
Messages
5,360,614
Members
400,592
Latest member
badgergurl

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top