Help With Formula (Using A Reference In A Range)

CaliKidd

Board Regular
Joined
Feb 16, 2011
Messages
173
I have a simple Excel 2003 workbook, consisting of 4 sheets named REF, CAT 1, CAT 2, and Summary.

On the Summary Sheet, I have the following formula:

=COUNTIF('CAT 2'!A5:A65536,'CAT 1'!A1)

Basically, it just tallies the number of matches it finds in the range A5:A65536 of the CAT 2 sheet using a criteria I've placed in cell A1 of the CAT 1 sheet.

Here's the problem:
In the formula, instead of referring to the last row explicitly (65536), I would like to use a reference to cell A1 of the REF sheet. I would use Application.Rows.count to place the last row value in cell A1 of the REF sheet so that if someone was using Excel 2007 or higher, the value of that cell would be 1048576, not 65536.

I tried the following combinations using a concatenation approach (my modifications in red), but they didn't work:
=COUNTIF('CAT 2'!A5:A & REF!A1,'CAT 1'!A1)

=COUNTIF("'CAT 2'!A5:A" & REF!A1,'CAT 1'!A1)

=COUNTIF('CAT 2'!"A5:A" & REF!A1,'CAT 1'!A1)

=COUNTIF('CAT 2'!"A5:A & REF!A1",'CAT 1'!A1)

Can someone please tell me what the formula (in A1 format, not R1C1 format) should be?
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
You don't need to explicitly state the last row in a COUNTIF. As long as there can't be any matches in rows 1:4, try:

=COUNTIF('CAT 2'!A:A,'CAT 1'!A1)

otherwise, try:

=COUNTIF('CAT 2'!A5:INDEX('CAT 2!A:A,REF!A1),'CAT 1'!A1)
 
Upvote 0
Do you mean in VBA? If so, you could use:
Code:
"=COUNTIF('CAT 2'!A5:" & Rows.Count & ",'CAT 1'!A1)"
 
Upvote 0
You can use this

=COUNTIF('CAT 2'!A5:INDEX('CAT 2'!A:A,REF!A1) ,'CAT 1'!A1)


However, I don't recommend using a number = to the last available row...
Rather, use a formula to determine the last occupied row...

Like this

If the column is Numeric
=MATCH(9.99999999999999E307,'CAT 2'!A:A)

If the column is Text
=MATCH(REPT("Z",255),'CAT 2'!A:A)


Hope that helps.
 
Upvote 0
I have a simple Excel 2003 workbook, consisting of 4 sheets named REF, CAT 1, CAT 2, and Summary.

On the Summary Sheet, I have the following formula:

=COUNTIF('CAT 2'!A5:A65536,'CAT 1'!A1)

Basically, it just tallies the number of matches it finds in the range A5:A65536 of the CAT 2 sheet using a criteria I've placed in cell A1 of the CAT 1 sheet.

Here's the problem:
In the formula, instead of referring to the last row explicitly (65536), I would like to use a reference to cell A1 of the REF sheet. I would use Application.Rows.count to place the last row value in cell A1 of the REF sheet so that if someone was using Excel 2007 or higher, the value of that cell would be 1048576, not 65536.

I tried the following combinations using a concatenation approach (my modifications in red), but they didn't work:
=COUNTIF('CAT 2'!A5:A & REF!A1,'CAT 1'!A1)

=COUNTIF("'CAT 2'!A5:A" & REF!A1,'CAT 1'!A1)

=COUNTIF('CAT 2'!"A5:A" & REF!A1,'CAT 1'!A1)

=COUNTIF('CAT 2'!"A5:A & REF!A1",'CAT 1'!A1)

Can someone please tell me what the formula (in A1 format, not R1C1 format) should be?
Try it like this...

=COUNTIF(INDIRECT("'CAT 2'!A5:A"&REF!A1),'Cat 1'!A1)
 
Upvote 0
Thanks all,

I appreciate the help.

Since I am always trying to learn more, I have one more question.

First, a comment for closure:
You don't need to explicitly state the last row in a COUNTIF.
Comment: Yes, I know, but I have data in Cells A1 - A4 that would throw off my COUNTIF results if I referenced the entire column.

Question:
The range I am using contains text. Which is faster in execution?

A) =COUNTIF('CAT 2'!A5:INDEX('CAT 2'!A:A,REF!A1),'CAT 1'!A1)
B) =COUNTIF(INDIRECT("'CAT 2'!A5:A"&REF!A1),'Cat 1'!A1)
C) Using =MATCH vs =COUNTIF?
 
Upvote 0
I would presume that A is Faster than B, Indirect is a volatile function and almost always slower.

Match is Faster than COUNTIF.
Match will stop searching once the value is found, while Countif actually must evaluate every single cell in the range.

However, match and countif are 2 very different things.
Match will only tell you if the value exists in the range(and where it is)
Match will NOT tell you how many times it exists in the range, only countif will do that.
 
Upvote 0
Thanks all,

I appreciate the help.

Since I am always trying to learn more, I have one more question.

First, a comment for closure:

Comment: Yes, I know, but I have data in Cells A1 - A4 that would throw off my COUNTIF results if I referenced the entire column.

Question:
The range I am using contains text. Which is faster in execution?

A) =COUNTIF('CAT 2'!A5:INDEX('CAT 2'!A:A,REF!A1),'CAT 1'!A1)
B) =COUNTIF(INDIRECT("'CAT 2'!A5:A"&REF!A1),'Cat 1'!A1)
C) Using =MATCH vs =COUNTIF?
MATCH is faster than COUNTIF.
 
Upvote 0
I would presume that A is Faster than B, Indirect is a volatile function and almost always slower.
In my tests the INIRECT version is "faster" when tested on a range of 100 rows. However, the differences are negligible.

The INDEX version is "faster" on ranges of 1000 and 10,000 rows. Again, the differences are negligible.

In each case the average difference was about 0.00003 seconds.
 
Upvote 0
Thanks again, all. I am always looking for the fastest method. In my case, I guess MATCH is not an option for me since I need to evaluate every cell in the range.

Thanks again. Cheers!
 
Upvote 0

Forum statistics

Threads
1,224,578
Messages
6,179,654
Members
452,934
Latest member
mm1t1

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