Need help with Index + Match function with multiple criteria.

BrandonBerner

New Member
Joined
Mar 16, 2019
Messages
15
Here is the formula which I am using.

  • Problem: Its not printing the correct row of data.

=INDEX($A$1:$H$15,MATCH($A$18,$A$1:$A$15,0),MATCH(B$18,$B$2:$H$2,0),MATCH($A19,$A$3:$A$15,0))

Here is the same formula, which explains the above formula, and what I'm looking to achieve.

=INDEX(Full_Schedule,MATCH(Data_Validation(Week1|Week2),Where_Week1_&_Week2_Are_Found,0),MATCH(Day_Of_The_Week,Where_Day_Of_The_Week_Is_Found_In_Full_Schedule,0),MATCH(Employee_Name,Where_Employee_Name_Is_Found_In_Full_Schedule,0))


Here is the sheet im working with...


[TABLE="width: 0"]
<tbody>[TR]
[TD="align: center"]Week1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD]SUN[/TD]
[TD]MON[/TD]
[TD]TUE[/TD]
[TD]WED[/TD]
[TD]THUR[/TD]
[TD]FRI[/TD]
[TD]SAT[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #1[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[/TR]
[TR]
[TD="align: right"]Employee #2[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #3[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[/TR]
[TR]
[TD="align: right"].Employee #4[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]12:15-6:15[/TD]
[TD="align: center"]12:15-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #5[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]12:15-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: center"]Week2[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD]SUN[/TD]
[TD]MON[/TD]
[TD]TUE[/TD]
[TD]WED[/TD]
[TD]THUR[/TD]
[TD]FRI[/TD]
[TD]SAT[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #1[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[/TR]
[TR]
[TD="align: right"]Employee #2[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #3[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[/TR]
[TR]
[TD="align: right"].Employee #4[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]12:15-6:15[/TD]
[TD="align: center"]12:15-6:15[/TD]
[TD="align: center"]9:45-6:15[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #5[/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]12:15-6:15[/TD]
[TD="bgcolor: #D9D9D9"][/TD]
[TD="align: center"]9:45-6:15[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD] Week1 v[/TD]
[TD="align: center"]SUN[/TD]
[TD="align: center"]MON[/TD]
[TD="align: center"]TUE[/TD]
[TD="align: center"]WED[/TD]
[TD="align: center"]THUR[/TD]
[TD="align: center"]FRI[/TD]
[TD="align: center"]SAT[/TD]
[/TR]
[TR]
[TD="align: right"]Employee #1[/TD]
[TD]FORMULA[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]Employee #2[/TD]
[TD]Week1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]Employee #3[/TD]
[TD]Week1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"].Employee #4[/TD]
[TD]Week1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]Employee #5[/TD]
[TD]Week1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Where "FORMULA" is written, is where
=INDEX($A$1:$H$15,MATCH($A$18,$A$1:$A$15,0),MATCH(B$18,$B$2:$H$2,0),MATCH($A19,$A$3:$A$15,0))
is.

Any help, or resources will be greatly appreciated! :D


 
Last edited:

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
your index() of 15 rows by 8 columns needs only 2 references, i.e. row no & column no, but the formula has 3 matches and yielding incorrect references.
 
Upvote 0
by moving the lookup table away from Cols A:H, the modified formula will cater for more weeks to be added and no of employee by amend the table size 8*8.


Book1
ABCDEFGHIJKLMNOPQ
1Week1Week3SUNMONTUEWEDTHURFRISAT
2SUNMONTUEWEDTHURFRISATEmployee #1009:45-6:1509:45-6:159:45-6:150
3Employee #19:45-6:159:45-6:159:45-6:159:45-6:15Employee #29:45-6:15000009:45-6:15
4Employee #29:45-6:159:45-6:159:45-6:15Employee #309:45-6:159:45-6:1509:45-6:159:45-6:150
5Employee #39:45-6:159:45-6:159:45-6:159:45-6:159:45-6:15Employee #409:45-6:1500012:15-6:159:45-6:15
6Employee #49:45-6:1512:15-6:159:45-6:15Employee #59:45-6:1509:45-6:15012:15-6:1509:45-6:15
7Employee #59:45-6:159:45-6:1512:15-6:159:45-6:15
8
9Week2
10SUNMONTUEWEDTHURFRISAT
11Employee #19:45-6:159:45-6:159:45-6:159:45-6:159:45-6:15
12Employee #29:45-6:159:45-6:159:45-6:15
13Employee #39:45-6:159:45-6:159:45-6:159:45-6:159:45-6:15
14Employee #49:45-6:1512:15-6:1512:15-6:159:45-6:15
15Employee #59:45-6:159:45-6:1512:15-6:159:45-6:15
16
17Week3
18SUNMONTUEWEDTHURFRISAT
19Employee #19:45-6:159:45-6:159:45-6:15
20Employee #29:45-6:159:45-6:15
21Employee #39:45-6:159:45-6:159:45-6:159:45-6:15
22Employee #49:45-6:1512:15-6:159:45-6:15
23Employee #59:45-6:159:45-6:1512:15-6:159:45-6:15
Sheet3
Cell Formulas
RangeFormula
K2=INDEX(OFFSET($A$1,MATCH($J$1,$A:$A,0)-1,0,8,8),MATCH($J2,$A$1:$A$7,0),MATCH(K$1,$A$2:$H$2,0))
 
Upvote 0

Forum statistics

Threads
1,224,824
Messages
6,181,186
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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