How to compare two set of list with formula

john5599

Board Regular
Joined
Mar 11, 2010
Messages
222
Hi,

How to compare 2 list with find match and mismatch with formula. Can some help me.



Sheet4
EFGHIJ
1
2LED TRIM PANEL LIGHT 5W RD 6500K16Lts Glannz Solar 1.5w Led10 pcs
3LED TRIM PANEL LIGHT ROUND 20W 6500K8LTS Solazen Led Solar Wall Light 3.2W Wh1 pcs
4LED TRIM PANEL LIGHT SQUARE 20W 6500K8LED Trim Panel Light 5w RD 6500K16 pcs
5LTS GAINZ SOLER 1.5W LED10LED Trim Panel Light Square 20W 6500K8 pcs
6LTS RANGER 30 RECHARGE LED TORCH 3W10NU Bulb 10W865 B22 3 Star96 pcs
7NUBULB 10W 865 B22 3 STAR96LED Trim Panel Light ROUND 20W 6500K8 pcs
8WALL LIGHT STYLO UPTO 14W CGL B228LED Light Lumeno D/L 5W CDL RD12 pcs
9Wall Light Stylo Upto 14W CFL B228 pcs
10LTS Ranger 3D Recharge LED Torch 3W10 pcs
11

<thead>
</thead><tbody>
</tbody>
Excel 2007
 
Last edited:

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
@john5599

Provided that you don't have duplicates then, maybe like....

Excel 2010
DEFGHIJK
1
2MatchLED TRIM PANEL LIGHT 5W RD 6500K16Lts Glannz Solar 1.5w Led10 pcsMiss
3MatchLED TRIM PANEL LIGHT ROUND 20W 6500K8LTS Solazen Led Solar Wall Light 3.2W Wh1 pcsMiss
4MatchLED TRIM PANEL LIGHT SQUARE 20W 6500K8LED Trim Panel Light 5w RD 6500K16 pcsMatch
5MissLTS GAINZ SOLER 1.5W LED10LED Trim Panel Light Square 20W 6500K8 pcsMatch
6MissLTS RANGER 30 RECHARGE LED TORCH 3W10NU Bulb 10W865 B22 3 Star96 pcsMiss
7MissNUBULB 10W 865 B22 3 STAR96LED Trim Panel Light ROUND 20W 6500K8 pcsMatch
8MissWALL LIGHT STYLO UPTO 14W CGL B228LED Light Lumeno D/L 5W CDL RD12 pcsMiss
9Wall Light Stylo Upto 14W CFL B228 pcsMiss
10LTS Ranger 3D Recharge LED Torch 3W10 pcsMiss
Sheet1
Cell Formulas
RangeFormula
D2=IF(E2="","",IF(SUMPRODUCT(($I$2:$I$10=E2)*($J$2:$J$10=F2&" pcs"))=1,"Match", "Miss"))
K2=IF(I2="","",IF(SUMPRODUCT(($E$2:$E$8=I2)*($F$2:$F$8&" pcs"=J2))=1,"Match", "Miss"))

Hope that helps.
 
Upvote 0
The problem is that col J does not have values like 16 pcs, it is simply formatted to show that.
Therefore try
=IF(I2="","",IF(SUMPRODUCT(($E$2:$E$8=I2)*($F$2:$F$8=J2))=1,"Match", "Miss"))
 
Upvote 0
The problem is that col J does not have values like 16 pcs, it is simply formatted to show that.
Therefore try
=IF(I2="","",IF(SUMPRODUCT(($E$2:$E$8=I2)*($F$2:$F$8=J2))=1,"Match", "Miss"))


Thanks for your help
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,207
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