'1004' error in Data Validation sub

PepDan

New Member
Joined
Jan 24, 2014
Messages
3
Hello,
I have the following sub within a larger macro.
Code:
Sub ValidateData()
'Insert Data Validation
    Sheets("Open Orders").Select
    Range("E3:E65536").Select
    With Selection.Validation
        .Delete
        .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:= _
        "=OFFSET('Inventory Qry'!$A$1,MATCH(C3,'Inventory Qry'!$A:$A,0)-1,1,COUNTIF('Inventory Qry'!$A:$A,C3),1)"
        .IgnoreBlank = True
        .InCellDropdown = True
        .InputTitle = ""
        .ErrorTitle = ""
        .InputMessage = ""
        .ErrorMessage = ""
        .ShowInput = True
        .ShowError = True
    End With
    Range("A1").Select
End Sub

Some users, but not all, get a 1004 error on
Code:
        .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:= _
        "=OFFSET('Inventory Qry'!$A$1,MATCH(C3,'Inventory Qry'!$A:$A,0)-1,1,COUNTIF('Inventory Qry'!$A:$A,C3),1)"

When the users gets that error I can end the sub then enter the formula into data validation and it work just fine.

Halp!!!
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.

mole999

Well-known Member
Joined
Oct 23, 2004
Messages
10,524
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
are they all using the same version of excel ? on a vanilla sheet with 2010 I get the same problem.
 

PepDan

New Member
Joined
Jan 24, 2014
Messages
3
mole999,
Thanks for replying. I found the issue.

There were some instances where the first line of data would have the cell in E3 blank and thus it was filtered out, this was causing the error.
I was able to amend the code to apply the data validation only to the visible cells and to start applying on the first visible line of data and that seemed to correct the issue.

Code:
Sub ValidateData()
'Insert Data Validation
    Sheets("Open Orders").Select
    FirstRow = Range([A3], Cells(Rows.Count, "A")).SpecialCells(xlCellTypeVisible)(1).Row
    Range("E3:E65536").SpecialCells(xlCellTypeVisible).Select
    With Selection.Validation
        .Delete
        .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:= _
        "=OFFSET('Inventory Qry'!$A$1,MATCH(C" & FirstRow & ",'Inventory Qry'!$A:$A,0)-1,1,COUNTIF('Inventory Qry'!$A:$A,C" & FirstRow & "),1)"
        .IgnoreBlank = True
        .InCellDropdown = True
        .InputTitle = ""
        .ErrorTitle = ""
        .InputMessage = ""
        .ErrorMessage = ""
        .ShowInput = True
        .ShowError = True
    End With
    Range("A1").Select
End Sub
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,163,514
Messages
5,832,192
Members
430,114
Latest member
kefier

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
Top