Formula to compare two lists

LearnMeExcel

Well-known Member
Joined
Aug 11, 2009
Messages
746
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
Hi
i have this to lists
Excel Workbook
ABCD
1List 1List 2Expected result
2Check 7290 at 26/5 - company BDelete Check 7763 at 5/9 - company AADone
3Check 78 at 1/6 - company APaid Check 7290 at 26/5 - company B - AAA BankDone
4Check 835922 at 20/8 - company FPaid Check 78 at 1/6 - company ANot in List
5Check 7763 at 5/9 - company AADone
6Check 79 at 1/7 - company ANot in List
7Check 80 at 1/8 - company ANot in List
Sheet1
Excel 2007

i want to compare the first list with the second to find which transaction done
the expected result in column D
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
I think something like this should get you started
Excel Workbook
ABCD
1List 1List 2Expected result
2Check 7290 at 26/5 - company BDelete Check 7763 at 5/9 - company AADone
3Check 78 at 1/6 - company APaid Check 7290 at 26/5 - company B - AAA BankNot In List
4Check 835922 at 20/8 - company FPaid Check 78 at 1/6 - company ADone
5Check 7763 at 5/9 - company AANot In List
6Check 79 at 1/7 - company ANot In List
7Check 80 at 1/8 - company ANot In List
APR
Excel 2007
Cell Formulas
RangeFormula
D2=IF(ISNUMBER(MATCH(MID(B2, FIND(" ", B2)+1, 255),A:A, 0)), "Done", "Not In List")
 
Upvote 0
thanx dave
but it is not what i am looking for
your formula compare list 2 with 1
i want to compare list 1 with 2
Excel Workbook
DE
1Expected resultDave 3009
2DoneDone
3DoneNot In List
4Not in ListDone
5DoneNot In List
6Not in ListNot In List
7Not in ListNot In List
Sheet1
Excel 2007
Cell Formulas
RangeFormula
E2=IF(ISNUMBER(MATCH(MID(B2, FIND(" ", B2)+1, 255),A:A, 0)), "Done", "Not In List")
 
Upvote 0
In D2 enter and copy down:

=IF(ISNUMBER(LOOKUP(9.99999999999999E+307,SEARCH(A2,$B$2:$B$4))),"Done","Not in List")
 
Upvote 0
An alternative

Sheet2

<TABLE style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Calibri,Arial; FONT-SIZE: 11pt" border=1 cellSpacing=0 cellPadding=0><COLGROUP><COL style="WIDTH: 30px; FONT-WEIGHT: bold"><COL style="WIDTH: 249px"><COL style="WIDTH: 348px"><COL style="WIDTH: 52px"><COL style="WIDTH: 111px"></COLGROUP><TBODY><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"><TD> </TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">List 1</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">List 2</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Expected result</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">2</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 7290 at 26/5 - company B</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Delete Check 7763 at 5/9 - company AA</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Done</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">3</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 78 at 1/6 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Paid Check 7290 at 26/5 - company B - AAA Bank</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Done</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">4</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 835922 at 20/8 - company F</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Paid Check 78 at 1/6 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Not in List</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">5</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 7763 at 5/9 - company AA</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Done</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">6</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 79 at 1/7 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Not in List</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">7</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 80 at 1/8 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Not in List</TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM-STYLE: groove; BORDER-BOTTOM-COLOR: #00ff00; BORDER-RIGHT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-TOP-STYLE: groove; COLOR: #000000; BORDER-RIGHT-COLOR: #00ff00; FONT-SIZE: 10pt; BORDER-LEFT-STYLE: groove; BORDER-LEFT-COLOR: #00ff00"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-FAMILY: Arial; FONT-SIZE: 9pt" border=1 cellSpacing=0 cellPadding=2><TBODY><TR style="BACKGROUND-COLOR: #cacaca; FONT-SIZE: 10pt"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>D2</TD><TD>=COUNTIF($B$2:$B$4,"*"&A2&"*")</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>

Column D uses a custom format, [=0]"Not in List";[>0]"Done"
 
Upvote 0
An alternative

Sheet2

<TABLE style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Calibri,Arial; FONT-SIZE: 11pt" border=1 cellSpacing=0 cellPadding=0><COLGROUP><COL style="WIDTH: 30px; FONT-WEIGHT: bold"><COL style="WIDTH: 249px"><COL style="WIDTH: 348px"><COL style="WIDTH: 52px"><COL style="WIDTH: 111px"></COLGROUP><TBODY><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"><TD> </TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">List 1</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">List 2</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Expected result</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">2</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 7290 at 26/5 - company B</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Delete Check 7763 at 5/9 - company AA</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Done</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">3</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 78 at 1/6 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Paid Check 7290 at 26/5 - company B - AAA Bank</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Done</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">4</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 835922 at 20/8 - company F</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Paid Check 78 at 1/6 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Not in List</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">5</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 7763 at 5/9 - company AA</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Done</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">6</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 79 at 1/7 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Not in List</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">7</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">Check 80 at 1/8 - company A</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt"> </TD><TD style="TEXT-ALIGN: right">Not in List</TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM-STYLE: groove; BORDER-BOTTOM-COLOR: #00ff00; BORDER-RIGHT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-TOP-STYLE: groove; COLOR: #000000; BORDER-RIGHT-COLOR: #00ff00; FONT-SIZE: 10pt; BORDER-LEFT-STYLE: groove; BORDER-LEFT-COLOR: #00ff00"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-FAMILY: Arial; FONT-SIZE: 9pt" border=1 cellSpacing=0 cellPadding=2><TBODY><TR style="BACKGROUND-COLOR: #cacaca; FONT-SIZE: 10pt"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>D2</TD><TD>=COUNTIF($B$2:$B$4,"*"&A2&"*")</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>

Column D uses a custom format, [=0]"Not in List";[>0]"Done"

nice idea jasonb
i like it
thank you
 
Upvote 0
Depending on the volume of data you have to work with, it may also be more efficient.

I tried it with 10k records in each list and it took around 10 seconds to calculate, I deleted the formula column and tried Aladins formula on the same set of records, which is still calulcating after around 5 minutes.
 
Upvote 0
Depending on the volume of data you have to work with, it may also be more efficient.

I tried it with 10k records in each list and it took around 10 seconds to calculate, I deleted the formula column and tried Aladins formula on the same set of records, which is still calulcating after around 5 minutes.

Would you also check:

=ISNUMBER(MATCH("*"&A2&"*",$B$2:$B$4,0))+0

with:

[=0]"Not in List";[=1]"Done"
 
Upvote 0

Forum statistics

Threads
1,224,505
Messages
6,179,147
Members
452,891
Latest member
JUSTOUTOFMYREACH

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