Blank Cells and LINEST

Tony Collins

New Member
Joined
Jun 5, 2009
Messages
2
I have been trying to use LINEST for the analysis of a large sets of data but have just noticed that this function does not allow for empty cells in the data set. Apart from the tredious possibility of removing the blank cells (which is not really possible for the large quantity of data involved) does anybody have any suggestions?

I have tried using the following but have not had any success:
=LINEST(IF(A3:A54=0,"",A3:A54),IF(B3:B54=0,"",B3:B54),,TRUE)

=LINEST(IF(ISNUMBER(A3:A54),A3:A54,""),IF(ISNUMBER(B3:B54),B3:B54,""))

I do not want the formula to take the empty cells as being 0 but to exclude them from the calculation.

All help would be greatly appreciated.
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Enter this as an array formula (Ctrl+Shift+Enter):
Code:
=LINEST(IF(A3:A54="",A3,A3:A54),IF(B3:B54="",B3,B3:B543))
 
Upvote 0
Another possibility:

=LINEST(N(OFFSET(A3:A54,SMALL(IF(ISNUMBER(A3:A54),ROW(A3:A54)-ROW(A3)),ROW(INDIRECT("1:"&COUNT(A3:A54)))),,1)),N(OFFSET(B3:B54,SMALL(IF(ISNUMBER(B3:B54),ROW(B3:B54)-ROW(B3)),ROW(INDIRECT("1:"&COUNT(B3:B54)))),,1)))

also with Ctrl+Shift+Enter.
 
Upvote 0
Enter this as an array formula (Ctrl+Shift+Enter):
Code:
=LINEST(IF(A3:A54="",A3,A3:A54),IF(B3:B54="",B3,B3:B543))

Econometrics class from years ago is flooding back to me... On second thought, while avoiding the error, this method may skew your results, so you should probably check the answer above, although I'm not sure what his solution is doing.
 
Upvote 0
Thank you both very much for the rapid replies.
However these solutions do not seem to be working, it appears that Phoxs suggestion has the problem of replacing the empty cell with the value in cell A3 ('value if TRUE' in logical test).
Mr Poulsoms suggestion appears close (even though its complexity baffles me, I don't really understand it), but only appears to work if the cells for corresponding x and y values are BOTH empty.
In my case the X valuse are constant while the Y values vary, with the Y values frequently containing empty cells or indeed 0.
I am surprised that EXCEL don't seem to have a means for the function to ignore empty cellls or those containing 0 when carrying out a LINEST calculation.
I'm actually not too sure if it is possible to regulate this problem with EXCEL.
Thank you.
 
Upvote 0
Stick around Tony. I'm sure Andrew can alter his formula to accomodate. I doubt he expected only one of the values would be blank.
 
Upvote 0
Andrew's formula can be modified as follows...

Code:
=LINEST(N(OFFSET(A3:A54,SMALL(IF(B3:B54<>0,ROW(B3:B54)-ROW(B3)),
     ROW(INDIRECT("1:"&COUNT(B3:B54)))),,1)),N(OFFSET(B3:B54,
          SMALL(IF(B3:B54<>0,ROW(B3:B54)-ROW(B3)),ROW(INDIRECT("1:"&
               COUNT(B3:B54)))),,1)))

...confirmed with CONTROL+SHIFT+ENTER. If, however, the so-called empty cells actually contain formula blanks (""), the formula would need to be modified further.

Edit: Actually, I guess it should be the other way around...

Code:
=LINEST(N(OFFSET(A3:A54,SMALL(IF(A3:A54<>0,ROW(A3:A54)-ROW(A3)),
     ROW(INDIRECT("1:"&COUNT(A3:A54)))),,1)),N(OFFSET(B3:B54,
          SMALL(IF(A3:A54<>0,ROW(A3:A54)-ROW(A3)),ROW(INDIRECT("1:"&
               COUNT(A3:A54)))),,1)))
 
Last edited:
Upvote 0
I was able to work Domenic's formula if the cell values were vertically placed. I tried to modified the formula(see below) for cell values placed horizontally, however I keep getting "#Value!". I'm not sure if my formula is correctly modified.

Code:
=LINEST(N(OFFSET(B15:K15,,SMALL(IF(B15:K15<>0,COLUMN(B15:K15)-COLUMN(B15)),
COLUMN(INDIRECT("1:"&COUNT(B15:K15)))),1,)),N(OFFSET(B16:K16,,
SMALL(IF(B15:K15<>0,COLUMN(B15:K15)-COLUMN(B15)),COLUMN(INDIRECT("1:"&
COUNT(B15:K15)))),1,)))
 
Upvote 0
Some of the ROW functions need to remain as ROW, even for horizontal ranges of data - try this version

=LINEST(N(OFFSET(B15:K15,,SMALL(IF(B15:K15<>0,COLUMN(B15:K15)-COLUMN(B15)),ROW(INDIRECT("1:"&COUNT(B15:K15)))),1,)),N(OFFSET(B16:K16,,SMALL(IF(B15:K15<>0,COLUMN(B15:K15)-COLUMN(B15)),ROW(INDIRECT("1:"&COUNT(B15:K15)))),1,)))
 
Upvote 0
Perfect.... essentially I am trying to calculate a multiple regression, with the "y" variable having blanks or "-" at times. If the "y" variables has blanks or "-" the regression ignores the calculation for that paired series. I did an independent multiple regression compared to my formula and I get different answers.

X variables : BQ11:DX12
Y variables : BQ18:DX18


=INDEX(LINEST(N(OFFSET(BQ18:DX18,,SMALL(IF(BQ18:DX18<>0,COLUMN(BQ18:DX18)-COLUMN(BQ18)),ROW(INDIRECT("1:"&COUNT(BQ18:DX18)))),1,)),N(OFFSET(BQ11:DX12,,SMALL(IF(BQ18:DX18<>0,COLUMN(BQ18:DX18)-COLUMN(BQ18)),ROW(INDIRECT("1:"&COUNT(BQ18:DX18)))),1,)),TRUE,TRUE),1,1)+INDEX(LINEST(N(OFFSET(BQ18:DX18,,SMALL(IF(BQ18:DX18<>0,COLUMN(BQ18:DX18)-COLUMN(BQ18)),ROW(INDIRECT("1:"&COUNT(BQ18:DX18)))),1,)),N(OFFSET(BQ11:DX12,,SMALL(IF(BQ18:DX18<>0,COLUMN(BQ18:DX18)-COLUMN(BQ18)),ROW(INDIRECT("1:"&COUNT(BQ18:DX18)))),1,)),TRUE,TRUE),1,2)

ctrl+shift+enter
 
Upvote 0

Forum statistics

Threads
1,213,495
Messages
6,113,992
Members
448,538
Latest member
alex78

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