Find matches across multiple worksheets using multiple criteria

daveasu

Board Regular
Joined
Jan 4, 2012
Messages
53
Attempting to search across worksheets for matches on 3 criteria and return salary.

Worksheet names are in cell A1 in each worksheet
Department account numbers are in cell A2 in each worksheet

Employee names are in column A
Titles are in column B
Salary is in column E
Department account numbers are in column F

K7 has the following formula:
=IFERROR(INDEX(E:E,SMALL(IF(ISNUMBER(SEARCH($K$5,F:F))*ISNUMBER(SEARCH(K4,B:B)),ROW(A:A)-MIN(ROW(A:A))+1),ROWS($K$7:K7))),"")

This returns matches for Title and Department account number on this sheet only.

Can an additional match criteria for Employee name in Column A be added that would also search across all sheets?

1.png


TEST.xlsm
ABCDEF
1Department1
221-1400
3
4
5GradeMonths2020-21
6Salaries:
7Employee1Title11249,85421-1400-5-135
8Employee2Title21224,87421-1400-5-135
9 -21-1400-5-135
10 -21-1400-5-135
11 -21-1400-5-135
12Total Full Time74,728
Department1
Cell Formulas
RangeFormula
E12E12=E7+E8+E9+E10+E11
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
It looks to me that your logic could go like this, based on your data and sample criteria...

1) Find the worksheet whose value in cell A2 equals 21-1400.

2) Within the found worksheet, search for Employee1 in Column A, and Title1 in the corresponding cell in Column B, and then return the corresponding value from Column E.

If so, first enter your sheet names in a range of cells, let's say M3:M5. Then enter the following formula in K7, and confirm with CONTROL+SHIFT+ENTER...

VBA Code:
=INDEX($M$3:$M$5,MATCH(TRUE,COUNTIF(INDIRECT("'"&$M$3:$M$5&"'!A2"),K5)>0,0))

Then enter the following formula in K8, and confirm with CONTROL+SHIFT+ENTER...

VBA Code:
=INDEX(INDIRECT("'"&$K$7&"'!E7:E100"),MATCH(1,IF(INDIRECT("'"&$K$7&"'!A7:A100")=K3,IF(INDIRECT("'"&$K$7&"'!B7:B100")=K4,1)),0))

Hope this helps!
 

Attachments

  • daveasu.png
    daveasu.png
    7.5 KB · Views: 6
Last edited:
Upvote 0
Domenic - that works perfectly! And the INDIRECT command pulls from the other worksheets! Thank you for your help!
 
Upvote 0
You're very welcome, glad I could help.

And thanks for the feedback.

Cheers!
 
Upvote 0

Forum statistics

Threads
1,213,561
Messages
6,114,312
Members
448,564
Latest member
ED38

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