Summing and grouping using Array

Guinaba

Board Regular
Joined
Sep 19, 2018
Messages
215
Office Version
  1. 2016
Platform
  1. Windows
I have two arrays:

RawData Array: having the raw data

Calc Array: having the transformed data

In the Calc array the column DEM needs to be summed grouping the data by column MTHID. Any suggestions, please.

Sub AddCalc()

Dim RawData() As Variant
Dim Calc() As Variant
Dim Dim1 As Long, Counter As Long

Sheet2.Activate

'Add data range into the RawData array
RawData = Range("A2", Range("A2").End(xlDown).End(xlToRight))

Dim1 = UBound(RawData, 1)
Dim2 = UBound(RawData, 2)

ReDim Calc(1 To Dim1, 1 To Dim2)

For Counter = 1 To Dim1
Calc(Counter, 1) = RawData(Counter, 3)
Calc(Counter, 2) = RawData(Counter, 16)
Calc(Counter, 3) = RawData(Counter, 17)
Calc(Counter, 4) = RawData(Counter, 6)

Next Counter

Worksheets.Add
Range("A2", Range("A2").Offset(Dim1, 3)).Value = Calc
[A1:D1] = [{"SKUCODE","MONTHYEAR","MTHID","DEM"}]

Erase RawData
Erase Calc

End Sub

SKUCODE
MONTHYEAR
MTHID
DEM
2CSH00596-5005​
1/01/2020​
MTH1​
0​
2CSH00596-5005​
1/01/2020​
MTH1​
0​
2CSH00596-5005​
1/01/2020​
MTH1​
2​
2CSH00596-5005​
1/01/2020​
MTH1​
1​
2CSH00596-5005​
1/01/2020​
MTH1​
1​
2CSH00596-5005​
1/01/2020​
MTH1​
1​
2CSH00596-5005​
1/01/2020​
MTH1​
2​
2CSH00596-5005​
1/01/2020​
MTH1​
1​
2CSH00596-5005​
1/02/2020​
MTH2​
2​
2CSH00596-5005​
1/02/2020​
MTH2​
1​
2CSH00596-5005​
1/02/2020​
MTH2​
1​
2CSH00596-5005​
1/03/2020​
MTH3​
1​
2CSH00596-5005​
1/03/2020​
MTH3​
1​
2CSH00596-5005​
1/03/2020​
MTH3​
1​
2CSH00596-5005​
1/03/2020​
MTH3​
1​
2CSH00596-5005​
1/04/2020​
MTH4​
1​
2CSH00596-5005​
1/04/2020​
MTH4​
1​
2CSH00596-5005​
1/05/2020​
MTH5​
1​
2CSH00596-5005​
1/05/2020​
MTH5​
1​
2CSH00596-5005​
1/06/2020​
MTH6​
1​
2CSH00596-5005​
1/07/2020​
MTH7​
1​
2CSH00596-5005​
1/07/2020​
MTH7​
1​
2CSH00596-5005​
1/07/2020​
MTH7​
1​
2CSH00596-5005​
1/07/2020​
MTH7​
1​
2CSH00596-5005​
1/08/2020​
MTH8​
1​
2CSH00596-5005​
1/08/2020​
MTH8​
1​
2CSH00596-5005​
1/09/2020​
MTH9​
1​
2CSH00596-5005​
1/09/2020​
MTH9​
1​
2CSH00596-5005​
1/09/2020​
MTH9​
1​
2CSH00596-5005​
1/10/2020​
MTH10​
1​
2CSH00596-5005​
1/10/2020​
MTH10​
1​
2CSH00596-5005​
1/11/2020​
MTH11​
1​
2CSH00596-5005​
1/11/2020​
MTH11​
1​
2CSH00596-5005​
1/12/2020​
MTH12​
1​
2CSH00596-5005​
1/12/2020​
MTH12​
1​
 

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.
Before going any further, is this part of a larger process? I ask, as this all seems like simple stuff that could be achieved using PivotTables.
 
Upvote 0
Is the example data you posted the raw data or the result?
 
Upvote 0
VBA Code:
Sub AddCalc()
Dim RawData() As Variant
Dim Calc() As Variant
Dim Dim1 As Long, Counter As Long, columncount As Long
Dim mthref As String
Sheet2.Activate
'Add data range into the RawData array
RawData = Range("A2", Range("A2").End(xlDown).End(xlToRight))
Dim1 = UBound(RawData, 1)
dim2 = UBound(RawData, 2)
Z = 1
For Counter = 1 To Dim1

If x <> RawData(Counter, 3) Then
ReDim Preserve Calc(1 To 4, 1 To Z)
columncount = 1
Do While columncount <= dim2 - 1
Calc(columncount, Z) = RawData(Counter, columncount)
columncount = columncount + 1
Loop
mthref = RawData(Counter, 3)
Calc(4, Z) = sumDEM(mthref)
x = RawData(Counter, 3)
Z = Z + 1
Else
x = RawData(Counter, 3)
End If
Next Counter

Worksheets.Add
Range("A2", Range("A2").Offset(Dim1, 3)).Value = Application.WorksheetFunction.Transpose(Calc)
[A1:D1] = [{"SKUCODE","MONTHYEAR","MTHID","DEM"}]
Erase RawData
Erase Calc
End Sub


Function sumDEM(mthrefer As String)
sumDEM = Application.WorksheetFunction.SumIf(Range("C:C"), mthrefer, Range("D:D"))

End Function
 
Upvote 0
This is rough as hell as Im between reports in work and bored =D.

That was a right pain to code, I had to invert the axis on the 2d array as redim preserve only works on the last dimension Then transpose the output on the new sheet. It gives a summary of only the rows summed using MTHID as the key field


Cheers

Tom
 
Upvote 0
This is rough as hell as Im between reports in work and bored =D.

That was a right pain to code, I had to invert the axis on the 2d array as redim preserve only works on the last dimension Then transpose the output on the new sheet. It gives a summary of only the rows summed using MTHID as the key field


Cheers

Tom
That's awesome Tom! Thanks a lot!!! Great job!!
 
Upvote 0

Forum statistics

Threads
1,213,487
Messages
6,113,937
Members
448,534
Latest member
benefuexx

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