=Max Forumula, multiple criteria, pull another cell on row

NextWorldAngel

New Member
Joined
Oct 19, 2006
Messages
31
Okay I need a formula that finds the max number in column D, if column B="Local" and then whatever the max # is in row ___ pull the entry in in that same row but from column A for the answer.

Example:
(Col. A) (Col. B) (Col. D)
1 ------Local-------- $50
2------- OTR------- $125
3------ Local------- $100

Answer would be 3.
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
Code:
=MAX((A1:A3)*(B1:B3="local")*(D1:D3=MAX((B1:B3="local")*(D1:D3))))

Best Regards.
 
Upvote 0
Try:

=MATCH(MAX(IF(B1:B3="local",D1:D3)),IF(B1:B3="local",D1:D3),0)

which is an array formula and must be confirmed with CTRL+SHIFT+ENTER (doing so correctly will result in Excel putting { }'s around your formula in the formula bar)

(Note that your ranges must start in row 1)

northwolves: I think you meant

=MAX(ROW(A1:A3)*(B1:B3="local")*(D1:D3=MAX((B1:B3="local")*(D1:D3))))
 
Upvote 0
Okay what if I can't start on row 1?

=MATCH(MAX(IF(B1:B3="local",D1:D3)),IF(B1:B3="local",D1:D3),0) tells you the position in your range where the match exists. If you start in row 5 and the formula returns 3, the formula is telling you the match is in the (5+(3-1)) =7th row.

Alternatively, northwolves' solution (incorporating ROW) has that adjustment embedded.
 
Upvote 0
Okay so wolf's should work? Because it's not. I'm getting a number back from the correct column but it's not the max number. Here's the formula as I adjusted it for my spreadsheet.

=MAX((A15:A300)*(B15:B300="local")*(D15:D300=MAX((B15:B300="local")*(D15:D300))))

Did I mess something up?
 
Upvote 0
(northwolves' formula is also an array formula and requires CTRL+SHIFT+ENTER)
 
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,089
Members
448,548
Latest member
harryls

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