Search for values within a range and return where they've been found

tigerzen

Board Regular
Joined
Mar 8, 2023
Messages
165
Office Version
  1. 365
Platform
  1. Windows
I'm trying to assist someone with a large data set. I'm stuck however with a formula that doesn't work. I've used AND(Countif) as I thought that's what was required here when matching 2 ranges but as you can see it's returning FALSE which is clearly incorrect. So the objective here is to take the list of Tom, Harry, Fred and check them against each individual row and see if they appear there.
Secondly, if they do appear in the row, we'll need to return which department they are in (in Column F), so for row 2 it would be Dept 1 because Tom who is on the list works there. At this point I have not found that any row would contain more than one person ie Tom and Harry etc but I can't rule that out, for the sake of this example we'll exclude that possibility. I should also say that the person I'm helping does not have Office 365 and only has Excel 2019 on their computer so I'll try and solve this with that constraint.

Book4
ABCDEFGHIJ
1Dept 1Dept 2Dept 3Dept 4ExistingWhich Dept?
2TomJaneMaryJennyFALSETomHarryFred
3JaneMaryJennyAnnaFALSE
4PeteJackKenTomFALSE
5HarryJoeJerryPeteFALSE
6FredKevinCosmoJennyFALSE
Sheet2
Cell Formulas
RangeFormula
E2:E6E2=AND(COUNTIF(A2:D2,$H$2:$J$2))
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Book1
ABCDEFGHIJ
1Dept 1Dept 2Dept 3Dept 4ExistingWhich Dept?
2TomJaneMaryJennyYesDept 1TomHarryFred
3JaneMaryJennyAnnaNo#N/A
4PeteJackKenTomYesDept 4
5HarryJoeJerryPeteYesDept 1
6FredKevinCosmoJennyYesDept 1
Sheet1
Cell Formulas
RangeFormula
E2:E6E2=IF(ISERROR(F2),"No","Yes")
F2:F6F2=LOOKUP(2,1/(COUNTIF($H$2:$J$2,$A2:$D2)>0),$A$1:$D$1)
 
Upvote 0
Thanks bebo021999, that was quick!!! One slight variation if I may, can your E2:E6 formula be adjusted so that it returns the name of the staff member name rather than just whether they are existing staff, in the spreadsheet it would mean Tom, blank, Tom, Harry, Fred.
 
Upvote 0
Try:
Book1
ABCDEFGHIJ
1Dept 1Dept 2Dept 3Dept 4ExistingWhich Dept?
2TomJaneMaryJennyTomDept 1TomHarryFred
3JaneMaryJennyAnna #N/A
4PeteJackKenTomTomDept 4
5HarryJoeJerryPeteHarryDept 1
6FredKevinCosmoJennyFredDept 1
Sheet1
Cell Formulas
RangeFormula
E2:E6E2=IFERROR(LOOKUP(2,1/(COUNTIF($H$2:$J$2,$A2:$D2)>0),$A2:$D2),"")
F2:F6F2=LOOKUP(2,1/(COUNTIF($H$2:$J$2,$A2:$D2)>0),$A$1:$D$1)
 
Upvote 0
Solution
Try:
Book1
ABCDEFGHIJ
1Dept 1Dept 2Dept 3Dept 4ExistingWhich Dept?
2TomJaneMaryJennyTomDept 1TomHarryFred
3JaneMaryJennyAnna #N/A
4PeteJackKenTomTomDept 4
5HarryJoeJerryPeteHarryDept 1
6FredKevinCosmoJennyFredDept 1
Sheet1
Cell Formulas
RangeFormula
E2:E6E2=IFERROR(LOOKUP(2,1/(COUNTIF($H$2:$J$2,$A2:$D2)>0),$A2:$D2),"")
F2:F6F2=LOOKUP(2,1/(COUNTIF($H$2:$J$2,$A2:$D2)>0),$A$1:$D$1)
Perfect. Thanks very much.
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,551
Members
449,088
Latest member
davidcom

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