finding the lowest value in from peak to peak

cloobless

Board Regular
Joined
Jul 15, 2014
Messages
84
Office Version
  1. 2010
Platform
  1. Windows
Hi, there. I'm trying (unsuccessfully) to figure out how to calculate column L. Is there a way to identify the low value in each sequence of K "days under" data in something like the L column faked below? The formulas I returned don't seem to be checking the whole sequence, or identify the wrong value, or neither. Thank you to anyone who might see this.

The columns are:
F is the value on any given date
H looks for the highest peak value and keeps outputting it until a new peak comes
K is a count of days in a row that the F-value is still under the peak
L -- looks at all the sequential days' values under last peak and determines which is the lowest. This is the formula I cannot solve.


Any ideas for L? Thank you very much.



a8sgFYR.jpg




 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Hi cloobless,

Paste the following into cell M3 and confirm with Ctrl+Shift+Enter (array formula):

=IF(K3<>"New Peak",IF(F3=MIN(INDIRECT(ADDRESS(MATCH(2,1/(FIND("New Peak",$K$2:K3)))+2,6)):INDIRECT(ADDRESS(ROW()+MATCH("New Peak",K4:K1000,0)-1,6))),F3,""),"")

I'm certain a better solution exists but that's the only formula I could come up with. I hope it helps.
 
Upvote 0
JustynaMK, thank you *very* much. That works perfectly (and is impressive). Thank you for taking your time to help me; I really appreciate it.
 
Upvote 0
JustynaMK, a quick question. If one (large) returns N/A, what does it mean? Is it the size of the range that is a problem? The formula works in the array just before this large array and after it, too...
 
Upvote 0
Hi cloobless, which row number is that? And how many days are in the new peak?
Maybe also test individual components of the formula and let me know which one returns an error (enter the first one using Ctrl+Shift+Enter):
=ADDRESS(MATCH(2,1/(FIND("New Peak",$K$2:K37)))+2,6)
=ADDRESS(ROW()+MATCH("New Peak",K38:K1030,0)-1,6)

...also the red values need to be adjusted accordingly, as I do not know which row you are currently analyzing.
 
Last edited:
Upvote 0
Hi!

Try this Array Formula (use Ctrl+Shift+Enter and not just Enter to enter the formula) in L2 and copy down:

=IF(ISNUMBER(K2),IF(MIN(IF($H$2:$H$92=$H2,$F$2:$F$92))=$F2,$F2,""),"")

Where H2:H92 (Peak) and F2:F92 (Value) are the ranges of your data.

Markmzz
 
Upvote 0
Cloobless,

You can try too, this small modification in JustynaMK's formula (normal formula) in L2 and copy down:

=IF(ISNUMBER(K2),IF(F2=MIN(INDEX($F:$F,MATCH("ZZZZZ",$K$1:$K2)+1):
INDEX($F:$F,IFERROR(MATCH("New Peak",$K2:$K$92,0)+ROWS($L$2:$L2),$K$92))),F2,""),"")

Markmzz<strike></strike>
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,179
Members
453,021
Latest member
Justyna P

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