merge duplicated items and sum values without loop

MKLAQ

Active Member
Joined
Jan 30, 2021
Messages
387
Office Version
  1. 2016
Platform
  1. Windows
hello
I have data a bout 10000 rows so what I want merge items and sum values without loop
I found this code but I no know how modify it
and this sample simple to understand my data
datecommidatymodelqcommidatyq
01/01/2021car1bmw200car1250
01/02/2021car1bmw50car230
01/03/2021car2mer10
01/04/2021car2mer20


VBA Code:
Sub dupremove()
Dim ws As Worksheet
Dim lastrow As Long

Set ws = Sheets("Sheet1") ' Change to your sheet

With ws
    lastrow = .Range("b" & .Rows.Count).End(xlUp).Row
    With .Range("d2:d" & lastrow)
        .Offset(, 9).FormulaR1C1 = "=SUMIF(C1,RC1,C[-9])"
        .Offset(, 9).Value = .Offset(, 9).Value
    End With
    With .Range("b2:b" & lastrow)
        .Offset(, 9).Value = .Value
    End With
    .Range("k2: l" & lastrow).RemoveDuplicates 1, xlYes

End With

End Sub
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
VBA Code:
Sub dupremove()
Dim ws As Worksheet
Dim r1 As Range
Dim r2 As Range
Dim lastrow As Long
Set ws = Sheets("Blad1") ' Change to your sheet
lastrow = ws.Range("b" & ws.Rows.Count).End(xlUp).Row
Set r1 = ws.Range("B2:B" & lastrow)
Set r2 = ws.Range("D2:D" & lastrow)
r1.Offset(, 9).Value = r1.Value
r1.Offset(, 10).FormulaR1C1 = "=SUMIF(" & r1.Address(ReferenceStyle:=xlR1C1) & ",INDIRECT(""B""&ROW())," & r2.Address(ReferenceStyle:=xlR1C1) & ")"
ws.Range("K1:L" & lastrow).RemoveDuplicates Columns:=Array(1, 2), Header:=xlYes
End Sub
 
Upvote 0
@Mart many thanks ! but the code is something wrong it doesn't give me right value , two values are both give the same total 250 it should 250 & 30 as in my post#1
 
Upvote 0
VBA Code:
Sub dupremove()
Dim ws As Worksheet
Dim r1 As Range
Dim r2 As Range
Dim lastrow As Long
Set ws = Sheets("Blad1") ' Change to your sheet
lastrow = ws.Range("b" & ws.Rows.Count).End(xlUp).Row
Set r1 = ws.Range("B2:B" & lastrow)
Set r2 = ws.Range("D2:D" & lastrow)
r1.Offset(, 9).Value = r1.Value
r1.Offset(, 10).FormulaR1C1 = "=SUMIF(" & r1.Address(ReferenceStyle:=xlR1C1) & ",INDIRECT(""B""&ROW())," & r2.Address(ReferenceStyle:=xlR1C1) & ")"
r1.Offset(, 10).Value = r1.Offset(, 10).Value
ws.Range("K1:L" & lastrow).RemoveDuplicates Columns:=Array(1, 2), Header:=xlYes
End Sub
 
Upvote 0
Solution
excellent !! I try mod your code but I failed I would also show column c so the result should be
column B,C,D= K,L,M , may you help me please?
VBA Code:
Sub dupremove()
Dim ws As Worksheet
Dim r1 As Range
Dim r2 As Range
Dim lastrow As Long
Set ws = Sheets("sheet1") ' Change to your sheet
lastrow = ws.Range("b" & ws.Rows.Count).End(xlUp).Row
Set r1 = ws.Range("B2:c" & lastrow)
Set r2 = ws.Range("D2:D" & lastrow)
r1.Offset(, 9).Value = r1.Value
r1.Offset(, 10).Value = r1.Value
r1.Offset(, 11).FormulaR1C1 = "=SUMIF(" & r1.Address(ReferenceStyle:=xlR1C1) & ",INDIRECT(""b""&ROW())," & r2.Address(ReferenceStyle:=xlR1C1) & ")"
r1.Offset(, 11).Value = r1.Offset(, 11).Value
ws.Range("K1:m" & lastrow).RemoveDuplicates Columns:=Array(1, 2), Header:=xlYes
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
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