ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   How do I count the # of unique occurences of a text in a column? (https://www.excelbanter.com/excel-worksheet-functions/50350-how-do-i-count-unique-occurences-text-column.html)

Rob Kaiser

How do I count the # of unique occurences of a text in a column?
 
I am looking for a command/formulat to count (return a single number) the
number of unique text entries in a column.

Peo Sjoblom

One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...
I am looking for a command/formulat to count (return a single number) the
number of unique text entries in a column.




Duke Carey

This is VERY resource intensive, so be careful using it on a list of several
thousand entries

It's an array formula - enter it with the key combination Ctrl+Shift+Enter

=SUM(1/COUNTIF(A1:A10,A1:A10))



"Rob Kaiser" wrote:

I am looking for a command/formulat to count (return a single number) the
number of unique text entries in a column.


Duke Carey

I like yours MUCH better, Peo

"Peo Sjoblom" wrote:

One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...
I am looking for a command/formulat to count (return a single number) the
number of unique text entries in a column.





Aladin Akyurek

It's the SumProduct version of Hager's formula extended to take care of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...

I am looking for a command/formulat to count (return a single number) the
number of unique text entries in a column.





JayMan

How do I count the # of unique occurences of a text in a colum
 
Experts
How do you adjust this to account for columns that may be different in
length? One time you need A375 and the next time you use it is A584.


JayMan

"Aladin Akyurek" wrote:

It's the SumProduct version of Hager's formula extended to take care of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...

I am looking for a command/formulat to count (return a single number) the
number of unique text entries in a column.





T. Valko

How do I count the # of unique occurences of a text in a colum
 
Sounds like you want to use a dynamic range. See this:

http://contextures.com/xlNames01.html#Dynamic

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
Experts
How do you adjust this to account for columns that may be different in
length? One time you need A375 and the next time you use it is A584.


JayMan

"Aladin Akyurek" wrote:

It's the SumProduct version of Hager's formula extended to take care of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...

I am looking for a command/formulat to count (return a single number)
the
number of unique text entries in a column.







JayMan

How do I count the # of unique occurences of a text in a colum
 
T
Do I now plug that in like this, Range is the name of the range
{=SUM(IF(Range<"",1/COUNTIF(Range,Range)))}

not really sure here

JayMan

"T. Valko" wrote:

Sounds like you want to use a dynamic range. See this:

http://contextures.com/xlNames01.html#Dynamic

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
Experts
How do you adjust this to account for columns that may be different in
length? One time you need A375 and the next time you use it is A584.


JayMan

"Aladin Akyurek" wrote:

It's the SumProduct version of Hager's formula extended to take care of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...

I am looking for a command/formulat to count (return a single number)
the
number of unique text entries in a column.








T. Valko

How do I count the # of unique occurences of a text in a colum
 
Yes. However, I would use the SUMPRODUCT formula that was posted in your
thread:

=SUMPRODUCT((Range<"")/COUNTIF(Range,Range&""))

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
T
Do I now plug that in like this, Range is the name of the range
{=SUM(IF(Range<"",1/COUNTIF(Range,Range)))}

not really sure here

JayMan

"T. Valko" wrote:

Sounds like you want to use a dynamic range. See this:

http://contextures.com/xlNames01.html#Dynamic

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
Experts
How do you adjust this to account for columns that may be different in
length? One time you need A375 and the next time you use it is A584.


JayMan

"Aladin Akyurek" wrote:

It's the SumProduct version of Hager's formula extended to take care
of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...

I am looking for a command/formulat to count (return a single
number)
the
number of unique text entries in a column.










JayMan

How do I count the # of unique occurences of a text in a colum
 
THANK YOU

"T. Valko" wrote:

Yes. However, I would use the SUMPRODUCT formula that was posted in your
thread:

=SUMPRODUCT((Range<"")/COUNTIF(Range,Range&""))

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
T
Do I now plug that in like this, Range is the name of the range
{=SUM(IF(Range<"",1/COUNTIF(Range,Range)))}

not really sure here

JayMan

"T. Valko" wrote:

Sounds like you want to use a dynamic range. See this:

http://contextures.com/xlNames01.html#Dynamic

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
Experts
How do you adjust this to account for columns that may be different in
length? One time you need A375 and the next time you use it is A584.


JayMan

"Aladin Akyurek" wrote:

It's the SumProduct version of Hager's formula extended to take care
of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in message
...

I am looking for a command/formulat to count (return a single
number)
the
number of unique text entries in a column.











T. Valko

How do I count the # of unique occurences of a text in a colum
 
You're welcome!

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
THANK YOU

"T. Valko" wrote:

Yes. However, I would use the SUMPRODUCT formula that was posted in your
thread:

=SUMPRODUCT((Range<"")/COUNTIF(Range,Range&""))

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
T
Do I now plug that in like this, Range is the name of the range
{=SUM(IF(Range<"",1/COUNTIF(Range,Range)))}

not really sure here

JayMan

"T. Valko" wrote:

Sounds like you want to use a dynamic range. See this:

http://contextures.com/xlNames01.html#Dynamic

--
Biff
Microsoft Excel MVP


"JayMan" wrote in message
...
Experts
How do you adjust this to account for columns that may be different
in
length? One time you need A375 and the next time you use it is A584.


JayMan

"Aladin Akyurek" wrote:

It's the SumProduct version of Hager's formula extended to take
care
of
formula-blanks and empty cells,

{=SUM(IF(A1:A10<"",1/COUNTIF(A1:A10,A1:A10)))}

Duke Carey wrote:
I like yours MUCH better, Peo

"Peo Sjoblom" wrote:


One way

=SUMPRODUCT((A1:A10<"")/COUNTIF(A1:A10,A1:A10&""))


Regards,

Peo Sjoblom

"Rob Kaiser" <Rob wrote in
message
...

I am looking for a command/formulat to count (return a single
number)
the
number of unique text entries in a column.














All times are GMT +1. The time now is 04:57 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com