Plot and add best fit trend
Upcoming Power Excel Seminars
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 5 of 5

Thread: Plot and add best fit trend

  1. #1
    New Member
    Join Date
    Feb 2002
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

     
    I recorded this Macro to plot cells that I highlight, open as a new sheet and add an exponential trend displaying the equation and R^2 value. There are two problems: the macro does not plot the highlighted cells, rather it plots the entire columns; and when it is time to open the chart as a new sheet it stops because the sheet name is not changing, and cannot create two sheets with the same name.

    I would also like to add a few lines so that it goes through different trends and compares the R^2 values, therefore selecting the best fit. Any help will be greatly appreciated.

    Charts.Add
    ActiveChart.ChartType = xlXYScatter
    ActiveChart.SetSourceData Source:=Sheets("4-K0 2002-01-28 16-19-32").Range("G" & ":H"), PlotBy:=xlColumns
    ActiveChart.Location Where:=xlLocationAsObject, Name:= _
    "4-K0 2002-01-28 16-19-32"
    With ActiveChart
    .HasTitle = False
    .Axes(xlCategory, xlPrimary).HasTitle = True
    .Axes(xlCategory, xlPrimary).AxisTitle.Characters.Text = "time"
    .Axes(xlValue, xlPrimary).HasTitle = True
    .Axes(xlValue, xlPrimary).AxisTitle.Characters.Text = "mg/m^3"
    End With
    With ActiveChart.Axes(xlCategory)
    .HasMajorGridlines = False
    .HasMinorGridlines = False
    End With
    With ActiveChart.Axes(xlValue)
    .HasMajorGridlines = False
    .HasMinorGridlines = False
    End With
    ActiveChart.HasLegend = False
    ActiveChart.SeriesCollection(1).Trendlines.Add(Type:=xlExponential, Forward _
    :=0, Backward:=0, DisplayEquation:=True, DisplayRSquared:=True).Select
    ActiveChart.SeriesCollection(1).Trendlines(1).DataLabel.Select
    Selection.Left = 205
    Selection.Top = 52
    End Sub

  2. #2
    MrExcel MVP Damon Ostrander's Avatar
    Join Date
    Feb 2002
    Location
    Denver, Colorado USA
    Posts
    4,240
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hi Cmauras,

    First of all, to get the chart to use the selected rather than hard-wired range, change

    Sheets("4-K0 2002-01-28 16-19-32").Range("G" & ":H")

    to

    Selection

    In order to get a unique name each time, you must come up with a naming strategy. For example, if you want the chart name to contain the current date and time (as in your example, but updated to the current time), you could do this

    ..., Name:= _
    "4-K0 " & Format(Now(),"yyyy-mm-dd hh-mm-ss")

    which encodes the current time into the name in the same format you are using now.

    Sorry, but I don't have time right now to answer your R^2 question.
    Keep Excelling.

    Damon

    VBAexpert Excel Consulting
    LinkedIn Profile http://www.linkedin.com/pub/damon-ostrander/7/79/a93
    AllExperts Profile http://www.allexperts.com/ep/1059-30...-Ostrander.htm

  3. #3
    New Member
    Join Date
    Feb 2002
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Thank you for your reply. I tried using Selection, but it did not seem to work. Is there anything else to type on this command?

  4. #4
    MrExcel MVP Damon Ostrander's Avatar
    Join Date
    Feb 2002
    Location
    Denver, Colorado USA
    Posts
    4,240
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hi again cmauras,

    Yes, I see why the Selection won't work. When you create the chart without assigning it to an object variable, it becomes the selected object. To get around this simply save the selection before creating the chart:

    Dim SelData As Range

    Set SelData = Selection

    Charts.Add
    ActiveChart.ChartType = xlXYScatter
    ActiveChart.SetSourceData Source:=SelData, PlotBy:=xlColumns

    etc.




    Keep Excelling.

    Damon

    VBAexpert Excel Consulting
    LinkedIn Profile http://www.linkedin.com/pub/damon-ostrander/7/79/a93
    AllExperts Profile http://www.allexperts.com/ep/1059-30...-Ostrander.htm

  5. #5
    New Member
    Join Date
    Feb 2002
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

      
    Thank you Damon. This worked.

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  

 

 
DMCA.com