MIN function exclude "Zero" values - Non Consecutive group of cells

Copper Contributor

I am struggling with ignore zero values when the group of cells to be tested is not a consecutive range

 

The function "=MIN(D7,M7,V7,AE7,AN7)" works fine but I want to ignore lowest value if AE7 and AN7 are zero.

 

All the examples for MINIFS require the group of cells to be tested to be a consecutive Range  (D7:AN7) however, I have values in the 7th row that I do not want factored in.

 

Thanks in advance and I apologize for my nube-ness...

5 Replies

@JPScottIII 

=MIN(IF((MOD(COLUMN(D7:AN7),9)=4)*(D7:AN7<>0),D7:AN7,1E+300))

If you don't have Microsoft 365 or Office 2021, confirm the formula with Ctrl+Shift+Enter.

@JPScottIII 

Something like this?

 

=MIN(D7,M7,V7,LET(a,FILTER(AE7:AN7,{1,0,0,0,0,0,0,0,0,1}),FILTER(a,a>0,"")))

 

@JPScottIII 

Another 365 solution

= LET(
    k, SEQUENCE(1,5,1,9),
    array,   INDEX(dataRow, k),
    nonzero, IF(NOT((array=0)*(k>=28)), array),
    MIN(nonzero) )

This builds an array from every 9th cell in the row.  Any zeros found in the back end of the array are converted to FALSE.  MIN returns the required result.

 

If you do not have 365, it might be the time to say.

@JPScottIII 

=IF(AND(AE7=0,AN7=0),MIN(D7,M7,V7),IF(AND(AE7=0,AN7<>0),MIN(D7,M7,V7,AN7),IF(AND(AE7<>0,AN7=0),MIN(D7,M7,V7,AE7),MIN(D7,M7,V7,AE7,AN7))))

 

With Office365 or 2021 you can apply IFS formula:

=IFS(AND(AE7=0,AN7=0),MIN(D7,M7,V7),

AND(AE7=0,AN7<>0),MIN(D7,M7,V7,AN7),

AND(AE7<>0,AN7=0),MIN(D7,M7,V7,AE7),

AND(AE7<>0,AN7<>0),MIN(D7,M7,V7,AE7,AN7))

@JPScottIII 

As variant

=LET(v, INDEX(D7:AN7,,SEQUENCE(,5,1,9)), MIN( FILTER(v,v)) )