How to Control Excel from Word

Article contributed by Bill Coan and Dave Rado

Here's some code which uses Early Binding. It checks to see if Excel is running. If it is, the code uses the existing instance of Excel. If not, the code creates an instance of Excel.

You can get the syntax for most things you might want to do within Excel with the aid of Excel's macro recorder.

First set a reference to Excel (in the VB Editor, select Tools + References).

Sub WorkOnAWorkbook() 

Dim oXL As Excel.Application
Dim oWB As Excel.Workbook
Dim oSheet As Excel.Worksheet
Dim oRng As Excel.Range
Dim ExcelWasNotRunning As Boolean
Dim WorkbookToWorkOn As String 

'specify the workbook to work on 
WorkbookToWorkOn = "C:\My Documents\myworkbook.xls" 

'If Excel is running, get a handle on it; otherwise start a new instance of Excel
On Error Resume Next
Set
oXL = GetObject(, "Excel.Application")

If Err Then
   ExcelWasNotRunning = True
   Set oXL = New Excel.Application
End If

On Error GoTo Err_Handler

'If you want Excel to be visible, you could add the line: oXL.Visible = True here; but your code will run faster if you don't make it visible

'Open the workbook
Set oWB = oXL.Workbooks.Open(FileName:=WorkbookToWorkOn) 

'Process each of the spreadsheets in the workbook
For Each oSheet In oXL.ActiveWorkbook.Worksheets
   'put guts of your code here 
   'get next sheet 
Next oSheet 

If ExcelWasNotRunning Then
  oXL.Quit
End If

'Make sure you release object references.
Set oRng = Nothing
Set oSheet = Nothing
Set oWB = Nothing
Set oXL = Nothing

'quit 
Exit Sub

Err_Handler:
   MsgBox WorkbookToWorkOn & " caused a problem. " & Err.Description, vbCritical, _
           "Error: " & Err.Number
   If ExcelWasNotRunning Then
       oXL.Quit
   End If

End  Sub