How to use dictionary method instead countif?

Crosssover

New Member
Joined
Dec 2, 2020
Messages
2
Office Version
  1. 365
  2. 2016
I want to use vba dictionary method to calculate over 100k rows instead of in worksheet countif function to reduce time of calculation but I could not find how to convert my formula which shown in below.

Range("AG2").Formula = "=COUNTIF($AF$2:$AF100000,"YES" & X2 & Z2 & "TRUE")"
Range("AG3").Formula = "=COUNTIF($AF$2:$AF100000,"YES" & X3 & Z3 & "TRUE")"
Range("AG4").Formula = "=COUNTIF($AF$2:$AF100000,"YES" & X4 & Z4 & "TRUE")"
...
Range("AG100000").Formula = "=COUNTIF($AF$2:$AF100000,"YES" & X100000 & Z100000 & "TRUE")"

Does anyone help me to convert it dictionary method?
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Hi & welcome to MrExcel.
How about
VBA Code:
Sub crosssover()
   Dim Ary As Variant, Nary As Variant
   Dim r As Long
   
   Ary = Range("X2", Range("AF" & Rows.Count).End(xlUp)).Value2
   ReDim Nary(1 To UBound(Ary), 1 To 1)
   With CreateObject("scripting.dictionary")
      For r = 1 To UBound(Ary)
         .Item(Ary(r, 9)) = .Item(Ary(r, 9)) + 1
      Next r
      For r = 1 To UBound(Nary)
         Nary(r, 1) = .Item("YES" & Ary(r, 1) & Ary(r, 3) & "TRUE")
      Next r
   End With
   Range("AG2").Resize(UBound(Nary), 1).Value = Nary
End Sub
 
Upvote 0
Solution
Thank you for quick response and it worked like jet. Is there any source where can I learn more about dictionary structure, interpret and write codes without help?
 
Upvote 0

Forum statistics

Threads
1,223,954
Messages
6,175,603
Members
452,658
Latest member
GStorm

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