Linest and the if function

stretch2011

New Member
Joined
Jan 1, 2016
Messages
6
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.
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
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
xy
Shot 11001
Shot 22002
Shot 33003
Shot 44004
Shot 55005
Shot 66006
Shot 77007
Shot 88008
Shot 99009
Shot 10

<tbody>
</tbody>

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 11001
Shot 22002
Shot 33003
Shot 44004
Shot 55005
Shot 6
Shot 7
Shot 8
Shot 9
Shot 10

<tbody>
</tbody>
 
Last edited:
Upvote 0
Thanks for the inline samples...

Is this what you are after?
Rich (BB code):

=LINEST(O3:INDEX(O:O,MATCH(9.99999999999999E+307,O:O)),
         N3:INDEX(N:N,MATCH(9.99999999999999E+307,O:O)),TRUE,TRUE)
 
Upvote 0
You sir, are awesome!

Would it be too much for you to explain this formula? I like to know how things work.
 
Upvote 0
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:
Rich (BB code):

=MIN(MATCH(9.99999999999999E+307,N:N),MATCH(9.99999999999999E+307,O:O))
Once we have M2, we can run:
Rich (BB 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.
 
Upvote 0
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.
 
Upvote 0
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?
 
Upvote 0
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.
 
Upvote 0

Forum statistics

Threads
1,213,567
Messages
6,114,342
Members
448,570
Latest member
rik81h

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