Logicwurks Home Page

Links To Excel Code Examples

Tracing VBA Statements
Range/Wkb/Wks Variables
Add Grand Totals Using Ranges
Using Range Offset Property
Using Range Find Method
ConvertCellAddressToRange
Set Conditional Formatting
Union Of Ranges
Parse Range Strings
Delete Duplicate Rows
Delete Rows And Columns
Worksheet Variables
TypeName And TypeOf
Loop Through Worksheets
Loop Through Open Workbooks
Form Button Magic
Command Button Magic
Add Worksheets Dynamically
ImportExternalWorksheets
Find Last Row Or Column
Copy And Paste Special
Copy To Specific Cell Types
Range Copy With Filter
ExcelFileOpenSaveClose
ExcelFileOpenSaveCSV
Open An Excel File
Open An Excel File w/Params
Open An Excel File On Web
Save A Workbook
Save A Workbook Using mso
Clone A Workbook
Test If WEB URL Exists
Parse Using Split Command
Using Classes in Excel
TypeStatementStructures
Color Management
Convert Cell Color To RGB
Sort Methods 2003 - 2010
Sort Alpha/Numeric In ASCII
Search Using Match Function
Search Using Vlookup Function
Search Using Xlookup Function
Using Find Instead of Vlookup
Remove String Non-Printables
Auto_Open And Auto_Close
Initialize Form At Open
Edit Numerics In UserForm
Load Combo And List Boxes
Floating Sheet Combo Boxes
Advanced User Form Coding
Excel Events
Worksheet Change Events
Binary Search Of Array
Typecast Constants
Excel Error Handling
Handling Optional Parameters
Data Validation Drop Downs
Insert Data Validation Sub
Read A Text File w/Handle
Write A Text File w/Handle
Read a Binary File w/Handle
Update a Binary File w/Handle
Binary File Copy and Update
Read A Text Fiile w/Script
Text File Processing Examples
Test For Exists Or Open
Splash Screen
Dynamically Load Formulas
PaymentStreamsByDate
Date Examples
Date Find Same Days
Convert Month To Number
Initialize Arrays
Load Arrays Using Evaluate
ChartsAndGraphsVBA
Redim An Array
Reassign Button Action
Timer Functions
Legacy Calendar Control
Excel 2010 Date Picker
Date Picker Alternative
Generate Multiple Worksheets
Read Access Data Into Excel
Send Outlook Email w/Attach
Copy AutoFilters To Sheets
Export A Text File
Get Windows User Name
VBA Format Statement
Manipulate Files via VBA
Dynamically Load Images
Loop Through Worksheet Objects
Loop Through Form Objects
Loop Through Files with DIR
Active-X Checkboxes
Add Forms Checkboxes Dynam
Paste Pictures Into Excel
Copy Pictures Sheet To Sheet
Copy Pictures Sheet To Sheet
Create Forms Buttons With VBA
Extract Filename From Path
Convert R1C1 Format to A1
Special Cells Property
Insert Cell Comments

Links To Access Code Examples

DAO Versus ADODB
SearchVBACodeStrings
Interface Excel With Access
Create Form Manually
Create Recordset With AddNew
Multi-Select List Boxes
Update Field(s) In A Recordset
Update Excel Pivot From Access
Import A Tab Delimited File
Export Excel FileDialog
Create Excel Within Access
Open Excel Within Access
Open Excel OBJ From Access
Format Excel From Access
Control Excel via Access VBA
On Error Best Practices
Import Tab Delim w/WinAPI
Initialize Global Variables
Using TempVars For Globals
Access Error Handling
Loop Through Form Controls
Insert A Calendar Control
Create A Filtered Recordset
Populate Combo Boxes
Bookmarks And Forms
Combo Box Multiple Sources
Passing Form Objects
Create VBA SQL Statements
Create Dynamic Queries
Display File Images On A Form
Manipulate Files via VBA
Manipulate Files via Scripting
Number Subform Records
Reference Subform Objects
Parse Delimited Fields
Parameterized Queries (VBA)
Manipulating QueryDefs In VBA
FindFirst On Combined Keys
Dlookup Command
Dlookup In Form Datasheet
Execute SQL Delete Records
Commit Form To Table
Report With No Data
Reference Form Objects
DSNLess Connections To MySQL
Print Active Form Record
Count Records in Linked Tables
Delete Empty Tables
Open Linked SQL Tables

 

Export A Query To Excel Using New FileDialog Object

Office 2007 and later versions provide the new Microsoft Office 12.0 or Later Object Library which can be used to create File Save Dialog Boxes, simplifying the coding required.

Details on this technology can be viewed at:

FileDialog Object

In the following example, I illustrate the form which calls the Save FileDialog Box, and then exports a query to Excel in the target directory and file name selected by the user.

Program Code

