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!
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.

JamesCanale

Board Regular
Joined
Jan 13, 2021
Messages
236
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
This is a silly solution.

MrExcelPlayground2.xlsx
KL
15,6,7,8,9,108,9,10
28,9,10,11,12
Sheet4
Cell Formulas
RangeFormula
L1L1=TEXTJOIN(",",TRUE,XLOOKUP(VALUE(MID(K1,SORT(UNIQUE(IFERROR(FIND(",",K1,SEQUENCE(LEN(K1)))+1,1)),1,1),UNIQUE(IFERROR(FIND(",",K1,SEQUENCE(LEN(K1))),LEN(K1)+1))-(SORT(UNIQUE(IFERROR(FIND(",",K1,SEQUENCE(LEN(K1)))+1,1)),1,1)))),VALUE(MID(K2,SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1),UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2))),LEN(K2)+1))-(SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1)))),VALUE(MID(K2,SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1),UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2))),LEN(K2)+1))-(SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1)))),"",0))
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
59,980
Office Version
  1. 365
Platform
  1. Windows
Hi & welcome to MrExcel.
A couple of options, the formula in C3 only works on a pc.
+Fluff 1.xlsm
ABC
1
27,8,9,1,14,157,9,14,15,19,2
39,10,15,117,9,14,15,19,2
47,23,19,26,2,3
514,19,2
6
Main
Cell Formulas
RangeFormula
C2C2=LET(a,TEXTJOIN(",",,A2:A5),b,TRIM(MID(SUBSTITUTE(a,",",REPT(" ",100)),SEQUENCE(LEN(a)-LEN(SUBSTITUTE(a,",",""))+1,,,100),100)),TEXTJOIN(",",,UNIQUE(FILTER(b,ISNA(MATCH(b, UNIQUE(b,,1),0))))))
C3C3=TEXTJOIN(",",,FILTERXML("<k><m>"&TEXTJOIN("</m><m>",,SUBSTITUTE(A2:A5,",","</m><m>"))&"</m></k>","//m[.=following-sibling::m]"))
 
Solution

CellHell

New Member
Joined
Apr 21, 2021
Messages
7
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
This is a silly solution.

MrExcelPlayground2.xlsx
KL
15,6,7,8,9,108,9,10
28,9,10,11,12
Sheet4
Cell Formulas
RangeFormula
L1L1=TEXTJOIN(",",TRUE,XLOOKUP(VALUE(MID(K1,SORT(UNIQUE(IFERROR(FIND(",",K1,SEQUENCE(LEN(K1)))+1,1)),1,1),UNIQUE(IFERROR(FIND(",",K1,SEQUENCE(LEN(K1))),LEN(K1)+1))-(SORT(UNIQUE(IFERROR(FIND(",",K1,SEQUENCE(LEN(K1)))+1,1)),1,1)))),VALUE(MID(K2,SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1),UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2))),LEN(K2)+1))-(SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1)))),VALUE(MID(K2,SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1),UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2))),LEN(K2)+1))-(SORT(UNIQUE(IFERROR(FIND(",",K2,SEQUENCE(LEN(K2)))+1,1)),1,1)))),"",0))
thanks so much James - if i knew you I would be buying you a pint at this stage. :)
 

JamesCanale

Board Regular
Joined
Jan 13, 2021
Messages
236
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS

ADVERTISEMENT

thanks so much James - if i knew you I would be buying you a pint at this stage. :)
You are welcome. I'll help myself to a pint.
 

CellHell

New Member
Joined
Apr 21, 2021
Messages
7
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hi & welcome to MrExcel.
A couple of options, the formula in C3 only works on a pc.
+Fluff 1.xlsm
ABC
1
27,8,9,1,14,157,9,14,15,19,2
39,10,15,117,9,14,15,19,2
47,23,19,26,2,3
514,19,2
6
Main
Cell Formulas
RangeFormula
C2C2=LET(a,TEXTJOIN(",",,A2:A5),b,TRIM(MID(SUBSTITUTE(a,",",REPT(" ",100)),SEQUENCE(LEN(a)-LEN(SUBSTITUTE(a,",",""))+1,,,100),100)),TEXTJOIN(",",,UNIQUE(FILTER(b,ISNA(MATCH(b, UNIQUE(b,,1),0))))))
C3C3=TEXTJOIN(",",,FILTERXML("<k><m>"&TEXTJOIN("</m><m>",,SUBSTITUTE(A2:A5,",","</m><m>"))&"</m></k>","//m[.=following-sibling::m]"))
thanks Fluff - again I would be buying you a pint if I knew you. I will test this version out tomorrow and let you know how I get on. thanks again, much appreciated.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
59,980
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Ok, (y)
 

CellHell

New Member
Joined
Apr 21, 2021
Messages
7
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hi Fluff, sorry one last one.... the XML formula is working great apart from one added complication - If I want non-adjacent cells instead of a range e.g. 'A2,B2,E2' instead of 'A2:E2' is this constrained by this type of formula (using XML) or is it just that I need to do something with SUBSTITUTE (I have only ever used this for singular references before and cant find an example with multiple non-adjacent cells, so not sure if I have to do something nested perhaps?). Apologies for my ignorance - I have read up on XML since getting this formula, but I can't fathom why it won't allow. Any further guidance, greatly appreciated.
 

CellHell

New Member
Joined
Apr 21, 2021
Messages
7
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hi Fluff, sorry one last one.... the XML formula is working great apart from one added complication - If I want non-adjacent cells instead of a range e.g. 'A2,B2,E2' instead of 'A2:E2' is this constrained by this type of formula (using XML) or is it just that I need to do something with SUBSTITUTE (I have only ever used this for singular references before and cant find an example with multiple non-adjacent cells, so not sure if I have to do something nested perhaps?). Apologies for my ignorance - I have read up on XML since getting this formula, but I can't fathom why it won't allow. Any further guidance, greatly appreciated.
ignore - sorry.... I should have known this one. I just needed to type it out and I figured out what I was doing wrong....sorry! and thanks.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
59,980
Office Version
  1. 365
Platform
  1. Windows
Glad you sorted it & thanks for the feedback.
 

Forum statistics

Threads
1,136,444
Messages
5,675,894
Members
419,591
Latest member
mersanko

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
Top