Hi All,
I need formula to find Max and Min Value when criteria matches in array. I don't know the way to explain. Attached the file for your reference.
Any help would be appreciated.
Hi All,
I need formula to find Max and Min Value when criteria matches in array. I don't know the way to explain. Attached the file for your reference.
Any help would be appreciated.
Manikandan Arumugam
Excel Learner
In D2:
=IF(B2=B1,"","$"&MIN(IF($B$2:$B$18=B2,IF($C$2:$C$18<>0,$C$2:$C$18)))&"-$"&MAX(IF($B$2:$B$18=B2,IF($C$2:$C$18<>0,$C$2:$C$18))))
... confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer. Once entered, drag copy down.
Ali
Enthusiastic self-taught user of MS Excel who's always learning!
Don't forget to say "thank you" in your thread to anyone who has offered you help. It's a universal courtesy.
You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.
NB: as a Moderator, I never accept friendship requests.
Forum Rules (updated August 2023): please read them here.
d2=IF($A2="Variable",MIN(IF(($B$2:$B$18=$B2)*($A$2:$A$18<>"Variable"),$C$2:$C$18))&"-"&MAX(IF(($B$2:$B$18=$B2)*($A$2:$A$18<>"Variable"),$C$2:$C$18)),"")
Try this array (Confirm with Ctrl+Shift+Enter) formula and copy towards down
Samba
Say thanks to those who have helped you by clicking Add Reputation star.
Use this array formula in D2, copied down:
=IF(COUNTIF($B$2:B2,B2)=1,"$ "&MIN(IF($B$2:$B$18=B2,IF($C$2:$C$18>0,$C$2:$C$18)))&" - $ "&MAX(IF($B$2:$B$18=B2,IF($C$2:$C$18>0,$C$2:$C$18))),"")
Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.
You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.
Don't type the curly brackets yourself - it won't work...
Glenn
None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU
Try this array formula in C2
=LARGE(IF($B3:$B$18=$B2,C3:$C$18),COUNTIF($B3:$B$18,$B2))&"-"&LARGE(IF($B3:$B$18=$B2,$C3:$C$18),1)
copy and paste in c7 and c13
Thank You AliGw, Glenn, Nflsales.
You're welcome!
If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED. Thanks.
You're welcome.
If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.
It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.
There are currently 1 users browsing this thread. (0 members and 1 guests)
Bookmarks