lookup value, multiple entries determine max value in a specific date range and return value

just_lookin_009

New Member
Joined
Jan 16, 2014
Messages
5
Hi,

I have two sheets in a workbook, I would like to lookup a persons name in sheet 1, that name has multiple entries in sheet 2 that have a date, project, and hours. I would like for a specified start and end date determine for the entries that fall into that date range what project was the majority of the hours spent and return the name of the project in sheet 1 column B. I tried a vlookup but it is giving me the first project vs. the project in the specified date range and the most hours. Not sure how to work in a Max or maybe a range? Thanks for the help!

Sheet 1:

For date Range (Start)1/1/2014 to (End)1/5/2014 <- these are each a named cell (Start) (End)
ABResult in B:
1Joe?Project B
2Frank?Project B
3Jill?Project C

<TBODY>
</TBODY>

Result would leave out the projects that exceed the date range, and return the project name that had the most hours ie. Joe worked on Project A & B but spent more time on B

Sheet 2:
ABCD
1Joe1/1/20143Project A
2Joe1/2/20148Project B
3Frank1/1/20148Project B
4Jill1/1/20142Project C
5Joe1/3/20148Project B
6Jill1/2/20148Project A
7Joe1/10/201420Project D

<TBODY>
</TBODY>
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
Sheet1, B1, control+shift+enter, notjust enter, and copy down:
Rich (BB code):
=INDEX(Sheet2!$D$1:$D$7,MATCH(MAX(IF(Sheet2!$A$1:$A$7=$A1,
  IF(Sheet2!$B$1:$B$7>=Start,IF(Sheet2!$B$1:$B$7<=End,Sheet2!$C$1:$C$7)))),
  IF(Sheet2!$A$1:$A$7=A1,Sheet2!$C$1:$C$7),0))
 
Upvote 0

Forum statistics

Threads
1,215,026
Messages
6,122,743
Members
449,094
Latest member
dsharae57

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