Formula to extract data for multiple critera

Dazzybeeguy

Board Regular
Joined
Jan 6, 2022
Messages
114
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
I want to add a formula in cell M6:u12 that looks for the name in M2 and pulls the data out of the table to the left for the dates in C2 to D2

How Can this be achieved ? TIA

Book1
BCDEFGHIJKLMNOPQRSTU
2Start Date05/01/202511/01/2025PersonPerson 3
3
4CodeESMSLSSRDEDOLDOALTCTOIL
5ESMSLSSRDEDOLDOALTCSun 05 JanMon 06 JanTue-07-JanWed-08-JanThu-09-JanFri-10-JanSat-11-JanSun-12-JanMon-13-Jan
6PersonSun 05 JanMon 06 JanTue-07-JanWed-08-JanThu-09-JanFri-10-JanSat-11-JanSun-12-Jan05/01/2025ES
7Person 1SLESESESESESESES06/01/2025
8Person 2ESESESESESESALES07/01/2025ES
9Person 3ESESTOILESESALTC08/01/2025TOIL
10Person 4ESESESESESALTCTOIL09/01/2025ES
11Person 5TCESES10/01/2025ES
12Person 6ESESESESALTC11/01/2025AL
13Person 7ESESESESALTCTOILWFH(E)
14Person 8ESESESESESESES
15Person 9ESALESTOILESAL
16Person 10ESALTCTOILESAL
17Person 11ALTCTOILWFH(E)ALTC
18Person 12
19Person 13SLESESESESESESES
20
21
Sheet1
Cell Formulas
RangeFormula
D2D2=C2+6
L6L6=C2
L7:L12L7=L6+1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
T5Dates OccurringtodaytextNO
J6Dates OccurringtodaytextNO
Cells with Data Validation
CellAllowCriteria
C5:J5List=$B$5:$B$19
M4:U4List=$B$5:$B$19
M2:N2List=$B$7:$B$19
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
A bit strange layout - to show it on diagonal of the table, but in M6:
Excel Formula:
=IF(AND($L6=M$5,M$5>=$C$2,M$5<=$D$2),INDEX($C$7:$J$19,MATCH($M$2,$B$7:$B$19,0),MATCH(M$5,$C$6:$J$6,0)),"")
and copy down and right will do for both Excel 2010 and 365.

You will notice 0 in N7. so select all output table and use custom cell formatting of
,,,@

Book1
BCDEFGHIJKLMNOPQRSTU
2Start Date05.01.202511.01.2025PersonPerson 3
3
4CodeESMSLSSRDEDOLDOALTCTOIL
5ESMSLSSRDEDOLDOALTC05.01.202506.01.202507.01.202508.01.202509.01.202510.01.202511.01.202512.01.202513.01.2025
6Person05.01.202506.01.202507.01.202508.01.202509.01.202510.01.202511.01.202512.01.202505.01.2025ES        
7Person 1SLESESESESESESES06.01.2025         
8Person 2ESESESESESESALES07.01.2025  ES      
9Person 3ESESTOILESESALTC08.01.2025   TOIL     
10Person 4ESESESESESALTCTOIL09.01.2025    ES    
11Person 5TCESES10.01.2025     ES   
12Person 6ESESESESALTC11.01.2025      AL  
13Person 7ESESESESALTCTOILWFH(E)12.01.2025         
14Person 8ESESESESESESES13.01.2025         
15Person 9ESALESTOILESAL
16Person 10ESALTCTOILESAL
17Person 11ALTCTOILWFH(E)ALTC
18Person 12
19Person 13SLESESESESESESES
Sheet1
Cell Formulas
RangeFormula
D2D2=C2+6
M6:U14M6=IF(AND($L6=M$5,M$5>=$C$2,M$5<=$D$2),INDEX($C$7:$J$19,MATCH($M$2,$B$7:$B$19,0),MATCH(M$5,$C$6:$J$6,0)),"")
 
Upvote 0
Solution

Forum statistics

Threads
1,223,996
Messages
6,175,862
Members
452,676
Latest member
woodyp

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