Wrox Programmer Forums

Need to download code?

View our list of code downloads.

Go Back   Wrox Programmer Forums > Microsoft Office > Access and Access VBA > Access VBA
Password Reminder
Register
| FAQ | Members List | Calendar | Search | Today's Posts | Mark Forums Read
Access VBA Discuss using VBA for Access programming.
Welcome to the p2p.wrox.com Forums.

You are currently viewing the Access VBA section of the Wrox Programmer to Programmer discussions. This is a community of tens of thousands of software programmers and website developers including Wrox book authors and readers. As a guest, you can read any forum posting. By joining today you can post your own programming questions, respond to other developers’ questions, and eliminate the ads that are displayed to guests. Registration is fast, simple and absolutely free .
DRM-free e-books 300x50
Reply
 
Thread Tools Search this Thread Display Modes
  #1 (permalink)  
Old June 20th, 2006, 02:09 PM
Registered User
 
Join Date: Jun 2006
Location: Aberdeen, , Denmark.
Posts: 1
Thanks: 0
Thanked 0 Times in 0 Posts
Default Export Access queries to Excel

I have 14 Access 2000 queries that I wish to export to a single Excel 2000 Worksheet with the output of each query being exported to a separate worksheet within the workbook. Is this possible from within Access and if so how is it done?

Thanks

Craig

Reply With Quote
  #2 (permalink)  
Old June 22nd, 2006, 07:32 PM
Authorized User
 
Join Date: Jul 2004
Location: , , .
Posts: 30
Thanks: 0
Thanked 0 Times in 0 Posts
Default

Private Sub CmdTrns_Click()

DoCmd.TransferSpreadsheet acExport, acSpreadsheetTypeExcel9, "Query2", "C:\Documents and Settings\Owner\Desktop\MySpreadsheet.xls", , "Sheet2"

DoCmd.TransferSpreadsheet acExport, acSpreadsheetTypeExcel9, "Query3", "C:\Documents and Settings\Owner\Desktop\MySpreadsheet.xls", , "Sheet3"

End sub

Reply With Quote
  #3 (permalink)  
Old August 18th, 2006, 11:21 AM
pjm pjm is offline
Authorized User
 
Join Date: Jul 2006
Location: Boston, MA, USA.
Posts: 70
Thanks: 0
Thanked 0 Times in 0 Posts
Default

My interpretation of your question is that you want to place the the SQL code for all
your queries onto one sheet and make a separate sheet for each of the resulting tables
from these queries. My code for this is below. Note that I create a brand new Excel file
and that there are certain caveats that I listed near the bottom of the code.

Public Sub QueryToExcel(ExcelFile As String)
Dim db As Database
Dim qdf As QueryDef

Dim qryCount As Integer
Dim SheetName As String

Dim xlApp As Excel.Application
Dim xlBook As Excel.Workbook
Dim xlSheet As Excel.Worksheet

    Set xlApp = CreateObject("Excel.Application")
    Set xlBook = xlApp.Workbooks.Add
    Set xlSheet = xlBook.Worksheets(1)

    'Make the worksheet visible.
    xlSheet.Application.Visible = True

    Set db = CurrentDb()

    With db
        qryCount = 0
        For Each qdf In .QueryDefs
            qryCount = qryCount + 1
            ' Output qryCount, .Name and .SQL to the next line
            ' in a sheet in the Excel file
            With xlSheet.Cells(qryCount, 1)
                .Value = Str(qryCount)
                .Font.Size = 12
                .Font.Bold = True
            End With
            With xlSheet.Cells(qryCount, 2)
                .Value = qdf.Name
                .Font.Size = 12
                .Font.Bold = True
            End With
            With xlSheet.Cells(qryCount, 3)
                .Value = qdf.SQL
                .Font.Size = 10
            End With
        Next qdf
    End With

    'Save the new worksheet, close Excel and clear the object variable.
    xlSheet.SaveAs ExcelFile
    xlSheet.Application.Quit
    Set xlSheet = Nothing

    ' Create new sheets in the newly created Excel file for
    ' the results of each of the queries
    With db
        qryCount = 0
        For Each qdf In .QueryDefs
            With qdf
                qryCount = qryCount + 1
                SheetName = "Query" & Trim(Str(qryCount))

                ' Create a new sheet in the specified Excel file with
                ' the output of the named query.
                ' If there is a pre-existing one with the same name
                ' the new sheet will have a "1" appended to its name.

                ' Problems or issues:
                ' 1. Invalid queries will error out
                ' 2. Action queries will error out
                ' 3. Queries with parameters will require user input

                DoCmd.TransferSpreadsheet acExport, acSpreadsheetTypeExcel9, _
                    .Name, ExcelFile, , SheetName
            End With
        Next qdf
        .Close
    End With

End Sub

-Phil-
Reply With Quote
Reply


Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

BB code is On
Smilies are On
[IMG] code is Off
HTML code is Off
Trackbacks are Off
Pingbacks are On
Refbacks are Off


Similar Threads
Thread Thread Starter Forum Replies Last Post
Export an Access query to Excel Peter Martin Access 5 June 8th, 2006 06:36 AM
Queries export to excel ymeyaw Access VBA 0 April 21st, 2006 01:17 AM
Access and Excel Queries in VB Mihai B Access VBA 1 January 24th, 2005 08:40 AM
Exported Access Parameter Queries to Excel vallasca Access VBA 4 January 19th, 2005 07:34 PM
Export Table from Access to Excel aramchan Access VBA 2 July 12th, 2004 03:20 PM



All times are GMT -4. The time now is 05:59 PM.


Powered by vBulletin®
Copyright ©2000 - 2020, Jelsoft Enterprises Ltd.
© 2013 John Wiley & Sons, Inc.