Counting unique instances across several (named) ranges

sandwichgirl

New Member
Joined
Aug 13, 2007
Messages
31
Office Version
  1. 365
Platform
  1. Windows
Hi

I've tried searching for a function that will calculate this answer, but am having trouble finding anything relevant relating to multiple ranges.

I've named my ranges to reduce my confusion and they are called onecraft, twocraft, threecraft, fourcraft etc (each is on a different worksheet and each contains a different number of rows). I want to count up how many different prices are contained across these ranges (whilst ignoring duplicates). I've tried sumproduct/countif, but from what I've read the countif can't cope with multiple ranges.

Is there a way to do this?

thanks in anticipation of my reduced frustration.

sandwichgirl
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
I don't know of a formula either, but if you don't mind VBA code, you might try this:
Code:
Sub countem()
With CreateObject("scripting.dictionary")
    For Each e In Sheets("Sheet1").Range("onecraft")
        If Not IsEmpty(e) And Not .exists(e.Value) Then .Add e.Value, 1
    Next e
    For Each e In Sheets("Sheet2").Range("twocraft")
        If Not IsEmpty(e) And Not .exists(e.Value) Then .Add e.Value, 1
    Next e
    For Each e In Sheets("Sheet3").Range("threecraft")
        If Not IsEmpty(e) And Not .exists(e.Value) Then .Add e.Value, 1
    Next e
    For Each e In Sheets("Sheet4").Range("fourcraft")
        If Not IsEmpty(e) And Not .exists(e.Value) Then .Add e.Value, 1
    Next e
MsgBox .Count & " unique items"
End With
End Sub
A couple of additional points:
1. By unique I take it you mean each item counted only once, and not a count of only the items which occur only once. i.e. in the set a,b,a would you want only the b (1 unique) or a and b counted once each (two uniques). The code takes the latter approach, although easily modified to the other if you like.
2. If you don't mind your ranges being renamed, or even if you do, the code and its relevant entries could be shortened by including a loop.
 
Upvote 0
Download and install the free add-in Morefunc.xll, then try the following formula...

=COUNTDIFF(ARRAY.JOIN(Onecraft,Twocraft,Threecraft),,"")

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,981
Members
448,538
Latest member
alex78

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