Dynamic Loop + Dynamic range to sum

nonono

Board Regular
Joined
Jul 25, 2018
Messages
59
Thank you for reading my post, I am new to VBA and macros...
I am having difficulty trying to solve the loop and dynamic sum value

As you can see I would like to have sum the values in blue and have the total in orange but I am having trouble to sum it up at the macro since it is a dynamic range. and I would like to loop the amount of times in the red cell to repeat the sum value process where it will sum up the value in the grey cell and have the total in the gold cell next
2KHUNHT.png
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Perhaps this ???
Code:
[COLOR="Navy"]Sub[/COLOR] MG25Jul38
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, R [COLOR="Navy"]As[/COLOR] Range, nSum [COLOR="Navy"]As[/COLOR] Double
[COLOR="Navy"]Set[/COLOR] Rng = Range("c:C").SpecialCells(xlCellTypeConstants)
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng.Areas
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] R [COLOR="Navy"]In[/COLOR] Dn
        R.Offset(, 1).Value = R.Value * R.Offset(, -1)
        nSum = nSum + R.Value * R.Offset(, -1)
        [COLOR="Navy"]If[/COLOR] R.Address = Dn(Dn.Count).Address [COLOR="Navy"]Then[/COLOR]
            R.Offset(, 2) = nSum
            nSum = 0
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR] R
[COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Sorry Mr Mick G,
If you may, can you explain your coding?
I would like to understand the coding better as I do not ... know how you did it :(
 
Upvote 0
Here's code that puts formulas on the worksheet :
Code:
Sub v()
Dim Rng As Range, a As Range
Set Rng = [C:C].SpecialCells(xlCellTypeConstants)
For Each a In Rng.Areas
    Range(a(1, 2), a(a.Cells.Count, 2)).FormulaR1C1 = "=RC[-2]*RC[-1]"
    a(a.Cells.Count, 3).Formula = "=Sum(" & a(1, 2).Address & ":" & a(a.Cells.Count, 2).Address & ")"
Next
End Sub
 
Upvote 0
No problem :-

Code:
[COLOR=navy]Sub[/COLOR] MG25Jul56
[COLOR=navy]Dim[/COLOR] Rng [COLOR=navy]As[/COLOR] Range, Dn [COLOR=navy]As[/COLOR] Range, R [COLOR=navy]As[/COLOR] Range, nSum [COLOR=navy]As[/COLOR] Double
'[COLOR=green][B]set "Rng" as range object Areas[/B][/COLOR]
'[COLOR=green][B]In your specific case that is range  "C5:C9" and "C11:C14"[/B][/COLOR]
[COLOR=navy]Set[/COLOR] Rng = Range("C:C").SpecialCells(xlCellTypeConstants)
'[COLOR=green][B]Loop through those individual range Area[/B][/COLOR]
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng.Areas
 
 '[COLOR=green][B]Loop through the each of the Range Areas. Th first being "C5:C9"[/B][/COLOR]
    [COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] R [COLOR=navy]In[/COLOR] Dn
      '[COLOR=green][B]loop through each r in range("C3:C9")[/B][/COLOR]= "Dn"
      '[COLOR=green][B]for each "R" in  range "dn" multiply the r.value by
      'the cell to its left in column "B".[/B][/COLOR]
       
       '[COLOR=green][B]Then place that value in column "D"[/B][/COLOR]
        R.Offset(, 1).Value = R.Value * R.Offset(, -1)
        
        
        '[COLOR=green][B]Sum all the values in specific areas and leave the[/B][/COLOR]
        '[COLOR=green][B]result in  in last cell column "E"[/B][/COLOR]
        '[COLOR=green][B] That when :-  R.Address = Dn(Dn.Count).Address[/B][/COLOR]
        nSum = nSum + R.Value * R.Offset(, -1)
        [COLOR=navy]If[/COLOR] R.Address = Dn(Dn.Count).Address [COLOR=navy]Then[/COLOR]
            R.Offset(, 2) = nSum
            '[COLOR=green][B]set nsum to 0 and proceed to next Area.[/B][/COLOR]
            nSum = 0
        [COLOR=navy]End[/COLOR] If
    [COLOR=navy]Next[/COLOR] R
[COLOR=navy]Next[/COLOR] Dn
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,904
Messages
6,175,295
Members
452,633
Latest member
DougMo

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