Need formula to return max value & max value reason from Multiple Data.

himadri Chakraborty

New Member
Joined
Nov 8, 2017
Messages
2
[TABLE="width: 697"]
<colgroup><col span="2"><col><col><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]Sl[/TD]
[TD]Site_Name[/TD]
[TD]Value[/TD]
[TD]Reason[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]A[/TD]
[TD]200[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Formula in the below[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]B[/TD]
[TD]250[/TD]
[TD]Pas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]A[/TD]
[TD]300[/TD]
[TD]MISC[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Site_Name[/TD]
[TD]Max_Value[/TD]
[TD]Max_VALUE_Reason[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]A[/TD]
[TD]890[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]A[/TD]
[TD]999[/TD]
[TD]Act[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]C[/TD]
[TD]700[/TD]
[TD]MISC[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]B[/TD]
[TD] [/TD]
[TD] [/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]B[/TD]
[TD]450[/TD]
[TD]Other[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]A[/TD]
[TD]500[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]A[/TD]
[TD]550[/TD]
[TD]Pas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]B[/TD]
[TD]600[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]C[/TD]
[TD]650[/TD]
[TD]Other[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]A[/TD]
[TD]999[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]D[/TD]
[TD]500[/TD]
[TD]Other[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]13[/TD]
[TD]C[/TD]
[TD]1100[/TD]
[TD]Pas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
[TABLE="class: grid, width: 606"]
<tbody>[TR]
[TD]Sl[/TD]
[TD]Site_Name[/TD]
[TD]Value[/TD]
[TD]Reason[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]1[/TD]
[TD]A[/TD]
[TD="align: right"]200[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]2[/TD]
[TD]B[/TD]
[TD="align: right"]250[/TD]
[TD]Pas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]3[/TD]
[TD]A[/TD]
[TD="align: right"]300[/TD]
[TD]MISC[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Site_Name[/TD]
[TD]Max_Value[/TD]
[TD]Max_VALUE_Reason[/TD]
[/TR]
[TR]
[TD="align: right"]4[/TD]
[TD]A[/TD]
[TD="align: right"]890[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]A[/TD]
[TD="align: right"]999[/TD]
[TD]Act[/TD]
[/TR]
[TR]
[TD="align: right"]5[/TD]
[TD]C[/TD]
[TD="align: right"]700[/TD]
[TD]MISC[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]B[/TD]
[TD="align: right"]600[/TD]
[TD]Act[/TD]
[/TR]
[TR]
[TD="align: right"]6[/TD]
[TD]B[/TD]
[TD="align: right"]450[/TD]
[TD]Other[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]7[/TD]
[TD]A[/TD]
[TD="align: right"]500[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]8[/TD]
[TD]A[/TD]
[TD="align: right"]550[/TD]
[TD]Pas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]9[/TD]
[TD]B[/TD]
[TD="align: right"]600[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]10[/TD]
[TD]C[/TD]
[TD="align: right"]650[/TD]
[TD]Other[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]11[/TD]
[TD]A[/TD]
[TD="align: right"]999[/TD]
[TD]Act[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]12[/TD]
[TD]D[/TD]
[TD="align: right"]500[/TD]
[TD]Other[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]13[/TD]
[TD]C[/TD]
[TD="align: right"]1100[/TD]
[TD]Pas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

In I5 control+shift+enter, not just enter, and copy down:

=MAX(IF($B$2:$B$14=$H5,$C$2:$C$14))

In J5 control+shift+enter, not just enter, and copy down:

=INDEX($D$2:$D$14,MIN(IF($B$2:$B$14=H5,IF($C$2:$C$14=I5,ROW($B$2:$B$14)-ROW($B$2)+1))))
 
Upvote 0

Forum statistics

Threads
1,223,715
Messages
6,174,065
Members
452,542
Latest member
Bricklin

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