Comparing two cells with comma separated lists of values and returning any duplicates

CellHell

New Member
Joined
Apr 21, 2021
Messages
7
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Easy one to explain, but frustrating to try and resolve!... 1 cell has '7,8,9', the next cell has '8,9,10' and I want it to compare and report the overlap '8,9'. I can't split these out into separate cells due to the spreadsheet size as each cell might contain upto 12 or so values and ideally I would be able to simultaneously compare 8 or so cells together with the same operation (although even comparing 2 with multiple values would be very useful). It would be ok to CONCAT all the values into one cell and then pull out the duplicates perhaps? ...If it also reported the number of overlapped ; so '2' for '8,9' that would be great but suspect I could find a way for that easier bit. Any help would be really greatly appreciated , to my mind this should be simple and quite a common comparison but lost on this one!....if I have to scrub up on VBA to resolve then so be it. Thanks for reading!
 
Glad you sorted it & thanks for the feedback.
Sorry Fluff, I spoke too soon - I thought I had it!, but my solution results in a duplication of numbers; if comparing 3 cells it shows the answer for comparing each one against each other in turn - rather than the collective with duplicates removed;
e.g. my formula for comparing upto 12 or so individual non-adjacent cells;
=TEXTJOIN(",",,FILTERXML("<k><m>"&TEXTJOIN("</m><m>",,SUBSTITUTE(O277,",","</m><m>"),SUBSTITUTE(Q277,",","</m><m>"),SUBSTITUTE(S277,",","</m><m>"),SUBSTITUTE(U277,",","</m><m>"),SUBSTITUTE(W277,",","</m><m>"),SUBSTITUTE(Y277,",","</m><m>"),SUBSTITUTE(AA277,",","</m><m>"),SUBSTITUTE(AC277,",","</m><m>"),SUBSTITUTE(AE277,",","</m><m>"),SUBSTITUTE(AG277,",","</m><m>"),SUBSTITUTE(AI277,",","</m><m>"),SUBSTITUTE(AK277,",","</m><m>"))&"</m></k>","//m[.=following-sibling::m]"))

when there is;

5,6,7,8,9,10 in cell O

5,7,9,11,13 in cell Q

5,6,7,8,9,10 in cell S

this produces '5,6,7,8,9,10,5,7,9' rather than just '5,6,7,8,9,10' (as you probably know) . Nested substitute needed or something similar? . I know again this is me missing the obvious but I cannot fathom..As ever, any guidance much appreciated!.
 
Upvote 0

Excel Facts

What is the last column in Excel?
Excel columns run from A to Z, AA to AZ, AAA to XFD. The last column is XFD.
How about
Excel Formula:
=TEXTJOIN(",",,UNIQUE(FILTERXML("<k><m>"&SUBSTITUTE(TEXTJOIN(",",,O277,Q277,S277,U277,W277,Y277,AA277,AC277,AE277,AG277,AI277,AK277),",","</m><m>")&"</m></k>","//m[.=following-sibling::m]")))
 
Upvote 0
How about
Excel Formula:
=TEXTJOIN(",",,UNIQUE(FILTERXML("<k><m>"&SUBSTITUTE(TEXTJOIN(",",,O277,Q277,S277,U277,W277,Y277,AA277,AC277,AE277,AG277,AI277,AK277),",","</m><m>")&"</m></k>","//m[.=following-sibling::m]")))
that's it, far tidier and works to remove duplicates. thanks again.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,551
Messages
6,120,161
Members
448,948
Latest member
spamiki

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