98.7% Of all customers recommend us, we're so confident about our results we publish all reviews and stats
View Live Stats View ReviewsForum home » Delegate support and help forum » Microsoft Excel VBA Training and help » Countifs
Countifs
Resolved · Medium Priority · Version 2016
Stuart has attended:
Excel VBA Intermediate course
Countifs
Hi Jens,
I am trying to do a countif within VBA to determine whether unique IDs appear in a different list. It is possible to just do formulas but due to the datasets being huge it slows excel down massively. Please can you help me figure out how to code this?
Thanks,
Stuart
RE: Countifs
Hi Stuart,
Thank you for the forum question.
If you work with large datasets, there is only one good solution. You will have to use arrays.
You cannot use Countif in arrays but you can count how many times you have a match.
I have attached an example workbook. You may be need to be a little patient. If you cannot see the attachment wait 10 minutes and refresh your browser.
In the example I have 3 worksheets. I count on list 3 how many times I have the ID on list 1 and 2.
I use the code below, but you will also find it in the attached file.
Option Explicit
Sub FindDupl()
Dim ListOneArray As Variant
Dim ListTwoArray As Variant
Dim ListCountResult As Variant
Dim lListRowcount As Long
ListOneArray = Sheet1.Range("a1").CurrentRegion.Columns(1)
ListTwoArray = Sheet2.Range("a1").CurrentRegion.Columns(1)
ListCountResult = Sheet3.Range("a1").CurrentRegion.Columns(1)
ReDim Preserve ListCountResult(1 To UBound(ListCountResult, 1), 1 To UBound(ListCountResult, 2) + 2)
For lListRowcount = 2 To UBound(ListCountResult, 1)
ListCountResult(lListRowcount, 2) = Application.Count(Application.Match(ListCountResult(lListRowcount, 1), ListOneArray, 0))
ListCountResult(lListRowcount, 3) = Application.Count(Application.Match(ListCountResult(lListRowcount, 1), ListTwoArray, 0))
Next lListRowcount
Sheet3.Range("b1").Resize(UBound(ListCountResult, 1), 1) = Application.Index(ListCountResult, , 2)
Sheet3.Range("c1").Resize(UBound(ListCountResult, 1), 1) = Application.Index(ListCountResult, , 3)
End Sub
I hope it makes sense
Kind regards
Jens Bonde
Microsoft Office Specialist Trainer
Tel: 0207 987 3777
STL - https://www.stl-training.co.uk
98%+ recommend us
London's leader with UK wide delivery in Microsoft Office training and management training to global brands, FTSE 100, SME's and the public sector
Attached files...
RE: Countifs
Thanks Jens. I can't seem to see the attachment, please can I ask you to email it to me?
Kind regards
Stuart
RE: Countifs
Hi Stuart,
It is a little bit strange because I can see the attachment.
Please send me an email:
jens.bonde@stl-training.co.uk
then I will send you the file
Thanks
Kind regards
Jens Bonde
Microsoft Office Specialist Trainer
Tel: 0207 987 3777
STL - https://www.stl-training.co.uk
98%+ recommend us
London's leader with UK wide delivery in Microsoft Office training and management training to global brands, FTSE 100, SME's and the public sector
RE: Countifs
Sorry I can see it now, for some reason it didn't appear until after I had messaged! Thanks again Jens
RE: Countifs
You are welcome
Kind regards
Jens Bonde
Microsoft Office Specialist Trainer
Tel: 0207 987 3777
STL - https://www.stl-training.co.uk
98%+ recommend us
London's leader with UK wide delivery in Microsoft Office training and management training to global brands, FTSE 100, SME's and the public sector
Training information:
Welcome. Please choose your application (eg. Excel) and then post your question. Our Microsoft Qualified trainers will then respond within 24 hours (working days). Frequently Asked Questions
Any suggestions, questions or comments? Please post in the Improve the forum thread. |
Excel tip:Closing Multiple Open Worksheets At OnceWhen multiple Excel worksheets are opening, rather than performing a File > Close menu option multiple times, hold down the the SHIFT key and select the File > Close All menu option. |