' *********************************************************************************
' This Form Exports A Query To Excel Targeting a Selected Directory And File Name
' Using The File Save Dialog Box Procedure
' *********************************************************************************
Option Compare Database
Option Explicit

Private Sub cmdExportToExcel_Click()
' *********************************************************************************
' This Form Exports A Query To Excel To A Selected Directory And File Name
' *********************************************************************************
Dim strTitle As String
Dim strFileNameToSave As String
Dim strFilePathAndName As String

' *********************************************************************************
' Set Up Parameters For The Call To the Save Dialog Box
' *********************************************************************************
strTitle = "Export Style Master to Excel"
strFileNameToSave = "StyleMaster-" & Format(Now(), "mm-dd-yyyy-hh-mm-ss") & ".xls"

' *********************************************************************************
' Call The Save Dialog Box With Parameters And Receive The Full Path And File Name
' Which Will Be The Target For the Excel Export
' *********************************************************************************
strFilePathAndName = cmdFileDialogSave(strTitle, strFileNameToSave)

' *********************************************************************************
' Exit if the user pressed cancel
' *********************************************************************************
If strFilePathAndName = "" Then
    MsgBox ("File Not Saved")
    Exit Sub
End If

' *********************************************************************************
' Transfer the query to Excel
' *********************************************************************************
DoCmd.TransferSpreadsheet acExport, acSpreadsheetTypeExcel8, _
    "qryExportStyleMaster", strFilePathAndName, True

' *********************************************************************************
' Close The Form
' *********************************************************************************
DoCmd.Close acForm, "frmExportExcel"

End Sub


Option Compare Database
Option Explicit

Public Function cmdFileDialogSave(strTitle As String, strFileName As String) As String
'*********************************************************************
' This Module Requires Including Microsoft OFFICE 12.0 Object Library
'*********************************************************************
Dim fDialog As Office.FileDialog
Dim strFileSelected As String

'****************************************************************
' Instantiate The File Dialog Object
'****************************************************************
Set fDialog = Application.FileDialog(msoFileDialogSaveAs)

'****************************************************************
' Set Up The File Dialog Parameters
'****************************************************************
With fDialog
    .AllowMultiSelect = False
    .Title = strTitle
    .InitialFileName = strFileName
    
'****************************************************************
' Present the File Save Dialog Box
'****************************************************************
    If .Show = True Then
          strFileSelected = .SelectedItems(1)
    Else
       strFileSelected = ""
    End If
End With

'****************************************************************
' Return The Full Path and File Name
'****************************************************************
cmdFileDialogSave = strFileSelected

End Function

A Simple Example

This module demonstrates how to export an Excel file from Microsoft Access.

Program Code

Option Compare Database
Option Explicit

' ********************************************************
' ******************* I M P O R T A N T ******************
' Add Microsoft Office 14 Object Library in VBA
' Tools, References - It is required to use the
' Application.FileDialog Method
' ********************************************************
Function SaveAQueryFromAccess()
' ****************************************************************************
' Export an Excel File From Microsoft Access Based On A Query
' This Function Presents the User With A File Save Dialog Box in Access
' And Provides an Initial File Name
' ****************************************************************************
Dim strFilePathToSave As String
Dim dlgSaveAs As FileDialog
strFilePathToSave = ""

Set dlgSaveAs = Application.FileDialog(msoFileDialogSaveAs)
With dlgSaveAs
    .InitialFileName = "SigmaNest" & Int((10000 * Rnd) + 1) & ".xlsx"
    .Show
    If .SelectedItems.Count < 1 Then
        Exit Function
    End If
    strFilePathToSave = .SelectedItems(1)
End With

On Error GoTo ExportError

DoCmd.OutputTo acOutputQuery, "qryExportToExcel", "ExcelWorkbook(*.xlsx)", strFilePathToSave, False, "", , acExportQualityPrint

ExportExit:
    Exit Function

ExportError:
    MsgBox Error$
    Resume ExportExit

End Function

'****************************************************************
' An Example To Set Initial Path
'****************************************************************
Option Compare Database
Option Explicit
Private Sub cmdExportRepSummary_Click()
Dim strFilePathToSave As String
Dim dlgSaveAs As FileDialog
       
strFilePathToSave = ""

Set dlgSaveAs = Application.FileDialog(msoFileDialogSaveAs)
With dlgSaveAs
    .InitialFileName = "C:\" & strSalesRepCode & "_RepSummary_" & Format(Now(), "mm-dd-yyyy-hh-mm-ss") & ".xls"
    .Show
    If .SelectedItems.Count < 1 Then
        MsgBox ("File Not Saved")
        Exit Sub
    End If
    strFilePathToSave = .SelectedItems(1)
End With

DoCmd.TransferSpreadsheet acExport, acSpreadsheetTypeExcel8, _
    "tblFCST1RepSummary", strFilePathToSave, True

DoCmd.Close acForm, "frmFCST1ExportMonthlyRepSummary"

End Sub