Mapping file

zinah

Active Member
Joined
Nov 28, 2018
Messages
368
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have a file to map from a different excel file. The common field in both files is the email address, however, some cells have more than one email address. Below is the sample data and here's what I need to get:
Is to fill column F with the right team from columns A & B, and if there's more than one email i.e. F6, then the result is to update the cell with both team names, there maybe a situation where more than one email belong to the same team. is there any good formula for such situation?

Book1
ABCDEFG
1Mapping TableDesired Results
2EmailTeamEmailTeam
3a@abc.comAAAa@abc.comAAA
4b@abc.comBBBb@abc.comBBB
5c@abc.comBBBc@abc.comBBB
6d@abc.comBBBa@abc.com b@abc.comAAA, BBB
7e@abc.comAAAd@abc.com
8f@abc.comAAAa@abc.com f@abc.comAAA
9g@abc.comBBBe@abc.com
10d@abc.com e@abc.comBBB, AAA
11f@abc.com
12g@abc.com
13
Sheet1
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
How about
+Fluff 1.xlsm
ABCDEF
1Mapping TableDesired Results
2EmailTeamEmailTeam
3a@abc.comAAAa@abc.comAAA
4b@abc.comBBBb@abc.comBBB
5c@abc.comBBBc@abc.comBBB
6d@abc.comBBBa@abc.com b@abc.comAAA, BBB
7e@abc.comAAAd@abc.comBBB
8f@abc.comAAAa@abc.com f@abc.comAAA
9g@abc.comBBBe@abc.comAAA
10d@abc.com e@abc.comBBB, AAA
11f@abc.comAAA
12g@abc.comBBB
Master
Cell Formulas
RangeFormula
F3:F12F3=TEXTJOIN(", ",,UNIQUE(XLOOKUP(FILTERXML("<k><m>"&SUBSTITUTE(E3,CHAR(10),"</m><m>")&"</m></k>","//m"),$A$3:$A$9,$B$3:$B$9,"",0)))
 
Upvote 0
Solution
How about
+Fluff 1.xlsm
ABCDEF
1Mapping TableDesired Results
2EmailTeamEmailTeam
3a@abc.comAAAa@abc.comAAA
4b@abc.comBBBb@abc.comBBB
5c@abc.comBBBc@abc.comBBB
6d@abc.comBBBa@abc.com b@abc.comAAA, BBB
7e@abc.comAAAd@abc.comBBB
8f@abc.comAAAa@abc.com f@abc.comAAA
9g@abc.comBBBe@abc.comAAA
10d@abc.com e@abc.comBBB, AAA
11f@abc.comAAA
12g@abc.comBBB
Master
Cell Formulas
RangeFormula
F3:F12F3=TEXTJOIN(", ",,UNIQUE(XLOOKUP(FILTERXML("<k><m>"&SUBSTITUTE(E3,CHAR(10),"</m><m>")&"</m></k>","//m"),$A$3:$A$9,$B$3:$B$9,"",0)))
You always amazed me with your suggested solutions, it worked perfectly great, thank you so much!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,183
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