Is this possible? VLOOKUP, CONCAT, TEXTJOIN, LEFT, help!

Lucero

New Member
Joined
Feb 8, 2010
Messages
2
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Ok, I don't think what I'm trying to do is unique, but I certainly can't seem to work it out or find any examples, or even failing that, think of a better way.

Sheet One contains cells with Action Groups. These cells might have one action group per cell, or multiple action groups per cell, such as:
Zx6nurn.png


In Sheet Two, the action group values are defined in Column A, and in Column B, a list of permissions, which are separated by ><
BS0mBtH.png


What I would like to do in Sheet One is use VLOOKUP or similar to look at that cell, see each of the action groups within it, then output the permissions associated with each of those action groups found in Sheet Two. Ideally one formula to cover both scenarios (of one action group per cell, and multiple action groups per cell), but if I have to have different formulas, then that's OK.

Obviously at the moment =VLOOKUP(R71,'Sheet2'!$A$2:$B$25,2,FALSE) works for singular cell items, the other cells return NA.

Thanks so much in advance for any help or advice.
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
What version of Excel are you using?

I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)

Also can you please post some sample data to the board.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0
Without any sample data try
+Fluff 1.xlsm
ABCDEF
1
2<East Sussex><Brighton and Hove><Surrey><Waverley>
3<Cumbria> <Greater London> <Tyne and Wear> <East Sussex> <Cambridgeshire>NA <Lambeth> <Sunderland> <Brighton and Hove> <East Cambridgeshire><Greater London><Lambeth>
4<Somerset><Bath and North East Somerset>
5<Devon><Exeter>
6<Bedfordshire><Luton>
7<Greater London><Waltham Forest>
8<Tyne and Wear><Sunderland>
9<East Sussex><Brighton and Hove>
10<West Yorkshire><Wakefield>
11<Hertfordshire><Three Rivers>
12<Cambridgeshire><East Cambridgeshire>
13<Gloucestershire><South Gloucestershire>
14<Tyne and Wear><Newcastle upon Tyne>
15<Lancashire><Wyre>
16<Hampshire><Hart>
Main
Cell Formulas
RangeFormula
B2:B3B2=TEXTJOIN(CHAR(10),,XLOOKUP(FILTERXML("<k><m>"&SUBSTITUTE(SUBSTITUTE(A2,"<","&lt;"),CHAR(10),"</m><m>")&"</m></k>","//m"),$D$2:$D$16,$E$2:$E$16,"NA",0))
 
Upvote 0

Forum statistics

Threads
1,224,818
Messages
6,181,151
Members
453,021
Latest member
Justyna P

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