Dynamic Range

Littlemalky

Board Regular
Joined
Jan 14, 2011
Messages
223
Ok, I need to be able to return the left-most cell value that is not a 0 so I can plug this into a CAGR calculation. I'm trying to work with a dynamic offset, but can't seem to get it to work properly to omit zero in the range. I need one formula that references the entire range of values in row 2. Row 1 represents the years.

Example, I need to be able to return 100 with a formula. However, if 2018 had a value other than zero, then I would need to return that instead. Any advice?

201820192020202120222023
0100200300400500

<tbody>
</tbody>
 

Some videos you may like

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop

StephenCrump

MrExcel MVP
Joined
Sep 18, 2013
Messages
4,046
Office Version
  1. 365
Platform
  1. Windows
Or this (given that values can presumably fall lower than the start value):

=INDEX(A2:F2,MATCH(TRUE,INDEX(A2:F2<>0,),))
 

Littlemalky

Board Regular
Joined
Jan 14, 2011
Messages
223
Thank you! I ended up finding SMALL(H8:M8,COUNTIF(H8:M8,0)+1) online somewhere. It seems to be working for me so far. Do you guys see any problems with it?
 

StephenCrump

MrExcel MVP
Joined
Sep 18, 2013
Messages
4,046
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Do you guys see any problems with it?

What about if the 2019 value is 100, but in 2020 (or some later year) it falls to, say, 95?
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
What about if the 2019 value is 100, but in 2020 (or some later year) it falls to, say, 95?

...and if there are formulas in the range or text in the range for some reason:

Either control+shift+enter...

=INDEX(A2:F2,MATCH(TRUE,ISNUMBER(1/A2:F2),0))

Or just enter...

=INDEX(A2:F2,MATCH(TRUE,INDEX(ISNUMBER(1/A2:F2),0),0))
 

Watch MrExcel Video

Forum statistics

Threads
1,123,281
Messages
5,600,704
Members
414,401
Latest member
grenona2020

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
Top