Count Blanks in dynamic range

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,236
Office Version
  1. 365
Platform
  1. Windows
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...
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
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
 
Upvote 0
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?
 
Upvote 0
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:
Upvote 0
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,""))))
 
Upvote 0
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!
 
Upvote 0
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<>""))),""),"")
 
Upvote 0
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.
 
Upvote 0
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?
 
Upvote 0
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
 
Upvote 0

Forum statistics

Threads
1,214,621
Messages
6,120,568
Members
448,972
Latest member
Shantanu2024

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