Get matching results in a cell

Ashish Mathur

New Member
Joined
Mar 10, 2013
Messages
40
Office Version
  1. 365
Platform
  1. Windows
Hi,

In range A2:A4, i have multiple text entries in each cell separated by comma and space (Please see image below). I have similar entries in range C2:C4. In range B2:B4, i want to see all matching items (items that exist in A2 and C2, A3 and C3 etc. I have solved it but i am sure there is a much better. In cell D2, i have this formula =TEXTSPLIT(A2,","). In cell I2, i have this formula =TEXTSPLIT(C2,","). In cell B2, i have this formula =TEXTJOIN(",",TRUE,FILTER(I2#,COUNTIF(D2#,I2#)=1)). I get the correct result in range B2:B4.

However, i want to solve this problem without using the helper columns which i have created in columns D and I. When i roll those formulas into the formula in cell B2, i get a #VALUE! error. Why am i getting this error and how can i resolve it?

Can somebody share a LAMBDA solution?

Thank you for your help.
 

Attachments

  • Untitled.png
    Untitled.png
    238.7 KB · Views: 7

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
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 better if you can provide sample data in a form that can be copied for testing: 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.

separated by comma and space (Please see image below).
When I look at the image, it looks like values are separated by comma only. Can you clarify the actual situation (&/or provide the sample data and expected results as outlined above)?
 
Upvote 0
the best solution often varies by version.
So IF you have all the latest function, you could try this.

23 01 14.xlsm
ABC
1
201,03,11,250302,03,14
307,12,23,24,2712,2712,27
410,111111,15,17,23
Common
Cell Formulas
RangeFormula
B2:B4B2=LET(a,TEXTSPLIT(A2,","),TEXTJOIN(",",1,IF(ISNUMBER(FIND(","&a&",",","&C2&",")),a,"")))
 
Upvote 0
Solution
So IF you have all the latest function, you could try this.

23 01 14.xlsm
ABC
1
201,03,11,250302,03,14
307,12,23,24,2712,2712,27
410,111111,15,17,23
Common
Cell Formulas
RangeFormula
B2:B4B2=LET(a,TEXTSPLIT(A2,","),TEXTJOIN(",",1,IF(ISNUMBER(FIND(","&a&",",","&C2&",")),a,"")))
Thank you for your help. Nice formula.
 
Upvote 0
You're welcome. Thanks for the follow-up. :)

But please don't forget this. ;)
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’)
 
Upvote 0

Forum statistics

Threads
1,213,531
Messages
6,114,172
Members
448,554
Latest member
Gleisner2

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