Linest and the if function

Thanks Thanks:  0
Likes Likes:  0
Page 1 of 2 12 LastLast
Results 1 to 10 of 12

Thread: Linest and the if function

  1. #1
    New Member
    Join Date
    Jan 2016
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Linest and the if function

     
    I've been working on this for about a week now. I am new to this site, but have read through previous linest problems. Sadly, I couldn't incorporate any to my specific case.

    I am trying to set up a worksheet so that it gives a graph with a regression line and the R^2 (accomplished),calculates a low, ideal, and high values for the different regression lines (accomplished), and chooses the best regression line given R^2(accomplished).

    The problem: Setting this up so that no formulas need to be changed given different quantities of cells. I had it working fine for a 10 shot process, but if any cells were left blank (i.e. 8 shot process) it returned a #value. I managed to use an if statement to work around this if 1 cell is blank. Although I must say it seems like the value if true and value if false should be switched (doesn't work that way). If excel had a loop function my life would be so much easier.

    I can provide an example worksheet that has left out all the fancy stuff and focuses on creating a linest function that works for different amounts of cells, but I am not seeing where to attach documents on this site.

    Thank you for any help you may provide.

  2. #2
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    81,436
    Post Thanks / Like
    Mentioned
    9 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    It is more convenient to have the sample data directly on the forum. Try to post an Excel readable, scaled-down small sample, using one of the methods listed in the following: Attachments or using this add-in:https://app.box.com/s/soezox25h3w0q5s4rcyl.
    Assuming too much and qualifying too much are two faces of the same problem.

  3. #3
    New Member
    Join Date
    Jan 2016
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    Thanks buddy, how is this?

    =LINEST(IF(O3:O12="",O3:O12,O3:O11),IF(N3:N12="",N3:N12,N3:N11),TRUE,TRUE)
    this works for this table
    x y
    Shot 1 100 1
    Shot 2 200 2
    Shot 3 300 3
    Shot 4 400 4
    Shot 5 500 5
    Shot 6 600 6
    Shot 7 700 7
    Shot 8 800 8
    Shot 9 900 9
    Shot 10

    Im not sure how to make one equation accommodate any variation in shot #'s like so. Luckily there will always be the same amount of x and y's.

    Shot 1 100 1
    Shot 2 200 2
    Shot 3 300 3
    Shot 4 400 4
    Shot 5 500 5
    Shot 6
    Shot 7
    Shot 8
    Shot 9
    Shot 10
    Last edited by stretch2011; Jan 2nd, 2016 at 02:35 AM.

  4. #4
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    81,436
    Post Thanks / Like
    Mentioned
    9 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    Thanks for the inline samples...

    Is this what you are after?
    Code:
    
    =LINEST(O3:INDEX(O:O,MATCH(9.99999999999999E+307,O:O)),
             N3:INDEX(N:N,MATCH(9.99999999999999E+307,O:O)),TRUE,TRUE)
    
    Assuming too much and qualifying too much are two faces of the same problem.

  5. #5
    New Member
    Join Date
    Jan 2016
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    You sir, are awesome!

    Would it be too much for you to explain this formula? I like to know how things work.

  6. #6
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    81,436
    Post Thanks / Like
    Mentioned
    9 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    Quote Originally Posted by stretch2011 View Post
    You sir, are awesome!

    Would it be too much for you to explain this formula? I like to know how things work.
    1.

    MATCH(9.99999999999999E+307,O:O)

    delivers the native row number of the last numeric value of column O.

    2.

    O3:INDEX(O:O,MATCH(9.99999999999999E+307,O:O))

    means the range from O3 to the last numeric value of column O.

    3.

    N3:INDEX(N:N,MATCH(9.99999999999999E+307,O:O))

    means likewise the range from N3 to the value that corresponds to the last numeric value of column O.

    If you would want to pick out the shortest range as specifier for the size of data points...

    In M2 enter:
    Code:
    
    =MIN(MATCH(9.99999999999999E+307,N:N),MATCH(9.99999999999999E+307,O:O))
    
    Once we have M2, we can run:
    Code:
    =LINEST(O3:INDEX(O:O,M2),N3:INDEX(N:N,M2),TRUE,TRUE)
    See in addition: http://www.mrexcel.com/forum/excel-questions/102091-9-9999999-a.html.
    Assuming too much and qualifying too much are two faces of the same problem.

  7. #7
    Board Regular
    Join Date
    Oct 2012
    Posts
    204
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    If you are doing simple straight line linear regression (i.e. just 2 parameters, slope and intercept) - and all you want are the coefficients and R^2 value then you could use the SLOPE(), INTERCEPT() and RSQ() functions as these handle blanks no problems.

  8. #8
    New Member
    Join Date
    Jan 2016
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    Thank you Aladin, very helpful.
    GooberTrop: I am not, I'm doing all the regressions except for polynomials.


    One more question if I may.

    Do you know the linest, or logest equation for an exponential regression and a power regression?

  9. #9
    New Member
    Join Date
    Jan 2016
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

    Let me rephrase that. Do you know the linest, or logest "function" for an exponential regression and a power regression? I know the y= equations.

  10. #10
    Board Regular
    Join Date
    Oct 2012
    Posts
    204
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Linest and the if function

      
    I would usually log-transform these and then fit a linear model.
    Some pages here if you haven't seen them.
    Exponential Linear Regression | Real Statistics Using Excel
    Power Regression | Real Statistics Using Excel

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