Find duplicate text and sum values in different columns

CypherBit

New Member
Joined
Jan 7, 2006
Messages
27
Office Version
  1. 2019
Platform
  1. Windows
I have a table that has three columns.
A column contains values, B column contains part numbers and C column which also contains values. The sum total of values in column A and Column C should be the same for each part number. The same part number in column B can exist in the table just once or 20+ times.

I'd like to somehow find all duplicated part number that exist in column B and based on that sum up column A and column C so I'd see where the differences are. The table has about 2.000 rows so I can't do that manually.

Count 1PartCount 2
0​
10446005​
1​
0​
10446005​
1​
2​
10446005​
1​
10446005​
1​
0​
10446005​
1​
0​
10446005​
2​
0​
10446005​
1​
0​
10446005​
2​
6​
10446005​
0​
10446005​
3​
0​
10446005​
3​
0​
10446005​
3​
0​
10446005​
2​
0​
10446005​
1​
8​
10446005​
2​
10446005​
2​

This example is just for one part number. SUM in column A is 19, in column C 23.

Ideally I'd end up with:
Count 1PartCount 2
19​
10446005​
23​


I'm using Excel 2019, would prefer to do it formulas only if at all possible.

Any assistance is more than welcome.
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
I'm using Excel 2019
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’)

How about
+Fluff 1.xlsm
ABCDEFGH
1Count 1PartCount 2Part
2010446005110446005920
3010446005110446010103
4210446005 
51104460051 
60104460051 
70104460052
80104460051
90104460052
10610446005
110104460053
120104460053
130104460053
140104460052
150104460101
16810446010
172104460102
18
19
Main
Cell Formulas
RangeFormula
G2:G3G2=SUMIFS(A:A,B:B,F2)
H2:H3H2=SUMIFS(C:C,B:B,F2)
F2:F6F2=IFERROR(INDEX($B$2:$B$100,AGGREGATE(15,6,(ROW($B$2:$B$100)-ROW($B$2)+1)/($B$2:$B$100<>"")/(ISNA(MATCH($B$2:$B$100,F$1:F1,0))),1)),"")
 
Upvote 0
Solution
Thank you for the extremely quick reply.

I updated my account details, but I'm having trouble with the formulas, this is what I'm getting:
EXCEL_yGCaRMKM8o.png
 
Upvote 0
In F2 the formula should be F$1:F1, not F$2:F2
 
Upvote 0
Glad to help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,526
Messages
6,114,136
Members
448,551
Latest member
Sienna de Souza

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