VBA - IsEmpty on filtered dataset

jcooooper

Board Regular
Joined
Mar 24, 2018
Messages
74
Office Version
  1. 365
Platform
  1. Windows
Hi all,

I have a code that filters data, and then I have the following function:

Code:
If IsEmpty([B]Range("A14").Offset(1, 0)[/B]) = False Then


    
    'Is not blank
    MsgBox "ABC"
    
Else
    'Is blank


MsgBox "XYZ"

Essentially I'm trying to see if the next available row in the data is blank.... but the offset function looks includes the filtered data.

Is there any way to select the row below the active cell, excluding the filtered data? i.e the same that would be selected if you just press the down arrow on a filtered data set?

Many thanks!
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Do you want the first empty row below your data or do you want to test the next filtered row below current active cell to see if column A is blank ?

Please post the line of code which filters the data

thanks
 
Last edited:
Upvote 0
Might be a bit hard as there are named ranges, but essentially the filter columns are row 14...


Code:
Sub Funds_futures()


If ActiveSheet.AutoFilterMode Then ActiveSheet.AutoFilterMode = False


Sheets("Data").Select
Range("A14").Select




Range("Data_column_headers").AutoFilter Range("data_portfolio_name").Column, Application.Transpose(Range("Mapping_cash_portfolio_codes")), xlFilterValues
Range("Data_column_headers").AutoFilter Field:=Range("data_security_group").Column, Criteria1:="<>Cash"


If IsEmpty(Range("A14").Offset(1, 0)) = False Then


    

    MsgBox "Test 1"
    
Else



MsgBox "Test 2."


If ActiveSheet.AutoFilterMode Then ActiveSheet.AutoFilterMode = False


End If
I'm trying to ascertain if the once the above filters are applied, if anything is left from A15 downwards

One way to do that is just press the down arrow from A14...if that's blank there's nothing left. The offset(1,0) just selects A15 (which always has a value).

Hope that makes sense
 
Last edited:
Upvote 0
see if this returns the correct cell for you

Code:
Sub NextCell()
   
    MsgBox Range("A15", Range("A" & Rows.Count)).SpecialCells(xlCellTypeVisible).Cells(1, 1).Address(0, 0)
   
End Sub
 
Upvote 0
see if this returns the correct cell for you

Code:
Sub NextCell()
   
    MsgBox Range("A15", Range("A" & Rows.Count)).SpecialCells(xlCellTypeVisible).Cells(1, 1).Address(0, 0)
   
End Sub

I can't seem to get this to work, just returns a message box with the row number? Unless I'm doing it wrong. I've tried it in various places in my code
 
Upvote 0
Using your original code

Code:
Sub NextCell()
    If IsEmpty(Range("A15", Range("A" & Rows.Count)).SpecialCells(xlCellTypeVisible).Cells(1, 1)) = False Then
        MsgBox "ABC"
    Else
        MsgBox "XYZ"
    End If
End Sub
 
Upvote 0
Using your original code

Code:
Sub NextCell()
    If IsEmpty(Range("A15", Range("A" & Rows.Count)).SpecialCells(xlCellTypeVisible).Cells(1, 1)) = False Then
        MsgBox "ABC"
    Else
        MsgBox "XYZ"
    End If
End Sub

Works perfect, thanks so much!
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,972
Members
448,537
Latest member
Et_Cetera

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