Count Blanks in dynamic range

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,212
Dear Smartest Excelers Around,

I want to count blanks in a horizontal range (all in one row) that will change (dynamic range). The values in the range could be numbers or words. Some values may be added to the end, but there may still be some empty cells to the right of the last value. My goal is to count blanks in the range up to the last entered value, but no beyond that. As an example:

A6 = 2
B6 = empty cell
C6 = 2
D6 = empty cell
E6 = tt
F6 = empty cell

The range for the count blanks would be A6:E6. F6 is not included because the last entered value is in cell E6.

The answer (count blanks in dynamic range) should be 2.

I have got these 3 formulas to work, but it seems that there must be a better (shorter, faster calculating, more elegant) formula than these:

=COUNTBLANK(OFFSET(A6,,,,MATCH(9.9E+307,MATCH(A6:F6,A6:F6)+TRANSPOSE(ROW(INDIRECT(""1:""&COLUMNS(A6:F6)))))))

=COUNTBLANK(OFFSET(A6,,,,MATCH(9.9E+307,MATCH(A6:F6,A6:F6)+{1,2,3,4,5,6})))

=COUNTBLANK(A6:INDEX(A6:F6,MATCH(9.9E+307,MATCH(A6:F6,A6:F6)+TRANSPOSE(ROW(INDIRECT(""1:""&COLUMNS(A6:F6)))))))

Any ideas?

P.S. The trouble I was having with creating a formula was that all the blanks became zeros when I started analyzing it with MATCH and other functions...
 

Matty

Well-known Member
Joined
Feb 17, 2007
Messages
3,707
Hello Mike,

Perhaps:

Excel Workbook
ABCDE
622tt
7
82
Sheet3
Excel 2003
#VALUE!
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}. Note: Do not try and enter these manually yourself
Does this do as expected?

Matty
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
By any chance, will the last value in the row always be a text value? And will new data continue to be added beyond Column F?
 

EB08

Active Member
Joined
Jun 9, 2008
Messages
343
A different thought: why not create a dynamic named range first, then use countif? Create a range, in my case "VarRange" with the formula below; then use =countif(VarRange,"")...you can adjust the size of the range to fit your needs.

confirmed CSE

Code:
=OFFSET($A$6,,,,LARGE(IF($A$6:$F$6<>"",COLUMN($A$6:$F$6),""),1))
You could always adjust this named range in the Insert<NAME<DEFINE p column larger a handle it have to section count.< range<NAME<DEFINE allow>
 
Last edited:

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,212
Matty,
It does do as expected. The formula is very nice! In particular, I like the INDEX:INDEX to trick COUNTIF into thinking there are no arrays!!

Domenic,
1) The last value could be a numeric or text value.
2) New data will not be added beyond the template edge (whatever range that is). The range probably will never run past 100 columns.

EB08,
I like it – very straight forward! And if it were not in column A:
=COUNTBLANK(OFFSET($A$7,,,,MAX(IF($A$7:$F$7<>"",COLUMN($A$7:$F$7)-COLUMN($A$7)+1,""))))
 

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,212
Matty,

I guess this would be better:

=COUNTIF(A7:INDEX(A7:F7,MATCH(2,1/(A7:F7<>""))),"")

Because I want to count all the blanks before the last value entered, even if the blanks are in the first few cells.

I am still amazed with the INDEX tricking the COUNTIF into not seeing the array!
 

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,212
And since the template could start totally blank, then this seems to work:

=IF(COUNTA(A11:F11),COUNTIF(A11:INDEX(A11:F11,MATCH(2,1/(A11:F11<>""))),""),"")
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
Here's a variation on the formula offered by Matty...

=COUNTBLANK(A6:INDEX(A6:F6,MATCH(2,1/(A6:F6<>""))))

...confirmed with CONTROL+SHIFT+ENTER. Note that like Matty's formula, this formula avoids the volatile function OFFSET.
 

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,212
Thanks, Matty, EB08 and Domenic!

Domenic, I clicked on the link in your signature line (xl-central.com). Is that a web site that you created?
 

Matty

Well-known Member
Joined
Feb 17, 2007
Messages
3,707
Hello Mike,

The formula I posted considers the starting point of the array to be the first Cell in range A6:F6 that is not equal to blank, but if the starting point is constant, i.e. always A6, then the...

INDEX(A6:F6,MATCH(TRUE,A6:F6<>"",0))

...part isn't required (which you've worked out for yourself).

It's quite ironic that Domenic should reply to your post as well, as he was the guy who showed me this technique in the first place, when I had a similar problem to you.

So it's Domenic who really deserves the appreciation, not me! :)

Matty
 

Forum statistics

Threads
1,082,250
Messages
5,364,022
Members
400,774
Latest member
Goldi paul

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top