How to use LOGEST function with data sets that has Blank cell

kayyeah

New Member
Joined
Mar 10, 2016
Messages
7
Hello!

I was wondering if anyone could help me with following example:

A1 B1 C1 D1 E1 F1 G1 H1
121 132 323 123 231 212

How can do the LOGEST function by using following at cell H1:

=G1*LOGEST(A1:G1)

Since there is a blank cell at E1, is there any way to forecast by omitting the cell E1?

Thanks a lot!
Jay
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Hi Jay
Welcome to the board

Logest(), like Linest(), doesn't allow missing values.

You have to use just the number values in the range, like:

=G1*LOGEST(N(OFFSET(A1,,SMALL(IF(ISNUMBER(A1:G1),COLUMN(A1:G1)),ROW(INDIRECT("1:"&COUNT(A1:G1))))-1)))

This is an array formula, you have to confirm it with CTRL-SHIFT-ENTER and not just ENTER.
 
Last edited:
Upvote 0
Hi,

PGC's solution is fine, though it is volatile.

I prefer the shorter, non-volatile:

=G1*LOGEST(INDEX(1:1,N(IF(1,MODE.MULT(IF(ISNUMBER(A1:G1),{1;1}*COLUMN(A1:G1)))))))


Regards
 
Upvote 0
Jay, I'm glad it helped.


XOR LX, great use of the Mode.Mult to get the list of the columns.
 
Upvote 0
XOR LX, great use of the Mode.Mult to get the list of the columns.

But it might be noted that it works only in Excel 2010 and later, when MODE.MULT was introduced.

I don't believe Jay ever indicated the version of Excel that is used.
 
Upvote 0
Hi XOR LX,

Thanks a lot for the help! I was wondering why did you use IF(1,MODE.MULT(IF(ISNUMBER(A1:G1),{1;1}*COLUMN(A1:G1))). I am not quiet sure about the first IF function as highlighted before.

Thank you very much!
Kind Regards,
Jay
 
Upvote 0
Hi XOR LX,

Thanks a lot for the help! I was wondering why did you use IF(1,MODE.MULT(IF(ISNUMBER(A1:G1),{1;1}*COLUMN(A1:G1))). I am not quiet sure about the first IF function as highlighted before.

Thank you very much!
Kind Regards,
Jay





Hi,

PGC's solution is fine, though it is volatile.

I prefer the shorter, non-volatile:

=G1*LOGEST(INDEX(1:1,N(IF(1,MODE.MULT(IF(ISNUMBER(A1:G1),{1;1}*COLUMN(A1:G1)))))))


Regards
 
Upvote 0

Forum statistics

Threads
1,213,558
Messages
6,114,296
Members
448,564
Latest member
ED38

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