Consulting

Results 1 to 5 of 5

Thread: Export to Excel from Access and Format Excel

  1. #1
    VBAX Regular
    Joined
    Dec 2008
    Posts
    16
    Location

    Export to Excel from Access and Format Excel

    I have this little VBA module that formats a spreadsheet in Exce that is exported from Access. I need to add the font being Arial, the size of the font being 8 and the top row being frozen. Below is the code I have that does most of the formatting except the items I need to add. Any help is appreciated.
    If this should be posted in the Excel Help forum please let me know and I will repost there.

    Formatting:
    Function FormatExcel(strFilename As String, strTabNames As String)
    Dim objXL
    Set objXL = CreateObject("Excel.Application")
    objXL.DisplayAlerts = False
    With objXL
    .Workbooks.Open (strFilename)

    ' Rename Tabs - optional
    Dim i As Integer
    i = 1
    If Len(strTabNames) Then
    arrNames = Split(strTabNames, "|")
    For Each strTabName In arrNames
    .Worksheets(i).Name = strTabName
    .Worksheets(i).AutoFilterMode = False
    .Worksheets(i).Range("A1").AutoFilter
    .Worksheets(i).Rows("1").Font.Bold = True
    .Worksheets(i).Rows("1").Interior.Color = RGB(191, 191, 191)
    .Worksheets(i).Columns("A:AQ").Columns.AutoFit
    i = i + 1
    Next
    End If

    .ActiveWorkBook.Save
    .ActiveWorkBook.Close

    End With
    objXL.DisplayAlerts = True
    Set objXL = Nothing
    End Function

  2. #2
    Moderator VBAX Master austenr's Avatar
    Joined
    Sep 2004
    Location
    Maine
    Posts
    2,033
    Location
    try this for the freeze panes:

    [VBA].Worksheets(i).Rows("1").FreezePanes = True[/VBA]
    Peace of mind is found in some of the strangest places.

  3. #3
    VBAX Regular
    Joined
    Dec 2008
    Posts
    16
    Location
    Quote Originally Posted by austenr
    try this for the freeze panes:

    [vba].Worksheets(i).Rows("1").FreezePanes = True[/vba]
    Thanks. I tried this but it blew up. I did get the size and font style parts to work. Any other ideas work be great. I am running Office 2007 if that matters.

    Function FormatExcel(strFilename As String, strTabNames As String)
    Dim objXL
    Set objXL = CreateObject("Excel.Application")
    objXL.DisplayAlerts = False
    With objXL
    .Workbooks.Open (strFilename)

    ' Rename Tabs - optional
    Dim i As Integer
    i = 1
    If Len(strTabNames) Then
    arrNames = Split(strTabNames, "|")
    For Each strTabName In arrNames
    .Worksheets(i).Name = strTabName
    .Worksheets(i).AutoFilterMode = False
    .Worksheets(i).Range("A1").AutoFilter
    .Worksheets(i).Rows("1").Font.Bold = True
    .Worksheets(i).Rows("1").Interior.Color = RGB(191, 191, 191)
    .Worksheets(i).Cells.Font.Name = "Arial"
    .Worksheets(i).Cells.Font.Size = 8
    .Worksheets(i).Columns("A:AQ").Columns.AutoFit
    ' .Worksheets(i).Rows("1").FreezePanes = True
    i = i + 1
    Next
    End If

    .ActiveWorkBook.Save
    .ActiveWorkBook.Close

    End With
    objXL.DisplayAlerts = True
    Set objXL = Nothing
    End Function

  4. #4
    Moderator VBAX Master austenr's Avatar
    Joined
    Sep 2004
    Location
    Maine
    Posts
    2,033
    Location
    Try putting this outside your for loop.

    [vba].Row(1).FreezePanes = True [/vba]

    Right after this line:

    [vba].Workbooks.Open (strFilename)
    [/vba]
    Peace of mind is found in some of the strangest places.

  5. #5
    VBAX Regular
    Joined
    Jul 2010
    Posts
    66
    Location
    I got it to work after I used .activate to show the file and sheets. here is the code that I use:

    [vba]Function FormatExcel(strFilename As String, strTabNames As String)
    Dim objXL
    Dim arrNames() As String
    Dim strTabName As Variant


    Set objXL = CreateObject("Excel.Application")
    objXL.DisplayAlerts = False
    With objXL
    .Workbooks.Open (strFilename)
    .Visible = True
    ' Rename Tabs - optional
    Dim i As Integer
    i = 1
    If Len(strTabNames) Then
    arrNames = Split(strTabNames, "|")
    For Each strTabName In arrNames
    .Worksheets(i).Activate
    .Worksheets(i).Name = strTabName
    .Worksheets(i).AutoFilterMode = False
    .Worksheets(i).Range("A1").AutoFilter
    .Worksheets(i).Rows("1").Font.Bold = True
    .Worksheets(i).Rows("1").Interior.Color = RGB(191, 191, 191)
    .Worksheets(i).Cells.Font.Name = "Arial"
    .Worksheets(i).Cells.Font.Size = 8
    .Worksheets(i).Columns("A:AQ").Columns.AutoFit
    .Worksheets(i).Range("a2").Select
    .ActiveWindow.FreezePanes = True
    i = i + 1
    Next
    End If

    .ActiveWorkBook.Save
    .ActiveWorkBook.Close

    End With
    objXL.DisplayAlerts = True
    Set objXL = Nothing
    End Function
    [/vba]
    I had to add some dim'd variables (since I always use Option Explicit). and had to activate the workbook and each sheet as it showed up... but it works. You may not have to have the workbook visible for this to work, but I put it in so I could see what was going on.

    GComyn

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •