Forum Discussion
VBA troubleshooting: "Object variable or With block variable not set" How do I fix this?
I'm using Excel version 15.38 for Mac and I'm getting a runtime error that I don't know how to fix it. This macro worked perfectly for months, I stopped using this spreadsheet over the summer, and today when I go to use it again, it mysteriously won't work. When I try to run it, it gets stuck saying there's a runtime error 91 Object variable or With block variable not set.
If I click on "debug", the following code is highlighted:
Selection.Find(What:="visit amazon's ", After:=ActiveCell, LookIn:= _
xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:= _
xlNext, MatchCase:=False).Activate
(Attached screenshot is what the data looks like prior to running the macro. The macro is supposed to remove punctuation, remove certain phrases etc.)
Can any of you smart people tell me what's wrong? I don't understand VBA code at all - this macro was created by recording me doing all this stuff manually - but I'm good at following directions :)
For what it's worth, here is the entire macro code from start to finish:
Sub step1_amazon_keywordprocessing()
'
' step1_amazon_keywordprocessing Macro
' Change to lower_Use data text to columns to get rid of : and (_get rid of Visit Amazon's_Get rid of page
'
' Keyboard Shortcut: Option+Cmd+r
'
Range("B1").Select
ActiveCell.FormulaR1C1 = "=LOWER(RC[-1])"
Range("B1").Select
Selection.AutoFill Destination:=Range("B1:B201"), Type:=xlFillDefault
Range("B1:B201").Select
Columns("B:B").Select
Selection.Copy
Columns("C:C").Select
Selection.PasteSpecial Paste:=xlValues, Operation:=xlNone, SkipBlanks:= _
False, Transpose:=False
Columns("B:B").Select
Application.CutCopyMode = False
Selection.ClearContents
Columns("A:A").Select
Selection.ClearContents
Range("C1").Select
Selection.Copy
Columns("A:A").Select
Columns("C:C").Select
Application.CutCopyMode = False
Selection.Copy
Columns("A:A").Select
ActiveSheet.Paste
Columns("C:C").Select
Application.CutCopyMode = False
Selection.ClearContents
Columns("A:A").Select
Selection.TextToColumns Destination:=Range("A1"), DataType:=xlDelimited, _
TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _
Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _
:=":", FieldInfo:=Array(Array(1, 1), Array(2, 1))
Columns("B:H").Select
Selection.ClearContents
Columns("A:A").Select
Selection.TextToColumns Destination:=Range("A1"), DataType:=xlDelimited, _
TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _
Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _
:="(", FieldInfo:=Array(1, 1)
Columns("B:H").Select
Selection.ClearContents
Columns("A:A").Select
Selection.Find(What:="visit amazon's ", After:=ActiveCell, LookIn:= _
xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:= _
xlNext, MatchCase:=False).Activate
ExecuteExcel4Macro _
"FORMULA.REPLACE(""visit amazon's "","""",2,1,FALSE,FALSE,,FALSE,FALSE,FALSE,FALSE)"
Selection.Find(What:=" page", After:=ActiveCell, LookIn:=xlFormulas, _
LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, _
MatchCase:=False).Activate
ExecuteExcel4Macro _
"FORMULA.REPLACE("" page"","""",2,1,FALSE,FALSE,,FALSE,FALSE,FALSE,FALSE)"
End Sub
Thank-you in advance to anyone who can help me with this - I really appreciate it! :)
14 Replies
- karthickrichardCopper Contributor
Just leaving this response here in case someone finds this useful. I was facing a similar issue when running a macro. I was trying to run the macro on a recently downloaded file and it kept throwing the Runtime Error 91. Enabling Editing (clicking on Enable Editing) fixed the issue for me.
- LaPaz5640Copper ContributorI am having a similar issue with "Error 91". My code includes "Error Handling", but for some weird reason, after the cell search has failed once and correctly executed my code, a subsequent search failure causes the macro to bomb with "Error 91". It's as though a line of reset code is needed after the 1st failed search.
Here is my complete code...
Sub Confirm_Quicken_Data_Links()
' This macro searches the "Expenditure" sheet for each Payee Link held in "Quicken Data". Search results are stored in the "LinkTest".
' A check is made for Payees having a "2-Line" Header text.
Dim N As Integer
Dim X As String
Dim Y As Integer
Dim Row As Integer
Dim Col As Integer
Dim Payee As String
Dim PayeeAddrs As String
Dim PayeeLinkAddrs As String
Dim Payees As Integer
Dim ExpenseCategory As String
Dim LinkRange As Range
Sheets("Quicken Data").Select
N = 0
Range("B1").Select
Selection.End(xlToRight).Select
Payees = ActiveCell.Column - 1
Set LinkRange = Sheets("Expenditures").Range("LinkRange")
Range("B1").Offset(0, N).Select
Do While N <= Payees
Err.Clear
Payee = ActiveCell
PayeeAddrs = ActiveCell.Address
PayeeLinkAddrs = ActiveCell.Offset(15, 0).AddressLocal
PayeeAddrs = "'Quicken Data'!" & PayeeAddrs
X = "IFERROR(SEARCH(CHAR(10)," & PayeeAddrs & "),0)"
Range("SearchCell_2").Select ' Cell location for "Formula" search
ActiveCell.Formula = "=" & X
If ActiveCell.Value = 0 Then ' 1-LINE Header Text(Payee Name)
Y = 0
Else
Y = 1 ' 2-LINE Header Text(Payee Name)
End If
Sheets("Expenditures").Select
Range("A1").Select
On Error Resume Next
Cells.Find(What:=PayeeLinkAddrs, After:=ActiveCell, LookIn:=xlFormulas _
, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, _
MatchCase:=True, SearchFormat:=False).Activate
On Error GoTo NOTFOUND
If Err.Number = 0 Then ' No Error - Search String Found
Expense = ActiveCell.Offset(0, -5).Value
Sheets("LinkTest").Select
Range("A2").Offset(N, 0).Select
If Y = 1 Then
X = "Replace(" & PayeeAddrs & ", Search(CHAR(10)," & PayeeAddrs & "), 1, CHAR(32))"
ActiveCell.Formula = "=" & X
Else
ActiveCell = Payee
End If
Range("A2").Offset(N, 1) = PayeeLinkAddrs
Range("A2").Offset(N, 2) = Expense
Else
NOTFOUND:
Sheets("LinkTest").Select
Range("A2").Offset(N, 0).Select
If Y = 0 Then
X = "Replace(" & PayeeAddrs & ", Search(CHAR(10)," & PayeeAddrs & "), 1, CHAR(32))"
ActiveCell.Formula = "=" & X
Else
ActiveCell = Payee
End If
Range("A2").Offset(N, 1) = PayeeLinkAddrs
Range("A2").Offset(N, 2) = "Not Found"
End If
N = N + 1
Expense = ""
Sheets("Quicken Data").Select
Range(PayeeLinkAddrs).Offset(-15, 1).Select ' Next Payee
Loop
End Sub
Thanks- LaPaz5640Copper Contributor
Sorry for simply adding my problem to your conversation. I couldn't figure out how to create my own post! But the main issue is the same as yours.
- Zack BarresseIron Contributor
That code will definitely fail. You're using the Selection object to find something after the ActiveCell. If nothing is found, an error is thrown. Overall it's very messy code. The macro recorder makes sure of that. But, it does make a great starting place!
It looks like you took some repetitive actions in the recorded code. I'm not 100% that I followed everything, but I removed all of the Select methods you called, which aren't needed at all. Also, there is no worksheet referenced for the ranges, so it will ALWAYS run on the ActiveSheet. If you are always going to run this code on this worksheet, then it won't be a problem.
Here is the code:
Sub step1_amazon_keywordprocessing() ' ' step1_amazon_keywordprocessing Macro ' Change to lower_Use data text to columns to get rid of : and (_get rid of Visit Amazon's_Get rid of page ' ' Keyboard Shortcut: Option+Cmd+r ' Range("B1:B201").FormulaR1C1 = "=LOWER(RC[-1])" Columns("B:B").Copy Columns("C:C").PasteSpecial Paste:=xlValues Application.CutCopyMode = False Columns("A:B").ClearContents Columns("C:C").Copy Columns("A:A") Columns("C:C").ClearContents Application.CutCopyMode = False Columns("A:A").TextToColumns Destination:=Range("A1"), DataType:=xlDelimited, _ TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _ Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _ :=":", FieldInfo:=Array(Array(1, 1), Array(2, 1)) Columns("B:H").ClearContents Columns("A:A").TextToColumns Destination:=Range("A1"), DataType:=xlDelimited, _ TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _ Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _ :="(", FieldInfo:=Array(1, 1) Columns("B:H").ClearContents Columns("A:A").Find(What:="visit amazon's ", After:=ActiveCell, LookIn:= _ xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:= _ xlNext, MatchCase:=False).Activate ExecuteExcel4Macro "FORMULA.REPLACE(""visit amazon's "","""",2,1,FALSE,FALSE,,FALSE,FALSE,FALSE,FALSE)"
On Error Resume Next Columns("A:A").Find(What:=" page", After:=Range("A1"), LookIn:=xlFormulas, _ LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, _ MatchCase:=False).Activate
On Error Goto 0 ExecuteExcel4Macro "FORMULA.REPLACE("" page"","""",2,1,FALSE,FALSE,,FALSE,FALSE,FALSE,FALSE)" End SubI would recommend stepping through your code the first time, until you know it's working right. To do that, just put your cursor anywhere in this routine (to make it the active routine) and the F8 key will step through each line of code. Tapping the F8 key will execute a single line of code at a time. The yellow highlighted line is the one which will run when you press F8.
Also, I added bare-minimum error handling to your Find method. This will ensure it doesn't bomb when executing that line. More importantly, I took out the Selection object you used, and replaced ActiveCell with Range("A1").
HTH
- Sheralyn GCopper Contributor
Thank-you SO much for doing that Zack - I can't tell you how much I appreciate you taking the time :) I learned some new things from what you said that will come in handy over the long term. Plus, it was informative to see your cleaner version of the macro code and I intend to study it until I understand what it's doing.
(Writing all the rest of this partly in case someone else comes along who finds this useful...)
I went through the code line by line as you said, and figured out that the recorded code was getting stuck on the part where it had to find "Visit Amazon's " because in this particular set of data, that wasn't on there. Then the same issue would happen when it was supposed to find " page" because that wasn't in this set of data either.
(For non-techies like me who might read this: F8 didn't work on my Mac (maybe it's a Windows-only shortcut?), but using the little button in the VBA editor that looked like a down error pointing to a dot, which said "step into" if I hovered over it, seems to do the same thing as F8 was supposed to do.)
So I saw what you meant when you said "If nothing is found, an error is thrown."
So if I created a test line that DID contain "Visit Amazon's Test Author page", the macro with the messy recorded code ran fine.
But since I don't want to do the work of adding that every time I want to clean up my data with the macro (just in case it doesn't contain that stuff), I added "On Error Resume Next" before each section of the macro that was supposed to find and replace since the stuff it's looking for won't always be found and that's no big deal.
Now the macro works despite the messy code.
My next job is to play with YOUR code.
AND, by the way, this ""On Error Resume Next" that you added to your cleaner code is seriously a game changer since now I can make the macro also look for symbols and punctuation marks, and replace those with nothing - this is HUGE for me since prior to your response, I couldn't get the macro to do that for me (which I now understand is because it would get stuck if the thing it was looking for wasn't present). WAHOO! This new knowledge will save me loads of tedious, repetitive manual fixing up in future since now I can make a macro do it all FOR me without getting itself stuck. THANK-YOU SO MUCH!!!
re: "Also, there is no worksheet referenced for the ranges, so it will ALWAYS run on the ActiveSheet."
Yes, this is okay for my purposes - but thanks for pointing that out!
I'm going to go play with the code more now. This non-techie is so flipping happy with this you have no idea :D- Zack BarresseIron Contributor
Very happy to help! :)
I'm not sure about Mac, but I don't think they have the F-keys on their keyboards and it's typically a PC thing. I use the VBE (Visual Basic Editor) keyboard shortcuts all the time. Huge time savers.
I wasn't sure what your Excel4Macro was supposed to be doing, but if it's just replacing values, you can do that in one fell swoop too:
RangeToWorkWith.Replace What:="This", Replacement:="That", LookAt:=xlPart
The benefit for this is, not only is it taking care of two lines in one fell swoop, but it won't throw an error like the Find method will, so no need to wrap it in error handling.
As long as we're talking about error handling, it should be noted this is the least preferred method for handling errors. The first is to take logical action in your code to prevent known errors from forming. The next would be trapping errors - performing some kind of check if an error was processed, like "If Err.Number <> 0".
Thanks for the detailed response. Have a great day!