BLOGS BY TOPIC▼
BLOGS BY AUTHOR▼
BLOGS BY YEAR▼
This blog is part of a complete Excel VBA tutorial. Wise Owl's main business, however, is providing classroom-based VBA (and other) training courses.
Posted by Andy Brown on 09 December 2011
You need a minimum screen resolution of about 700 pixels width to see our blogs. This is because they contain diagrams and tables which would not be viewable easily on a mobile phone or small laptop. Please use a larger tablet, notebook or desktop computer, or change your screen resolution settings.
An Alternative Method - CreateObject and GetObject
This blog describes how to create or get an object (useful when you want to link to another Microsoft application). What I'll do is first show how to do this, then consider the pros and cons of the approach.
This blog gives a summary of an alternative way to create references. If you want to know more about the subject - including why you might want to create a reference in the first place, and what this means - read my earlier blog on how to create references in VBA.
Using an Existing Copy of Word
If you are already running an application like Word, you can get a reference to this running application using GetObject:
Sub PutCellInWord()
Dim WordApp As Object
'get reference to running copy of Word
Set WordApp = GetObject(Class:="Word.Application")
WordApp.Visible = True
'add a new document, and show contents of cell A1 in it
WordApp.Documents.Add
WordApp.Selection.TypeText (Range("A1").Value)
WordApp.Selection.TypeParagraph
End Sub
Notice that in the above code you can't declare WordApp as a Word application - you have to be vaguer, and just say it's an object.
Using a New or Existing Copy of Word
What happens if the application you're trying to link to isn't running (or worse, if it might be, and you're not sure)? The answer is to try getting a reference to a running copy of the application, and if this fails create a new one. If this sounds complicated, the code is fairly standard and easy:
Option Explicit
'variable to hold reference to Word
Dim WordApp As Object
Sub PutCellInWord()
'get a reference to a copy of Word (new or existing)
GetWordReference
'make copy of Word visible
WordApp.Visible = True
'add a new document, and show contents of cell A1 in it
WordApp.Documents.Add
WordApp.Selection.TypeText (Range("A1").Value)
WordApp.Selection.TypeParagraph
End Sub
Sub GetWordReference()
'if Word isn't open, jump to this label
On Error GoTo NoCurrentWord
'try to get a reference to running copy of Word
Set WordApp = GetObject(Class:="Word.Application")
'if we get here, Word was open ==> can leave
Exit Sub
NoCurrentWord:
'if we get here, Word wasn't open - so create a new copy
Set WordApp = CreateObject(Class:="Word.Application")
End Sub
The above code calls the GetWordReference procedure to get a reference to Word (whether to an open copy, or failing this to a newly created one).
Pros and Cons of this Approach
Why would you use CreateObject/GetObject rather than references? The disadvantages include:
- The above code uses something called late binding. What this means is that VBA doesn't know that the variable WordApp refers to a Word application until run time, which means it can't optimise the code when it's compiled and will run slightly more slowly.
- Another consequence of this late binding is that you can't use autocompletion (intellisense) when writing the above macro, since VBA doesn't know what sort of thing WordApp is at this point.
The advantages include:
- The references above aren't version specific (they'll work whichever version of Word you have on your computer).
- The code above uses an existing copy of Word where one is available, avoiding the unnecessary overhead of creating a new application.
As implied above, my recommendation for most people would be to ignore this blog!