Identify multiple entries, store value, perform calculation - VBA (code within)

NRGZ

New Member
Joined
Jul 23, 2021
Messages
47
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
  2. Mobile
  3. Web
The code i have identifies the entry from TOTALS matches the entry in CONTACTS and then returns the value, that woks fine but if there are multiple entries of the same product code i need to get each value and add them together to give a grand total. I think i'm right in thinking that i would store the values in an array but i'm not sure how to code it.
VBA Code:
Private Sub cntrct1()

' what product contract totals are 'contract commitments'

Sheets("totals").Activate

Dim y As Integer
Dim z As Integer
Dim prod As Integer
Dim prod0 As String
Dim matchPos As Integer



y = WorksheetFunction.CountA(Worksheets("contracts").Range(Worksheets("contracts").Cells(2, 1), Worksheets("contracts").Cells(999, 1)))
    
    With Worksheets("contracts")
     
    For z = 2 To y + 1

    prod = Sheets("Totals").Cells(z, 1)

    matchPos = Application.Match(prod, .Range(Worksheets("contracts").Cells(2, 1), Worksheets("contracts").Cells(999, 1)), 0)
    If Not IsError(matchPos) Then
    Sheets("Totals").Cells(z, 6).Value = .Cells(matchPos + 1, "C").Value
    End If
    
    Next z
    
End With

' check status only for testing
Cells(4, 10) = prod
Cells(4, 11) = y
(so easy to get out of your depth when your so early into learning VB....)

Thanks in advance.
o/
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Ok, how about
VBA Code:
Sub NRGZ()
   Dim Cl As Range
   Dim Dic As Object
   
   Set Dic = CreateObject("scripting.dictionary")
   With Sheets("Contracts")
      For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
         Dic.Item(Cl.Value) = Dic.Item(Cl.Value) + Cl.Offset(, 2).Value
      Next Cl
   End With
   With Sheets("Totals")
      For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
         If Dic.Exists(Cl.Value) Then Cl.Offset(, 5).Value = Dic.Item(Cl.Value)
      Next Cl
   End With
End Sub
 
Upvote 0
Solution
Fluff,
what can i say..... as expected works a dream. Amazingly concise code, using so many bits i've only read about 'scripting.dictionary' for one...

Question, I understand the sequence, i understand alot about how things are 'happening' but i'm not sure how C1 is working, if you have time could you explain?

Thanks again,
o/
 
Upvote 0
Cl is just a variable (my shorthand for Cell) so the code is looping for each cell in the range
 
Upvote 0
Glad to help & thanks for the feedback.
 
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