I'm not sure if this will help but here's some code I used to do Excel
Automation. It will have lots of extra stuff you probably don't need but
might help? No reference is required and I believe this is a better
method to use than what's in the article but don't quote me. The code is
a little old.
Mark
RPT Software
http://www.rptsoftware.com
---------------------------------
I used these two lines to create the excel file and then to ask whether it
should be opened.
strFieldName is the path to the document you are creating
---------------------------------
Call MakeExcelFileThruAutomation(strFieldName,
"qryActualEveryThingExcelSummary")
If MsgBox("Output to Excel a success! Would you like to open the
file?", vbYesNo, "Success!") = vbYes Then Call fHandleFile(strFieldName,
WIN_NORMAL)
---------------------------------
here is the MakeExcelFileThurAutomation subroutine
---------------------------------
Private Sub MakeExcelFileThruAutomation(strWorkbookName As String,
queryname As String)
On Error GoTo Err_MakeExcelFileThruAutomation
Dim objActiveWkb As Object
Dim objXL As Object
Dim Sheet As Object
Dim rs As DAO.Recordset
Dim booXLCreated As Boolean
Dim intCol As Integer
Dim intRow As Integer
Dim HoldID As String
Dim ActualNumber As Variant
Dim ColTotal(100) As Double
Dim iii As Integer
'Dim strMessage As String
Dim strSQL As String
DoCmd.Hourglass True
' Get a instance of Excel that we can use
' If it's already open, use it.
' Otherwise, create an instance of Excel.
' I'm doing this by trying to use the Excel object.
' If it doesn't exist, an error will be raised, and
' that tells me to create an Excel instance.
On Error Resume Next
Set objXL = GetObject(, "Excel.Application")
' An error will be raised if Excel isn't already open.
If Err.Number = 0 Then
booXLCreated = False
Else
Set objXL = CreateObject("Excel.Application")
booXLCreated = True
End If
On Error GoTo Err_MakeExcelFileThruAutomation
'add a new workbook and set Sheet to first worksheet in workbook
objXL.Application.Workbooks.Add
Set objActiveWkb = objXL.Application.activeworkbook
Set Sheet = objActiveWkb.Worksheets(1)
intCol = 1
intRow = 1
HoldID = -999
For iii = 1 To 100
ColTotal(iii) = 0
Next iii
Sheet.Columns("A:A").ColumnWidth = 14
Sheet.Rows("1:1").RowHeight = 150
Sheet.Rows("1:1").WrapText = True
Sheet.Columns("A:A").Interior.ColorIndex = 15
Sheet.Rows("1:1").Interior.ColorIndex = 15
Sheet.Rows("1:1").Orientation = -90
If (queryname = "qryActualEveryThingExcel") Then 'detailed version
Sheet.Rows("2:2").Interior.ColorIndex = 15
End If
Set rs = CurrentDb().OpenRecordset(queryname, dbOpenDynaset)
If Not (rs.BOF And rs.EOF) Then
rs.MoveFirst
Do While Not rs.EOF
'see if we need to start a new column
If (queryname = "qryActualEveryThingExcel") Then 'detailed
version
If (rs("ActualID") <> HoldID) Then
intRow = 1
intCol = intCol + 1
End If
Else
If (rs("PlannedID") <> HoldID) Then
intRow = 1
intCol = intCol + 1
End If
End If
If (intRow = 1) Then 'write col headings, capture holdID
Sheet.Cells(1, intCol).Value = rs("Output")
Sheet.Cells(1, intCol).Font.Bold = True
If (Len(rs("Output")) < 50) Then
Sheet.Columns(intCol).ColumnWidth = 10
ElseIf (Len(rs("Output")) < 100) Then
Sheet.Columns(intCol).ColumnWidth = 15
Else
Sheet.Columns(intCol).ColumnWidth = 20
End If
If (queryname = "qryActualEveryThingExcel") Then 'detailed
version
Sheet.Cells(2, intCol).Value = rs("OutputText2")
Sheet.Cells(2, intCol).Font.Bold = True
HoldID = rs("ActualID")
intRow = 3
Else
HoldID = rs("PlannedID")
intRow = 2
End If
End If
If (intCol = 2) Then 'write row headings and data
Sheet.Cells(intRow, 1).Value = rs("[Grant Number]")
Sheet.Cells(intRow, 1).Font.Bold = True
Sheet.Cells(intRow, 2).Value = rs("ActualNumber")
Else 'write just data point
ActualNumber = rs("ActualNumber")
If (Nz(ActualNumber, "") <> "") Then
Sheet.Cells(intRow, intCol).Value = ActualNumber
Sheet.Cells(intRow, intCol).NumberFormat = "#,##0"
ColTotal(intCol) = ColTotal(intCol) +
CDbl(ActualNumber)
End If
End If
intRow = intRow + 1
rs.MoveNext
Loop
End If
rs.Close
Sheet.Cells(intRow, 1).Value = "TOTALS:"
Sheet.Cells(intRow, 1).Font.Bold = True
For iii = 2 To intCol
Sheet.Cells(intRow, iii).Value = ColTotal(iii)
Sheet.Cells(intRow, iii).Font.Bold = True
Sheet.Cells(intRow, iii).NumberFormat = "#,##0"
Next iii
objActiveWkb.Close SaveChanges:=True, FileName:=strWorkbookName
End_MakeExcelFileThruAutomation:
On Error Resume Next
' Clean up after yourself!
Set objActiveWkb = Nothing
If booXLCreated Then
objXL.Application.Quit
End If
Set objXL = Nothing
Set rs = Nothing
DoCmd.Hourglass False
Exit Sub
Err_MakeExcelFileThruAutomation:
MsgBox Err.Number & ": " & Err.Description & " in
MakeExcelFileThruAutomation", _
vbOKOnly + vbCritical, "Error"
Resume End_MakeExcelFileThruAutomation
End Sub
---------------------------------
Here is the fHandleFile function (module from Dev Ashish)
http://www.mvps.org/access/
I just included the entire module
---------------------------------
Option Compare Database
Option Explicit
'************ Code Start **********
' This code was originally written by Dev Ashish.
' It is not to be altered or distributed,
' except as part of an application.
' You are free to use it in any application,
' provided the copyright notice is left unchanged.
'
' Code Courtesy of
' Dev Ashish
'
Private Declare Function apiShellExecute Lib "shell32.dll" _
Alias "ShellExecuteA" _
(ByVal hwnd As Long, _
ByVal lpOperation As String, _
ByVal lpFile As String, _
ByVal lpParameters As String, _
ByVal lpDirectory As String, _
ByVal nShowCmd As Long) _
As Long
'***App Window Constants***
Public Const WIN_NORMAL = 1 'Open Normal
Public Const WIN_MAX = 3 'Open Maximized
Public Const WIN_MIN = 2 'Open Minimized
'***Error Codes***
Private Const ERROR_SUCCESS = 32&
Private Const ERROR_NO_ASSOC = 31&
Private Const ERROR_OUT_OF_MEM = 0&
Private Const ERROR_FILE_NOT_FOUND = 2&
Private Const ERROR_PATH_NOT_FOUND = 3&
Private Const ERROR_BAD_FORMAT = 11&
'***************Usage Examples***********************
'Open a folder: ?fHandleFile("C:\TEMP\",WIN_NORMAL)
'Call Email app: ?fHandleFile("mailto:
[email protected]",WIN_NORMAL)
'Open URL: ?fHandleFile("
http://home.att.net/~dashish",
WIN_NORMAL)
'Handle Unknown extensions (call Open With Dialog):
' ?fHandleFile("C:\TEMP\TestThis",Win_Normal)
'Start Access instance:
' ?fHandleFile("I:\mdbs\CodeNStuff.mdb", Win_NORMAL)
'****************************************************
Function fHandleFile(stFile As String, lShowHow As Long)
Dim lRet As Long, varTaskID As Variant
Dim stRet As String
'First try ShellExecute
lRet = apiShellExecute(hWndAccessApp, vbNullString, _
stFile, vbNullString, vbNullString, lShowHow)
If lRet > ERROR_SUCCESS Then
stRet = vbNullString
lRet = -1
Else
Select Case lRet
Case ERROR_NO_ASSOC:
'Try the OpenWith dialog
varTaskID = Shell("rundll32.exe shell32.dll,OpenAs_RunDLL "
_
& stFile, WIN_NORMAL)
lRet = (varTaskID <> 0)
Case ERROR_OUT_OF_MEM:
stRet = "Error: Out of Memory/Resources. Couldn't Execute!"
Case ERROR_FILE_NOT_FOUND:
stRet = "Error: File not found. Couldn't Execute!"
Case ERROR_PATH_NOT_FOUND:
stRet = "Error: Path not found. Couldn't Execute!"
Case ERROR_BAD_FORMAT:
stRet = "Error: Bad File Format. Couldn't Execute!"
Case Else:
End Select
End If
fHandleFile = lRet & _
IIf(stRet = "", vbNullString, ", " & stRet)
End Function
'************ Code End **********
Vsn said:
Hi all,
I have used some prety code to export and query or tabel from my access
application to excel file, sheet and finaly cells from
http://www.databasejournal.com/features/msaccess/article.php/3563671/Export-Data-To-Excel.htm
All works fine on the exporting side.
Only question i have, i am not able to figure it, why does the excel file
not come 'open/show' to the screen? Moreover when i try to open the file
form its location, it gives a message that the file is already open and
would i like to open it again and loose anychanges to the last open
version. By clikking NO the created file shows to the screen.
Could any one tell me how i could open to the screen directly after it
creates the file. It would be to great help for me.
Thx a lot,
Ludovic