• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Run-time error 1004|VBA & Macros|Excel Forum|My Online Training Hub

You are here: Home / Run-time error 1004|VBA & Macros|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumVBA & MacrosRun-time error 1004
sp_PrintTopic sp_TopicIcon
Run-time error 1004
Avatar
David Davala
Member
Members
Level 0
Forum Posts: 26
Member Since:
October 21, 2020
sp_UserOfflineSmall Offline
1
December 19, 2020 - 6:52 am
sp_Permalink sp_Print

I now have a new error. Sometimes this error pops up, sometimes it runs OK

The line in red is where it stops with an error message, "Run-time error '1004': Method 'Range' of object'_Global' failed

The range "UP84Male" is a single column of 121 rows.

 

My code is as follows:

Public Sub Annuity()

Dim ArrayMortality As Variant
Dim ArrayL(121) As Variant
Dim ArrayInt_Discount(121) As Variant

Dim Seg_1 As Variant
Dim Seg_2 As Variant
Dim Seg_3 As Variant
Dim Age As Integer

Seg_1 = 0.03
Seg_2 = 0.04
Seg_3 = 0.05
Age = 15

ArrayMortality = Range("UP84Male").Value

ArrayL(1) = 1000000
ArrayInt_Discount(1) = 1
For i = 1 To 120

'Debug.Print ArrayMortality(i, 1)
'Debug.Print ArrayL(i)
ArrayL(i + 1) = (ArrayL(i) * (1 - ArrayMortality(i, 1)))
If i <= Age Then
ArrayInt_Discount(i) = 1
ElseIf i < (Age + 5) Then
ArrayInt_Discount(i) = 1 / ((1 + Seg_1) ^ (i - Age))
ElseIf i < (Age + 20) Then
ArrayInt_Discount(i) = 1 / ((1 + Seg_2) ^ (i - Age))
Else: ArrayInt_Discount(i) = 1 / ((1 + Seg_3) ^ (i - Age))
End If

Debug.Print ArrayL(i)
'Debug.Print ArrayInt_Discount(i)
Next i

 

End Sub

Avatar
Purfleet
England
Member
Members


Trusted Members
Level 4
Forum Posts: 412
Member Since:
December 20, 2019
sp_UserOfflineSmall Offline
2
December 23, 2020 - 4:09 pm
sp_Permalink sp_Print

I dont know if your macro is doing anything before this but is it on a different worksheet when it errors? the code is not fully qualified, so it will act on the active worksheet

try Worksheets("Sheet1").Range("UP84Male").Value as a starting point (where Sheet1 is the actual sheet name with the named range)

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 612
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
3
December 23, 2020 - 8:20 pm
sp_Permalink sp_Print

If the code is in a worksheet code module, then Range("UP84Male").Value would always refer to a range on that worksheet (this seems unlikely as you'd either always get the error, or never get it).

If the code is in a normal module, then that code is the equivalent of Application.Range("UP84Male").Value and should work as long as the correct workbook is active.

Avatar
David Davala
Member
Members
Level 0
Forum Posts: 26
Member Since:
October 21, 2020
sp_UserOfflineSmall Offline
4
December 23, 2020 - 11:01 pm
sp_Permalink sp_Print

What do you mean by, "the code is not fully qualified?"

I want this code to work on any worksheet in the workbook.

Ideally, I would like it to load whenever I opened Excel. (In my personal.xlsm file?)  I need to get the calculations working first.

Avatar
Alan Elston
Out of here
Member
Members
Level 0
Forum Posts: 21
Member Since:
December 29, 2020
sp_UserOfflineSmall Offline
5
December 29, 2020 - 11:52 pm
sp_Permalink sp_Print sp_EditHistory

Hello David

Range referencing in VBA is actually quite complicated. To understand fully needs  quite a bit of reading of a good Blog, or good tuition. But mostly you are lucky and never notice its complexity,  since a simple code line like yours usually works. When it doesn’t work  is when you usually have to learn the hard way.

What is usually meant  by “unqualified” in such cases is that Excel is left to “guess” where Range("UP84Male") is.

Purfleet suggested something which would tell VBA that your range is in a worksheet which has the name "Sheet1" in the workbook where the macro is.

" Velouria" explained the typical default places that Excel “guesses” your range is at,  in certain situations

 

It’s not too clearly defined this “unqualified” thing. If your macro is in a normal code module, then with no worksheet “qualifier” reference before the Range, you can loosely call it “unqualified”. If your macro is in a worksheet object code module then you are effectively “in” that worksheet so you are referencing that worksheet.

 

To fully “qualify” your range, you would need to do something of this sort of form

Workbooks("MyBook.xls").Worksheets("MySheet").Range("UP84Male").Value

or this:

Application.Range("='[MyBook.xls]MySheet'!UP84Male").Value

 

_.____

 

Having said all this, there is a rarely  reported bug in Excel that does , seemingly randomly and inconsistently , chuck up that error you are having  even when you are “qualifying” everything fully.

That bug usually goes away if you do some activating or selecting just before the code line that typically errors, something like

Worksheet("y").Activate: Worksheet("y").Range("A1").Select

or, if dealing with multiple open workbooks,

Workbooks("x“).Activate: Worksheet("y").Activate: Worksheet("y").Range("A1").Select

 

Just to avoid confusing you, here is the same again just written a bit differently:

Worksheet("y").Activate

 Worksheet("y").Range("A1").Select

or, if dealing with multiple open workbooks,

Workbooks("x“).Activate

 Worksheet("y").Activate

 Worksheet("y").Range("A1").Select

 

In your case, if using this workaround,  it would be best if in place of x you had your workbook name, y your worksheet name, ( both being those containing your range "UP84Male" ), and finally best to be Selecting Range("UP84Male")

Note that Activating and Selecting is generally not a good idea in VBA as it is rarely needed and can slow things down. I am only suggesting it here as something to try if the error type that you are experiencing cannot be cured by correctly “qualifying” your range

_._____

Another shot in the dark, but worth a quick try: Just before the code line that errors, try a double DoEvents , like

DoEvents: DoEvents

or

DoEvents

 DoEvents

I have never known this double DoEvents to cure the particular bug I am referring to, but it does cure some similar ones

 But once again, only use this if you have to , since it can slow things down slightly.

Alan

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Andy Kirby, Alison West, Jill Niemeier, Laxmi Praveen
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
yashal minahil
Oluwadamilola Ogun
Yannik H
dectator mang
Francis Drouillard
Orlando Inocente
Jovitha Clemence
Maloxat Axmatovna
Ricardo Freitas
Marko Meglic
Forum Stats:
Groups: 3
Forums: 24
Topics: 6201
Posts: 27185

 

Member Stats:
Guest Posters: 49
Members: 31861
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.