MrCleanFinalFinal

In my last post on working with strings, I demonstrated some VBA with a call to the Regular Expression (RegExp) library to split alpha characters from numeric characters where no delimiter was present. Today I received a data set that contained 10’s of thousand of strings that contained some trailing stuff that I wanted to remove. My initial thought was to use the RegExp engine with the correct pattern, but I discovered a better way.

The Requirements

Upon review of the strings, the pattern I discovered:

  1. The string always begin with an alpha or numeric character with a mix of upper and lower case
  2. The string I need to preserve end with an alpha or numeric character with a mix of upper and lower case
  3. Everything from the beginning of the of the first alphanumeric to the last alphanumeric must be preserved as is, spaces, case, special characters, whatever
  4. Everything trailing to right of the last alphanumeric may safely be removed, special characters, non-printable characters, spaces, whatever
  5. Strings are of random lengths both input and output

So, I need to :

  1. Search from the end (right) of the string
  2. Find the first alphanumeric character irregardless of case
  3. Return the string beginning from the first character to the character position determined in the previous step

Quick Segue – The Functions

Before I get to the Sub Procedure, I would like to review all of the Functions I am using to make the process fairly dynamic :

GetSelectedSheet

Here I am using an InputBox to allow the user to select a worksheet at run-time. The InputBox Method has 1 required parameter and 7 optional parameters. If the optional parameters are not utilized, then the InputBox returns a text value. However, The optional Type parameter makes the InputBox more powerful. In the function, I am using Type:=8 to return a cell reference as a Range Object. You can read more about the InputBox Method here.

Public Function GetSelectedSheet() As String
    
    'Declare variables
        Dim ws                          As Worksheet
        Dim rng                         As Range
    
    'Users - select a cell on a worksheet
        Set rng = InputBox( _
                    Prompt:="Please select a cell on a worksheet", _
                    Title:="Select a worksheet", _
                    Default:=ActiveCell.Address, _
                    Type:=8) 'Range selection
                    
    'Get the parent worksheet of the selected cell
        Set ws = rng.Parent
        
    'Pass the name of the worksheet to the function
        GetSelectedSheet = ws.Name
    
    'Tidy up
        Set rng = Nothing
        Set ws = Nothing
 End Function

GetRows

Fairly straight forward, I pass the selected worksheet to the function and it returns the maximum rows of data based on Column 1. I could make this more dynamic by passing a column number to the function as well, but I generally always use Column 1.

Public Function GetRows(ws As Worksheet) As Long

    Dim r As Long
    
    With ws
        r = .Cells(Rows.Count, 1).End(xlUp).Row
    End With
    
    GetRows = r
End Function

GetColumns

Straight forward, I pass the selected worksheet to the function and it returns the maximum columns of data based on Row 1. I could make this more dynamic by passing a row number to the function as well, but I generally always use Row 1.

Public Function GetColumns(ws As Worksheet) As Long

     'Declare variables    
           Dim c As Long
    
     'Get column count, store it in a variable    
          With ws
               c = .Cells(1, Columns.Count).End(xlToLeft).Column
          End With

     'Pass the variable value to the function
          GetColumns = c
End Function

GetUserInput

Again, fairly straight forward. Get a text value from the user to search for in the next function.
I call the function like this :

    'User - What is search term?
        strSearchTerm = GetUserInput(strPrompt:="What is the search term?", _
                                     strTitle:="Find Column Number")
Public Function GetUserInput(strPrompt As String, _
                             strTitle As String) As String
       
    'Declare variables
         Dim strUserInput As String
       
    'Call the InputBox Method, pass user input to a variable
          strUserInput = InputBox(Prompt:=strPrompt, _
                                  Title:=strTitle)

    'Pass the variable value to the function                                 
         GetUserInput = strUserInput

End Function

GetColumnNumber

The function has 2 arguments, a worksheet and a string value that I got from the user in the last function. The function will create a Range Object and search that Range for the term supplied by the user. Again, I am using Row 1 here, but I could make it more dynamic by passing a row number to the function as one of its arguments. Below, I am using the Named Argument, LookAt:= and passing the value xlPart instead of xlWhole. You may want to consider this in your VBA Projects as you program defensively around what the user may input. Since I am using this for myself, I am not too concerned for now,

Public Function GetColumnNumber(ws As Worksheet, _
                                strSearchTerm As String) As Long

    'Declare variables
        Dim rng As Range
        Dim MaxColumns As Long
        Dim lngField As Long
        
    'Initialize
        MaxColumns = GetColumns(ws:=ws)
        With ws
            Set rng = .Range(.Cells(1, 1), .Cells(1, MaxColumns))
        End With
        
    'Find columns number
        lngField = rng.Find(What:=strSearchTerm, _
                            LookIn:=xlValues, _
                            LookAt:=xlPart, _
                            MatchCase:=False).Column
                            
    'Pass the column number to the function
        GetColumnNumber = lngField
        
    'Tidy up
        Set rng = Nothing

End Function

GetCleanAlphaNumeric

This is the money! All other functions to this point were setup work to allow this function to do the heavy lifting. The function uses the LIKE operator to compare a character beginning at the right-most position of the string to the pattern, “[0-9A-Za-z]”. As soon as a match is found, the For..Next Loop is exited, thus saving time by not checking characters unnecessarily. I then use the MID() Function to get the string from the 1st character to the last alphanumeric character position determined in the For..Next Loop. More on the LIKE operator here.

Public Function GetCleanAlphaNumeric(strChar As String) As String
    
    'Comments   :   Remove non-alpha numeric characters from end of string
   
    'Declare variables
        Dim i As Long
        Dim lngLengthString As Long
        Dim blnTest As Boolean
        Dim posLastAlphaNumeric As Long
        Dim strClean As String
   
    'Initialize
        blnTest = False

    'Length of string to check
        lngLengthString = Len(CStr(strChar))
        
    'Compare each charcter to pattern
    'Begin at end of string
    'Stop as soon as find alphanumeric
        For posLastAlphaNumeric = lngLengthString To 1 Step -1
            blnTest = Mid(CStr(strChar), posLastAlphaNumeric, 1) Like "[0-9A-Za-z]"
            If blnTest = True Then Exit For
        Next posLastAlphaNumeric
        
    'posLastAlphaNumeric is the position of last AlphaNumeric character
    'Use the position of the last alphanumeric to get the final length of the string
    'Assign the value to the range
        strClean = CStr(Mid(strChar, 1, posLastAlphaNumeric))
        
    'Pass the clean string to the function
        GetCleanAlphaNumeric = strClean

 End Function

The Main Procedure

Here is the main procedure that calls all of the functions. Note: Screen updating must be on for the user to select a cell on a worksheet. Turn ScreenUpdating off after the user selects a cell on a worksheet.

Option Explicit
Sub CleanStrings()
     
    'Author:        Winston Snyder
    'Date:          3/28/14
    'Purpose:       Get string excluding non-alphanumeric trailing characters
    '---------------------------------------------------------------------------------------------------------------------------------------------
     
    'Declare variables
        Dim wb                                  As Workbook
        Dim ws                                  As Worksheet
        Dim rng                                 As Range
        Dim C                                   As Range
        Dim strSearchTerm                       As String
        Dim strStringToBeCleaned                As String
        Dim lngColumnNumber                     As Long
        Dim MaxRows                             As Long
     
    'Excel environment - speed things up
        With Application
            .DisplayAlerts = False
            .EnableEvents = False
            .Calculation = xlCalculationManual
        End With
     
    'Initialize
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets(GetSelectedSheet)
        Application.ScreenUpdating = False
        
    'Get maximum number of rows on the worksheet
        MaxRows = GetRows(ws:=ws)
         
    'User - What is search term?
        strSearchTerm = GetUserInput(strPrompt:="What is the search term?", _
                                     strTitle:="Find Column Number")
                                     
    'Get the column number based on the search term
        lngColumnNumber = GetColumnNumber(ws:=ws, _
                                          strSearchTerm:=strSearchTerm)
                                          
    'Define the range that contains strings to be cleaned
        With ws
            Set rng = .Range(.Cells(2, lngColumnNumber), .Cells(MaxRows, lngColumnNumber))
        End With
        
    'Clean each string in the range
        For Each C In rng
            strStringToBeCleaned = CStr(C.Value)
            C.Value = GetCleanAlphaNumeric(strChar:=strStringToBeCleaned)
        Next C

    'Tidy up
             
        'Destroy objects
            Set C = Nothing
            Set rng = Nothing
            Set ws = Nothing
            Set wb = Nothing
             
        'Restore Excel environment
            With Application
                .ScreenUpdating = True
                .DisplayAlerts = True
                .EnableEvents = True
                .Calculation = xlCalculationAutomatic
            End With
End Sub

Tidy up

    Final Thoughts

    That’s it today. I like the LIKE operator. This process is fast, reviewed 25K strings, and updated them when needed in no time. Awesome!

,

SpyVsSpyLg

In January, I wrote a post that demonstrated how to combine Excel Workbooks. That post assumed that each of the source workbooks contained at least one ListObject Object.

Today, I will revise that code a bit to add a ListObject Object (LO) if the lo does not exist. Then I will demonstrate the code to merge Workbooks using Range Objects. Lastly, I will compare both processes to see which is the fastest using the Windows High Resolution Timer.


    edit: As is my usual practice, I am going to use Late Binding in the sample snippets below. A discussion on Late / Early Binding is beyond the scope of this post. Please see these links for a detailed explanation of Late / Early Binding.

    1. Beyond Excel
    2. JP Software Technologies


The ListObject Object (LO)

One of the very useful features the LO, is that it offers us the three distinct properties: HeaderRowRange, DataBodyRange, TotalsRowRange. Once we have a LO, we can leverage these properties to streamline the heavy lifting.

ListObjectRanges

Check If The ListObject Object Exists

I can check if the LO exists, if not, I can add one while I’m looping through workbooks:

Option Explicit

Sub AddListObjectIfDoesNotExist()

    'Does a  ListObject Object exist?
    
    Dim wb As Workbook
    Dim ws As Worksheet
    Dim lo As ListObject
    
    Set wb = ThisWorkbook
    For Each ws In wb.Worksheets
        Set lo = ws.Range("A1").ListObject
        If lo Is Nothing Then
            Set lo = ws.ListObjects.Add( _
                                    SourceType:=xlSrcRange, _
                                    Source:=ws.Range("A1").CurrentRegion, _
                                    Destination:=ws.Range("A1"))
        Else
            'ListObject already exists - do nothing
        End If
    Next ws
    
    'Tidy up
        Set lo = Nothing
        Set wb = Nothing
End Sub

Now that I can add an LO dynamically, I can exploit its properties with assurance.

Here is the fully revised code to merge Excel Workbooks using ListObject Objects:

Option Explicit
 
Sub MergeWorbooksUsingListObjects()
     
    'Log:
    'Date               Author                      Action                  Comment
    '-------------------------------------------------------------------------------------------------------------------
    '1/26/2014           ws                         Created                 Merge workbooks using ListObjects from source files
    '3/23/2014           ws                         Modified                If ListObject does not exist, add ListObject
    '-------------------------------------------------------------------------------------------------------------------
     
    'Delare variables
        Dim wb                  As Workbook
        Dim wbData              As Workbook
        Dim ws                  As Worksheet
        Dim wsData              As Worksheet
        Dim rngData             As Range
        Dim rngDestination      As Range
        Dim lo                  As ListObject
        Dim fso                 As Object
        Dim fsoFolder           As Object
        Dim fsoFile             As Object
        Dim strSelectedFolder   As String
        Dim strCurrentPath      As String
        Const strSpecifiedPath  As String = "C:\"
        Dim lngRows             As Long
        Dim blnFlag             As Boolean
         
    'Excel environment - speed things up
        With Application
            .ScreenUpdating = False
            .DisplayAlerts = False
            .EnableEvents = False
            .Calculation = xlCalculationManual
        End With
         
    'Initialize variables
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets("Data")
        blnFlag = True
         
    'Clear data from control workbook from previous consolidations
        ws.UsedRange.ClearContents
     
    'Get the current path, so reset the path at the end of the procedure
        strCurrentPath = CurDir()
         
    'Set the target directory to get the user closer to the working folder
    'This will minimize the time the user must spend drilling into the file system
    'once they are presented with the FileDialog
        ChDir (strSpecifiedPath)
     
    'Create a FileSystemObject
        Set fso = GetFSO
 
    'Prompt the user to select a folder
    'Return the path of the selected folder
        strSelectedFolder = GetSelectedFolder
         
    'Get the FSO Folder of the selected folder
        Set fsoFolder = fso.GetFolder(strSelectedFolder)
         
    'Loop each file in folder
    'Copy data from each file to control workbook
        For Each fsoFile In fsoFolder.Files
            Set wbData = Workbooks.Open(fsoFile)
            Set wsData = wbData.Worksheets("Sheet1")
             
            'Get next blank row from destination worksheet
            'If first time, need row 1, else, next blank row
                lngRows = GetRows(ws:=ws)
                If blnFlag = False Then lngRows = lngRows + 1
                 
            'The Destination Range
                Set rngDestination = ws.Cells(lngRows, 1)
             
            With wsData
                'If a ListObject does not exist, add a ListObject
                    Set lo = .Range("A1").ListObject
                    If lo Is Nothing Then
                        Set lo = .ListObjects.Add( _
                                              SourceType:=xlSrcRange, _
                                              Source:=.Range("A1").CurrentRegion, _
                                              Destination:=ws.Range("A1"))
                    Else
                        'Do nothing, ListObject already exists
                    End If
                
                'If first workbook, include the header row
                    For Each lo In .ListObjects
                        If blnFlag = True Then
                            Set rngData = Union(lo.HeaderRowRange, lo.DataBodyRange)
                            blnFlag = False
                        Else
                            Set rngData = lo.DataBodyRange
                        End If
                    Next lo
            End With
  
            'Copy the Data Range to the Destination Range
                rngData.Copy
                rngDestination.PasteSpecial xlPasteValuesAndNumberFormats
                 
            'Close the source file without saving
                wbData.Close
         
        Next fsoFile
         
    'Tidy up
        'Restore to original path
            ChDir (strCurrentPath)
             
        'Restore Excel environment
            With Application
                .ScreenUpdating = True
                .DisplayAlerts = True
                .EnableEvents = True
                .Calculation = xlCalculationAutomatic
            End With
             
        'Destroy objects
            Set fsoFolder = Nothing
            Set fso = Nothing
            Set lo = Nothing
            Set rngData = Nothing
            Set rngDestination = Nothing
            Set ws = Nothing
            Set wb = Nothing
         
End Sub

And the functions:


Public Function GetRows(ws As Worksheet) As Long
 
    Dim r       As Long
     
    With ws
        r = .Cells(Rows.Count, 1).End(xlUp).Row
        GetRows = r
    End With
     
End Function

'-------------------------------------------------------------------------
Public Function GetFSO()
 
    Dim fso             As Object
     
    Set fso = CreateObject("Scripting.FileSystemObject")
    Set GetFSO = fso
     
    Set fso = Nothing
 
End Function

'-------------------------------------------------------------------------
Public Function GetSelectedFolder() As String
     
    Dim diaFolder       As FileDialog
    Dim strFolder       As String
 
    Set diaFolder = Application.FileDialog(msoFileDialogFolderPicker)
    With diaFolder
        .AllowMultiSelect = False
        .Show
        strFolder = .SelectedItems(1)
    End With
 
    GetSelectedFolder = strFolder
End Function

Works great!

The Range Object

The Range Object does not have the properties: HeaderRowRange, DataBodyRange, TotalsRowRange. I am ok with the entire Range from the first Workbook when Merging multiple Workbooks. But on subsequent Workbooks, I want to exclude the header row.

Assume I have a Range named rng with address $A$1:$G$10, from this, I would like to exclude the header row on Row 1. The first step is to count the number of rows and columns in the range

Dim r As Long
dim c As Long
r = rng.Rows.Count
c = rng.Columns.Count

Next, from the rng, move down 1 Row. This means the rng address is now $A$2:$G$11

rng.Offset(1)

The $A$2 part of the address is good, but the $G$11 part means I now have a blank row. So now I need to Resize the rng to exclude the blank row:

rng.Offset(1).Resize(r-1,c)

And test the final Range Address to make sure all is as expected:

Debug.Print rng.Address

$A$2:$G$10

Perfect! Exactly what I was looking for. I’m now ready to modify the code again to use Range Objects instead of ListObject Objects.

Merge Workbooks Using Range Objects

Here’s the working code to merge workbooks using Range Objects instead of ListObject Objects:

Option Explicit
 
Sub MergeWorbooksUsingRangeObjects()
     
    'Log:
    'Date               Author                      Action                  Comment
    '-------------------------------------------------------------------------------------------------------------------------------------------
    '1/26/2014           ws                         Created                 Merge workbooks using ListObjects from source files
    '3/23/2014           ws                         Modified                If ListObject does not exist, add ListObject
    '3/23/2014           ws                         Modified                Use Range Object, modify range to exclude header row if not File = 1
    '-------------------------------------------------------------------------------------------------------------------------------------------
     
    'Delare variables
        Dim wb                  As Workbook
        Dim wbData              As Workbook
        Dim ws                  As Worksheet
        Dim wsData              As Worksheet
        Dim rngData             As Range
        Dim rngDestination      As Range
        Dim fso                 As Object
        Dim fsoFolder           As Object
        Dim fsoFile             As Object
        Dim strSelectedFolder   As String
        Dim strCurrentPath      As String
        Const strSpecifiedPath  As String = "C:\"
        Dim lngRows             As Long
        Dim r                   As Long
        Dim c                   As Long
        Dim blnFlag             As Boolean
         
    'Excel environment - speed things up
        With Application
            .ScreenUpdating = False
            .DisplayAlerts = False
            .EnableEvents = False
            .Calculation = xlCalculationManual
        End With
         
    'Initialize variables
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets("Data")
        blnFlag = True
         
    'Clear data from control workbook from previous consolidations
        ws.UsedRange.ClearContents
     
    'Get the current path, so reset the path at the end of the procedure
        strCurrentPath = CurDir()
         
    'Set the target directory to get the user closer to the working folder
    'This will minimize the time the user must spend drilling into the file system
    'once they are presented with the FileDialog
        ChDir (strSpecifiedPath)
     
    'Create a FileSystemObject
        Set fso = GetFSO
 
    'Prompt the user to select a folder
    'Return the path of the selected folder
        strSelectedFolder = GetSelectedFolder
         
    'Get the FSO Folder of the selected folder
        Set fsoFolder = fso.GetFolder(strSelectedFolder)
         
    'Loop each file in folder
    'Copy data from each file to control workbook
        For Each fsoFile In fsoFolder.Files
            Set wbData = Workbooks.Open(fsoFile)
            Set wsData = wbData.Worksheets("Sheet1")
             
            'Get next blank row from destination worksheet
            'If first time, need row 1, else, next blank row
                lngRows = GetRows(ws:=ws)
                If blnFlag = False Then lngRows = lngRows + 1
                 
            'The Destination Range
                Set rngDestination = ws.Cells(lngRows, 1)
             
            With wsData
                'Create the data range
                    Set rngData = .Range("A1").CurrentRegion
                    r = rngData.Rows.Count
                    c = rngData.Columns.Count
                
                'If first workbook, include the header row, otherwise resize the range to exclude the header row
                    If blnFlag = True Then
                        blnFlag = False
                    Else
                        Set rngData = rngData.Offset(1).Resize(r - 1, c)
                    End If
            End With
  
            'Copy the Data Range to the Destination Range
                rngData.Copy
                rngDestination.PasteSpecial xlPasteValuesAndNumberFormats
                 
            'Close the source file without saving
                wbData.Close
         
        Next fsoFile
         
    'Tidy up
        'Restore to original path
            ChDir (strCurrentPath)
             
        'Restore Excel environment
            With Application
                .ScreenUpdating = True
                .DisplayAlerts = True
                .EnableEvents = True
                .Calculation = xlCalculationAutomatic
            End With
             
        'Destroy objects
            Set fsoFolder = Nothing
            Set fso = Nothing
            Set rngData = Nothing
            Set rngDestination = Nothing
            Set ws = Nothing
            Set wb = Nothing
         
End Sub

That worked well, next I’ll add a little bit of code to time each of the Subs() to see if there is any appreciable difference.

Windows High-Resolution Timer (WHRT)

To use WHRT, I’ll just need to add 3 lines of code:

Declare a reference to the kernel32 library

Public Declare Function GetTickCount Lib "kernel32.dll" () As Long

Get the tick count and assign it to a variable

t = GetTickCount

Get the tick count at the end, subtract the first to calculate elapsed time

debug.print GetTickCount - t & " Milliseconds"

I’ll put the Public Function “GetTickCount” in a Module with my other Public Functions.
I normally put the first call to the Public Function near the top of a Sub(), but in this case I’m using a FileDialog to interact with the user so I want to place the call to the Function after the FileDialog:

    'Prompt the user to select a folder
    'Return the path of the selected folder
        strSelectedFolder = GetSelectedFolder
        
    'Get the tick count
        t = GetTickCount

The last call to the GetTickCount Function goes at the very end of the code:

            Set ws = Nothing
            Set wb = Nothing
            
        'Get elapsed time
             Debug.Print GetTickCount - t & " Milliseconds"

The Results

The Sub() adding the ListObject Object dynamically:

1420 Milliseconds
1233 Milliseconds
1419 Milliseconds
1419 Milliseconds
1248 Milliseconds
1451 Milliseconds
1435 Milliseconds
1264 Milliseconds
1653 Milliseconds
1264 Milliseconds
——————–
1380.6 Milliseconds Avg

The Sub() Resizing the Range Object:

1217 Milliseconds
1217 Milliseconds
1451 Milliseconds
1264 Milliseconds
1232 Milliseconds
1232 Milliseconds
1248 Milliseconds
1263 Milliseconds
1264 Milliseconds
1248 Milliseconds
————————
1263.6 Milliseconds Avg

Tidy Up

    Final Thoughts

    The Sub() using the Range Object is a bit faster, but not much. Bear in mind, I ran the process on 3 files -each file with 50 rows and 7 columns. The results may be more pronounced on more files with more data in each file.

    Downloads

    Download the file containing both Subs() and all Functions here.

    Additional Resources

    ListObject Objects

    ListObject Object Model
    ListObjects Object Model
    Working with Tables in Excel 2013, 2010 and 2007 (VBA)
    Working with Microsoft Excel tables in VBA

    Range Object

    The Range Object – Object Model

, , ,

ExportCrop

A member over on one of the LinkedIn Excel Groups had a question about how to export 1 to several worksheets from an Excel Workbook to a pdf file.

Below is the method I use to load a Sheets Array from the list the user defined on a worksheet. There are other ways to do this such as based on the ColorIndex of the tab, some character in the name of the worksheet or the code name of the worksheet.

Option Explicit
    
Sub ExportXLToPDF()

    'Comments:
    'Assume list of worksheets to be included in output are listed in Column 1 on "List"

    Dim wb                  As Workbook
    Dim ws                  As Worksheet
    Dim Arr()               As String
    Dim MaxRows             As Long
    Dim i                   As Long
    Dim strPath             As String
    Dim strFileName         As String
    Const strEXTENSION      As String = ".pdf"
    
    Set wb = ThisWorkbook
    Set ws = wb.Worksheets("List")
    
    'User - where to save the output file
        strPath = GetFolder & "\"
        
    'User - what to name the output file
        strFileName = GetUserInput(strPrompt:="Please enter a name for the output file", _
                                   strTitle:="File Name")
        
    'Assume list to be included in sheets array in on worksheet named list in Column 1 beginning in Row 1
    'Total number of rows is dynamic
        MaxRows = GetRows(ws:=ws)
        
    'Redim the array to hold the name of the worksheets
        ReDim Preserve Arr(1 To MaxRows)
    
    'Load the list of sheets to be included into the array
        For i = 1 To MaxRows
            Arr(i) = ws.Cells(i, 1).Value
        Next i
        
    'Select the sheets array
        Sheets(Arr).Select
 
    'Export to the sheets array to pdf
        ActiveSheet.ExportAsFixedFormat Type:=xlTypePDF, _
                                        Filename:=strPath & strFileName & strEXTENSION, _
                                        Quality:=xlQualityStandard, _
                                        IncludeDocProperties:=True, _
                                        IgnorePrintAreas:=False, _
                                        OpenAfterPublish:=False
                    
    'Tidy up
        'Erase arrays
            Erase Arr
        
        'Destroy objects
            Set ws = Nothing
            Set wb = Nothing
End Sub

And the functions:


Public Function GetRows(ws As Worksheet) As Long
 
    Dim r       As Long
     
    With ws
        r = .Cells(Rows.Count, 1).End(xlUp).Row
        GetRows = r
    End With
     
End Function

Public Function GetUserInput(strPrompt As String, _
                             strTitle As String) As String
      
    Dim strUserInput As String
      
    strUserInput = InputBox(Prompt:=strPrompt, _
                            Title:=strTitle)
                              
    GetUserInput = strUserInput
  
End Function

Public Function GetFolder() As String
  
    Dim fd As FileDialog
    Dim strFolderName As String
    Set fd = Application.FileDialog(msoFileDialogFolderPicker)
      
    With fd
        .Title = "Please select a folder"
        .AllowMultiSelect = False
        .Show
        strFolderName = .SelectedItems(1)
    End With
  
    GetFolder = strFolderName
      
    Set fd = Nothing
End Function
,

FishingTrim

I’m not much of an angler these days. In my younger days, I pulled my share out of the Skunk River and lakes around central Iowa and southern Minnesota. Sit back and I’ll tell you a tale about the one that got away….

Kidding – today’s post is the third in a series about Microsoft Scripting in VBA. In the first post I covered the FileSystemObjct (FSO). In the second post, I looked at Regular Expressions (RegExp).

Previous posts:

  1. FileSystemObject (FSO)
  2. Regular Expressions

Today, I’ll look at the TextStream Object.

The TextStream Object

The TextStream Object enables you to read from and write to text files from Excel using VBA and the Microsoft Scripting Runtime Library (scrrun.dll)


    edit: I am going to use Late Binding in the sample snippets below. A discussion on Late / Early Binding is beyond the scope of this post. Please see these links for a detailed explanation of Late / Early Binding.

    1. Beyond Excel
    2. JP Software Technologies


Public Variables

Because I am using Late Binding, I’ll declare some Public Constants for working with the TextStream Object

Public Const gclForReading As Long = 1
Public Const gclForWriting As Long = 2
Public Const gclForAppending As Long = 8
Public Const gclTristateUseDefault As Long = -2
Public Const gclTristateTrue As Long = -1
Public Const gclTristateFalse As Long = 0

Tristate specifies the format of the text file:

  1. TristateUseDefault = -2 ; Opens the file using the system default
  2. TristateTrue = -1 ; Opens the file as Unicode
  3. TristateFalse = 0 ; Opens the file as ASCII

I also would like to create a function to let users choose a file or a folder. To use the function I’ll create global constants using the MsoFileDialogType Enumeration:

Public Const gclmsoFileDialogFilePicker As Long = 3
Public Const gclmsoFileDialogFolderPicker As Long = 4
Public Const gclmsoFileDialogOpen As Long = 1
Public Const gclmsoFileDialogSaveAs As Long = 2

CreateTextFile Method

I’ll use the CreateTextFile Method of the FileSystemObject (FSO) to create a TextStream Object and write a little message to the file:

Option Explicit
Sub WriteToText()

    'Author     :   Winston Snyder
    'Date       :   2/12/2014
    'Purpose    :   Write to a text file

    'Declare variables
        Dim fso             As Object
        Dim fsoFolder       As Object
        Dim fsoFile         As Object
        Dim ts              As Object
        Dim strFileName     As String
        Dim strFolderName   As String

    'Allow the user to choose a folder location to save the text file to
        strFolderName = GetFolder

    'Get file name from user
        strFileName = GetUserInput(strPrompt:="What would you like to name the file", _
                                   strTitle:="File Name")

    'Create a FileSystemObject (FSO)
        Set fso = GetFileSystemObject

    'Create a text file
        fso.CreateTextFile strFolderName & "\" & strFileName & ".txt"

    'Create an FSO file for the text file just created
        Set fsoFile = fso.GetFile(strFolderName & "\" & strFileName & ".txt")

    ' Open a TextStream for output.
        Set ts = fsoFile.OpenAsTextStream(gclForWriting, gclTristateUseDefault)

    ' Write to the TextStream
        ts.WriteLine "Jeff Weir"
        ts.WriteLine "is a prolific blogger!"
        ts.Close

    'Tidy up
        Set ts = Nothing
        Set fsoFile = Nothing
        Set fso = Nothing

End Sub

Textstream2

Append To A Text File

We don’t always want to create a new text file. Sometimes we want to append to an existing text file. We can use the OpenTextFile Method of the FileSystemObject:

Sub AppendToText()

    'Author     :   Winston Snyder
    'Date       :   2/15/2014
    'Purpose    :   Append to a text file

    'Declare variables
        Dim fso             As Object
        Dim fsoFile         As Object
        Dim ts              As Object
        Dim strFileName     As String

    'Allow the user to choose a file to append to
        strFileName = GetFile()

    'Create a FileSystemObject (FSO)
        Set fso = GetFileSystemObject

    'Create an FSO file for the text file just created
        Set fsoFile = fso.GetFile(strFileName)

    ' Open a TextStream for output.
        Set ts = fsoFile.OpenAsTextStream(gclForAppending, gclTristateUseDefault)

    ' Write to the TextStream
        ts.WriteLine
        ts.WriteLine "Mike Alexander is a handsome devil!"
        ts.Close

    'Tidy up
        Set ts = Nothing
        Set fsoFile = Nothing
        Set fso = Nothing

End Sub

At the GetFile() Dialog prompt, I chose the file I created in the “CreateTextFile Method”. I then used the constant, “gclForAppending” to specify that the new content was to be appended to the existing file. Had I used the constant, “gclForWriting”, the original contents would have been overwritten.

TextFileAppend2

The Functions

Here are the Functions() I used with the code snippets above

FileDialogFolderPicker

Public Function GetFolder() As String
 
    Dim fd As FileDialog
    Dim strFolderName As String
    Set fd = Application.FileDialog(msoFileDialogFolderPicker)
     
    With fd
        .Title = "Please select a folder"
        .AllowMultiSelect = False
        .Show
        strFolderName = .SelectedItems(1)
    End With
 
    GetFolder = strFolderName
     
    Set fd = Nothing
End Function

GetFileSystemObject

Public Function GetFileSystemObject() As Object
     
    On Error Resume Next
    Set GetFileSystemObject = CreateObject("Scripting.FileSystemObject")
     
End Function

GetUserInput

Public Function GetUserInput(strPrompt As String, _
                             strTitle As String) As String
     
    Dim strUserInput As String
     
    strUserInput = InputBox(Prompt:=strPrompt, _
                            Title:=strTitle)
                             
    GetUserInput = strUserInput
 
End Function

FileDialogFilePicker

Public Function GetFile() As String
 
    Dim fd As FileDialog
    Dim strFileName As String
    Set fd = Application.FileDialog(msoFileDialogFilePicker)
     
    With fd
        .Title = "Please select a file"
        .AllowMultiSelect = False
        .Show
        strFileName = .SelectedItems(1)
    End With
 
    GetFile = strFileName
     
    Set fd = Nothing
End Function

The sample Procedures() given are fine for learning and understanding how to create text files and how to write and append data to the files. But how can we leverage these in a business environment to solve business needs and goals?

Merge Text Files

We may have a series of text files that we wish to merge into 1. Back in November, 2013, Ken Puls showed us how to use Power Query to import multiple text files into a Data Model (Power Pivot). All well and good. Let’s see if we can merge text files using the TextStream Object.

Here are some .csv files that I would like to merge together:

TextFilesForMerge

Sub MergeTextFiles()
    
    'Author     :   Winston Snyder
    'Date       :   2/15/2014
    'Purpose    :   Merge text files in a folder
    
    'Declare variables
        Dim fso                             As Object
        Dim fsoFolder                       As Object
        Dim fsoFileOutput                   As Object
        Dim fsoFile                         As Object
        Dim tsOutput                        As Object
        Dim tsInput                         As Object
        Dim strFolderInputFiles             As String
        Dim strFolderOutputFiles            As String
        Dim strFileName                     As String
        Dim strMisc                         As String

    'Allow the user to choose a folder that contains files to be merged
        strFolderInputFiles = GetFolder(strTitle:="Folder for files to be merged")
        
    'Allow the user to choose a folder location for the output file
        strFolderOutputFiles = GetFolder(strTitle:="Folder for output files")

    'What to name the output file
        strFileName = GetUserInput(strPrompt:="What would you like to name the file", _
                                   strTitle:="File Name")

    'Create a FileSystemObject (FSO)
        Set fso = GetFileSystemObject
        
    'Get an FSO folder for the input files
        Set fsoFolder = fso.GetFolder(strFolderInputFiles)
        
    'Create a text file for output
        fso.CreateTextFile strFolderOutputFiles & "\" & strFileName & ".txt"
        
    'Create an FSO file for the text file just created
        Set fsoFileOutput = fso.GetFile(strFolderOutputFiles & "\" & strFileName & ".txt")

    'Open a TextStream for output.
        Set tsOutput = fsoFileOutput.OpenAsTextStream(gclForAppending, gclTristateUseDefault)
        
    'Loop through the files in the input folder
        For Each fsoFile In fsoFolder.Files
            Set tsInput = fsoFile.OpenAsTextStream(gclForReading, gclTristateUseDefault)
            Do Until tsInput.AtEndOfStream
                strMisc = tsInput.ReadLine                  'Read from the input file
                tsOutput.WriteLine strMisc                  'Write to the output file
            Loop
        Next fsoFile
        
    'Tidy up
        Set tsInput = Nothing
        Set tsOutput = Nothing
        Set fsoFolder = Nothing
        Set fso = Nothing

End Sub

Here is the merged file.

MergedFilesMultipleHeaders

Pretty good, except the headers are repeating. I want to revise the code a bit to only include the header from the first file and skip the header on the subsequent files. The revised code:

Sub MergeTextFilesFirstFileHeader()
    
    'Author     :   Winston Snyder
    'Date       :   2/15/2014
    'Purpose    :   Merge text files in a folder
    'Comments   :   Only uses header row from the first file
    '               subsequent files, header row is skipped
    
    'Declare variables
        Dim fso                             As Object
        Dim fsoFolder                       As Object
        Dim fsoFileOutput                   As Object
        Dim fsoFile                         As Object
        Dim tsOutput                        As Object
        Dim tsInput                         As Object
        Dim strFolderInputFiles             As String
        Dim strFolderOutputFiles            As String
        Dim strFileName                     As String
        Dim strMisc                         As String
        Dim blnTest                         As Boolean
        
    'Initialize variables
        blnTest = True                                          'First time through loop

    'Allow the user to choose a folder that contains files to be merged
        strFolderInputFiles = GetFolder(strTitle:="Folder for files to be merged")
        
    'Allow the user to choose a folder location for the output file
        strFolderOutputFiles = GetFolder(strTitle:="Folder for output files")

    'What to name the output file
        strFileName = GetUserInput(strPrompt:="What would you like to name the file", _
                                   strTitle:="File Name")

    'Create a FileSystemObject (FSO)
        Set fso = GetFileSystemObject
        
    'Get an FSO folder for the input files
        Set fsoFolder = fso.GetFolder(strFolderInputFiles)
        
    'Create a text file for output
        fso.CreateTextFile strFolderOutputFiles & "\" & strFileName & ".txt"
        
    'Create an FSO file for the text file just created
        Set fsoFileOutput = fso.GetFile(strFolderOutputFiles & "\" & strFileName & ".txt")

    'Open a TextStream for output.
        Set tsOutput = fsoFileOutput.OpenAsTextStream(gclForAppending, gclTristateUseDefault)
        
    'Loop through the files in the input folder
        For Each fsoFile In fsoFolder.Files
            Set tsInput = fsoFile.OpenAsTextStream(gclForReading, gclTristateUseDefault)
            If blnTest = True Then
                blnTest = False
            Else
                tsInput.SkipLine                            'Move the file pointer to the line below the header
            End If
            Do Until tsInput.AtEndOfStream
                strMisc = tsInput.ReadLine                  'Read from the input file
                tsOutput.WriteLine strMisc                  'Write to the output file
            Loop
        Next fsoFile
        
    'Tidy up
        Set tsInput = Nothing
        Set tsOutput = Nothing
        Set fsoFolder = Nothing
        Set fso = Nothing

End Sub

MergedFilesOneHeader

Awesome! The solution was to use the SkipLine Method of the TextStream Object everytime through the loop other than the first time:

If blnTest = True Then
   blnTest = False
Else
   tsInput.SkipLine                        'Move the file pointer to the line below the header
End If

Read From Text File

Another common problem, is to read the contents of a text file into Excel. I’ll demonstrate some code to take care of this using comma separated values (csv), but you can use any kind of delimiter such as tab, space, pipe “|”, etc….

Sub ReadTextFileIntoExcel()
    
    'Author     :   Winston Snyder
    'Date       :   2/15/2014
    'Purpose    :   Read data from text file, output to Excel
    
    'Declare variables
        Dim fso                         As Object
        Dim fsoFile                     As Object
        Dim ts                          As Object
        
        Dim vArrData()                  As Variant
        Dim strLine()                   As String
        Dim strData()                   As String
        
        Dim i                           As Long
        Dim j                           As Long
        
        Dim strTextFileName             As String
        Dim strFolderOutputFiles        As String
        Dim strExcelFileName            As String
        Dim strReadAll                  As String
        
    'User - choose a text file to read into Excel
        strTextFileName = GetFile()
        
    'User - choose a folder location for the output file
        strFolderOutputFiles = GetFolder(strTitle:="Folder for output files")

    'User - name the output file
        strExcelFileName = GetUserInput(strPrompt:="What would you like to name the file", _
                                        strTitle:="File Name")

    'Create a FileSystemObject (FSO)
        Set fso = GetFileSystemObject
        
    'Create an FSO file for the user selected text file
        Set fsoFile = fso.GetFile(strTextFileName)

    'Open a TextStream for reading
        Set ts = fsoFile.OpenAsTextStream(gclForReading, gclTristateUseDefault)
        
    'Read the text file and store it in a string variable
        strReadAll = ts.ReadAll
    
    'Split each line of the text document based on the new line delimiter
        strLine = Split(strReadAll, vbNewLine)
        
    'Get number of elements in the line
        strData = Split(strLine(0), ",")
        
    'Redim the data array
        ReDim vArrData(LBound(strData) To UBound(strData), LBound(strLine) To UBound(strLine))
        
    'Erase the strData Array
        Erase strData
        
    'Loop the strLine Array, split each line into data elements, load the data elements into the data array
        For i = LBound(strLine) To UBound(strLine)
            strData = Split(strLine(i), ",")
            For j = LBound(strData) To UBound(strData)
                vArrData(j, i) = strData(j)
            Next j
        Next i

    'Output the array to an Excel Worksheet
        Call ArrayToRange(vArr:=vArrData, _
                          strPath:=strFolderOutputFiles, _
                          strFileName:=strExcelFileName)
        
    'Tidy up
        'Erase arrays
            Erase vArrData
            Erase strLine
            Erase strData
            
        'Destroy objects
            Set ts = Nothing
            Set fsoFile = Nothing
            Set fso = Nothing

End Sub

'----------------------------------------------------------------------------------------

Public Sub ArrayToRange(ByRef vArr() As Variant, _
                        strPath As String, _
                        strFileName As String)
                        
    Dim wbNew As Workbook
    Dim wsNew As Worksheet
    Dim rngNew As Range
    Dim r As Long
    Dim c As Long
    
    c = UBound(vArr, 1)                                     '1st dimension of array
    r = UBound(vArr, 2)                                     '2nd dimension of array
    
    Set wbNew = Workbooks.Add
    Set wsNew = wbNew.Worksheets("Sheet1")
    Set rngNew = wsNew.Range("A1")

    'Resize the destination range
    'Use +1, +1 for Rows and columns since array begins at (0,0)
        rngNew.Resize(r + 1, c + 1).Value = Application.Transpose(vArr)
    
    wbNew.SaveAs strPath & "\" & strFileName & ".xlsx"
    wbNew.Close
    
    Set rngNew = Nothing
    Set wsNew = Nothing
    Set wbNew = Nothing
    
End Sub

TextToExcelFinal

Tidy Up

That’s it for today. Long post, sorry ’bout that. That last snjppet ended up being about Arrays as much as it was about the TextStream Object. Now, where did I leave my worms? I’m going fishing.

Download the file from SkyDrive

Previous Posts At dataprose.org – Scripting

  1. The FileSystemObject
  2. Regular Expressions

Microsoft Scripting

  1. Microsoft Scripting Center
  2. FileSystemObject Reference (Windows Scripting)
  3. TextStream Object
  4. 4 Guys From Rolla – FSO

Additional Resources – Arrays

  1. VBA Arrays And Worksheet Ranges
  2. Understanding Arrays
  3. Redim Statement
, , , ,

PTFlash4

In my last post, I showed how to hide the Field Captions of a Pivot Table by changing the font color to match the Interior ColorIndex of the Range. Shane replied on one of the LinkedIn Groups and recommended using the Custom Number Format, “;;;” instead. Let’s give it a try:

PTFieldCaptions1

Select the 3 cells that you want to remove the Captions. Click on the first cell, hold down the Ctrl key and click the other 2 cells:

PTSelectFieldCaptions

Click [Ctrl]+[1] on the keyboard to invoke the Format Cells Dialog.

FormatCellsDialog

Click on “Custom” in the Category Pane

FCD_CustomArrow

In the Type: InputBox, enter 3 semicolons, “;;;” and click, “OK”

FCD_CustomInputF

Field Captions are gone!!

FieldCaptionsManual

VBA

What we do manually, we should try to do with VBA. What if we have many PivotTables on many Worksheets? VBA to the rescue (Assume I restored the Captions so I don’t have to post another screen shot )

Sub PTHideFieldCaptionsCustomNumberFormat()

    'Declare variables
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim pt As PivotTable
        Dim rng As Range
        
    'Excel environment - speed things up
        Application.ScreenUpdating = False

    'Initialize variables
        Set wb = ThisWorkbook

    'Loop all PivotTables in all worksheets in the workbook
    'Set the Number Format of Field Captions so they will not display
        For Each ws In wb.Worksheets
            For Each pt In ws.PivotTables
                Set rng = pt.ColumnRange

                'Set the Number Format of the Field Captions to that nothing is displayed
                    Call SetRangeNumberFormat(rng:=rng)
    
            Next pt
        Next ws

    'Tidy up
        'Destroy objects
            Set rng = Nothing
            Set wb = Nothing

        'Restore Excel environment
            Application.ScreenUpdating = True

End Sub

'--------------------------------------------------------------------
Private Sub SetRangeNumberFormat(rng As Range)
                            
    Dim rngRow As Range
    Dim rngColumn As Range
    Dim rngBig As Range
    Const strNumberFormat As String = ";;;"

    Set rngRow = rng.Offset(1, -1).Resize(rng.Rows.Count - 1, 1)
    Set rngColumn = rng.Offset(0, -1).Resize(1, 2)
    Set rngBig = Union(rngRow, rngColumn)
    
    rngBig.NumberFormat = strNumberFormat
    
    Set rngBig = Nothing
    Set rngColumn = Nothing
    Set rngRow = Nothing

End Sub

FieldCaptionsVBA

Great tip, Shane – thanks!

Other PivotTable Posts At dataprose.org

  1. PivotTable Hide Field Captions – Change Font Color Option
  2. PivotTable Hide Field Captions
  3. PivotTable Conditional Formatting
  4. PivotTable Cell Borders

Additional Resources – PivotTables

  1. Contextures
  2. Peltier Technical Services, Inc.
  3. Chandoo

Additional Resources – Custom Number Formats

  1. A comprehensive guide to Number Formats in Excel – Jon von der Heyden
, ,

PivotTableFlash3

In my last PivotTable post, I showed how to hide PivotTable Field Captions. However, that hides the Filter Arrows as well.

PTNoFieldCaptions

What if you want to hide the Field Captions, but display the filter arrows?

PTArrowsNoLabels

I change the font color of the Field Captions to match the Range Interior ColorIndex

Sub PTFieldCaptionsChangeFontColor()

    'Declare variables
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim pt As PivotTable
        Dim pf As PivotField
        Dim rng As Range
        Dim lngRangeColor As Long

    'Excel environment - speed things up
        Application.ScreenUpdating = False

    'Initialize variables
        Set wb = ThisWorkbook

    'Loop all PivotTables in all worksheets in the workbook
    'Set Font Color of Field Captions to same color as Cell Interior ColorIndex
        For Each ws In wb.Worksheets
            For Each pt In ws.PivotTables
                
                'Get the interior fill color of the Column Range of the Pivot Table
                    Set rng = pt.ColumnRange
                    lngRangeColor = GetRangeColor(rng:=rng)
                    
                'Set the Font Color of the Field Captions to the same color as the Range Interior Color
                    Call ChangeFontColor(rng:=rng, _
                                         lngColor:=lngRangeColor)
    
            Next pt
        Next ws

    'Tidy up
        'Destroy objects
            Set rng = Nothing
            Set wb = Nothing

        'Restore Excel environment
            Application.ScreenUpdating = True

End Sub
'-----------------------------------------------------------------
Private Function GetRangeColor(rng As Range) As Long

    Dim lngColor As Long
    lngColor = rng.Interior.ColorIndex
    GetRangeColor = lngColor
    
End Function
'-----------------------------------------------------------------
Private Sub ChangeFontColor(rng As Range, _
                            lngColor As Long)
                            
    Dim rngRow As Range
    Dim rngColumn As Range
    Dim rngBig As Range

    Set rngRow = rng.Offset(1, -1).Resize(rng.Rows.Count - 1, 1)
    Set rngColumn = rng.Resize(rng.Rows.Count - 1, 1)
    Set rngBig = Union(rngRow, rngColumn)
    
    rngBig.Font.Color = lngColor
    
    Set rngBig = Nothing
    Set rngColumn = Nothing
    Set rngRow = Nothing

End Sub

PTFieldCaptionsInvisible

Other PivotTable Posts At dataprose.org

  1. PivotTable Hide Field Captions
  2. PivotTable Conditional Formatting
  3. PivotTable Cell Borders

Additional Resources

  1. Contextures
  2. Peltier Technical Services, Inc.
  3. Chandoo
, ,

PivotFlashRoman2

I don’t like PivotTable Field Captions

PTwFieldCaptions

You may turn them off manually:

  1. Click on a PivotTable
  2. The PivotTable Tools Tab is activated slightly above the Ribbon
  3. Click on the tab, “Analyze”
  4. In the PivotTable Group, click on the Options drop-down
  5. Click on options
  6. In the PivotTable Options Dialog, click on the Display tab
  7. Clear the tick mark on, “Display field captions and filter drop downs”

PTOptionsDialogFinal

But what if you have many PivotTables, or what if sometimes you want the Field Captions on and sometimes off? Let’s look at some VBA:

Option Explicit

Sub PTDisplayFieldCptions()

    'Declare variables
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim pt As PivotTable
    
    'Excel environment - speed things up
        Application.ScreenUpdating = False
        
    'Initialize variables
        Set wb = ThisWorkbook
        
    'Loop all PivotTables in all worksheets in the workbook
    'Turn off Field Captions
        For Each ws In wb.Worksheets
            For Each pt In ws.PivotTables
                pt.DisplayFieldCaptions = False
            Next pt
        Next ws
        
    'Tidy up
        'Destroy objects
            Set wb = Nothing
            
        'Restore Excel environment
            Application.ScreenUpdating = True
   
End Sub

Or, maybe you would like to toggle the display so if off, tune on and vice versa:

Option Explicit

Sub PTDisplayFieldCptionsToggle()

    'Declare variables
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim pt As PivotTable
    
    'Excel environment - speed things up
        Application.ScreenUpdating = False
        
    'Initialize variables
        Set wb = ThisWorkbook
        
    'Loop all PivotTables in all worksheets in the workbook
    'Turn off Field Captions
        For Each ws In wb.Worksheets
            For Each pt In ws.PivotTables
                If pt.DisplayFieldCaptions = False Then
                    pt.DisplayFieldCaptions = True
                Else
                    pt.DisplayFieldCaptions = False
                End If
            Next pt
        Next ws
        
    'Tidy up
        'Destroy objects
            Set wb = Nothing
            
        'Restore Excel environment
            Application.ScreenUpdating = True

End Sub

PTwFieldCaptionsOff

No more Field Captions

Other PivotTable Posts At dataprose.org

  1. PivotTable Conditional Formatting
  2. PivotTable Cell Borders

Additional Resources

  1. Contextures
  2. Peltier Technical Services, Inc.
  3. Chandoo
, ,

PivotFlashRoman1v2

I wanted to loop through a large workbook with lots of PivotTables to set a common conditional format on the DataBodyRange of each PivotTable.

Here’s my initial PivotTable with no conditional formatting:

PivotTableBigNCF

I would like change the text to red for any value that is less than 0.97 :

Option Explicit

Sub PTConditionalFormatting()

    'Declare variables
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim pt As PivotTable
        Dim rng As Range
        Dim dblLow As Double
        Dim dblHigh As Double
    
    'Excel environment - speed things up
        Application.ScreenUpdating = False
        
    'Initialize variables
        Set wb = ThisWorkbook
        dblLow = 0
        dblHigh = 0.97
        
    'Loop all PivotTables in all worksheets in the workbook
    'Set conditional formatting
        For Each ws In wb.Worksheets
            For Each pt In ws.PivotTables
                Set rng = pt.DataBodyRange
                Call FormatRange(rng:=rng, _
                                 dblValueHigh:=dblHigh, _
                                 dblValueLow:=dblLow)
            Next pt
        Next ws
        
    'Tidy up
        'Destroy objects
            Set wb = Nothing
            
        'Restore Excel environment
            Application.ScreenUpdating = True    
End Sub
'----------------------------------------------------------------------------
Private Sub FormatRange(rng As Range, _
                        dblValueHigh As Double, _
                        dblValueLow As Double)

    With rng
        .FormatConditions.Delete
        .FormatConditions.Add(Type:=xlCellValue, _
                              Operator:=xlBetween, _
                              Formula1:=dblValueHigh, _
                              Formula2:=dblValueLow).Font.Color = vbRed

    End With
End Sub

PTwCF

Very helpful if you have a lot of PivotTables to loop through. The Sub() takes a Range Object as one of the arguments. This means you could use it and pass it any Range Object – not just from PivotTables – Worksheet Range, ListObject Range, other PivotTable Range.

Additional PivotTable Resources

  1. Contextures
  2. Peltier Technical Services, Inc.
  3. Chandoo
, , ,

BeatlesLg
I like music – lots of different kinds of music, including The Beatles pictured here. These days, I’m more into “Adult Alternative” music, but I still like to listen to some stuff from the ’60’s and ’70’s every now and again.

Around these parts, we get “Breakfast With The Beatles” with Andre Gardner every Sunday from 7am-9am. Check your local listings to see if it is available in your area or you can stream it on KSLX. Really excellent show if you are into The Beatles.

However, today’s post is not about music or The Beatles. It is about Merging Excel Workbooks. Over on the LinkedIn Excel Groups there are many questions about merging data from several Excel Workbooks into 1 Workbook. Many folks suggest linking the workbooks using a formula. Others suggest using the INDIRECT() function. I prefer to use some VBA to copy the desired data from the Source Workbooks to the Destination Workbook.

All testing, screen shots, code in this post are from Office 365. If you are using another version of Excel, your results may vary (though they should not).

Linking Files

A common way to get data from one file to another is to link them. In this sample, I opened 2 Excel files, entered a value in 1 file, activated another file, typed, “=” and clicked on a cell in the 1st file:

LinkFiles2

DestinationWB.xlsx in the active workbook and cell $A$1 is selected. The formula bar give us:

  1. [SourceWB.xlsx] <- The name of the workbook
  2. Sheet1! <- The name of the worksheet
  3. $A$1 <- The cell reference

When I close the source workbook, the file path is added to the linked cell formula:

LinkedCellwPath

The folder location ‘C:\Data\ has been added to the linked formula.

There are a few things I do not like about linked cells

  1. The absolute references were added automatically. If I drag the formula to the right, the formula will still reference $A$1, not $B$1 as we may require
  2. What happens if a Row is added at Row 1 pushing all subsequent rows down by 1? This could cause an error in the linked formula, erroneous results, or at least the need for additional maintenance.
  3. What happens if the source file(s) are moved from the referenced folder location?

Here is the formula with the file in the folder ‘C:\OriginalFolder\.

PathReference

Linking Files – File Migration

One problem with linking files is that files move in our directory structures from time-to-time. We may initiate this move ourselves as we come up with a new way to organize our file structures. Other times this move may be initiated by the IT Department as they are updating or migrating storage.

Let’s see what happens to the original link formula when I move the source file.
I moved the file from ‘C:\OriginalFolder\ to ‘C:\NewFolder\ in Windows Explorer.

MoveFileFinal

Now when I try to update the link value in the Destination Workbook, I receive an error message

EditLinksErrorFinal

I can click on the change source button, but I would like a solution that provides for as little maintenance needs as possible.

Linking Files – Data Moves On Worksheet

The original linked formula is linked to cell A1 in the source file. What happens if, unbeknownst to you, a user inserts a blank row at A1 and all of the data shifts from A1 to A2?

UpdateValueFinal

The Edit Links Dialog status reads, “OK”, but it is not. The Linked Cell formula is still linked to Cell $A$1 and the updated Cell Value is now 0. We could use Find-Replace to update from $1 to $2, but that could have unintended consequences. What if other workbook moved data 2-3 rows? You see the point I’m sure.

Copy Data From Source To Destination

I propose to loop through a folder and copy some data from a worksheet for each workbook found in the folder – I would like the solution to be as dynamic as possible. As I am looping, I will paste the data on a worksheet in Top-Down fashion such that the first file results will be near the top, then the data from the second file and so on.

For today, my source files all have an Excel Table in them, though we could make the process work with Ranges as well with just a bit more work. For additional resources working with Excel Tables, see the links at the bottom of the post.

Some Functions & Properties

First, I’ll look at some VBA functions that I am going to use in the final code. These functions will make your code more dynamic and user-friendly.

CurDir

CurDir returns the current path. I use CurDir to trap the current path so I can restore it at then before I change the path to make navigating the file structure faster. Use as follows:

Option Explicit

Sub foo2()

    Dim strDirectory As String
    strDirectory = CurDir()
    Debug.Print strDirectory
    
End Sub

Output:

C:\Users\wsnyder\Documents

ChDir

ChDir changes the the current path. I use ChDir to change the current path to get the user closer the final folder they will eventually choose using the FileDialog to select a folder for processing. Use as follows:

Option Explicit

Sub foo2()

    Dim strDirectory As String
    strDirectory = "C:\Data\"
    ChDir (strDirectory)
    Debug.Print CurDir()
    
End Sub

Output:

C:\Data

FileDialog Property

The FileDialog Property of the Application Object returns a FileDialog Object. This give you the ability to interact with users at runtime by allowing the user to choose File(s) or Folder(s) to work with. The FileDialog accepts one argument, the DialogType.

There are 4 DialogTypes in the MsoFileDialogType Enumeration :

  1. msoFileDialogFilePicker
  2. msoFileDialogFolderPicker
  3. msoFileDialogOpen
  4. msoFileDialogSaveAs

For today’s purposes, I’ll use msoFileDialogFolderPicker

Set diaFolder = Application.FileDialog(msoFileDialogFolderPicker)

The Setup…

As I mentioned earlier, each source file has an Excel Table in it. I would like to loop through each file in the source folder and copy the DataBodyRange of the Excel Table to the destination workbook. Additionally, on the first pass, I would also like to copy the HeaderRowRange to create headers in the destination workbook. Lastly, I would like to add some data to the right of the data from the source files, such as the date the data was copied and the name of the source file.

Create Some Sample Data and Files

I quickly whipped up some sample data using Dick’s Random Data Generator and creatively saved the files as File1.xlsx, File2.xlsx, File3.xlsx.

TablesLayered

Again, I highlighted the data [Ctrl] + [a] and added an Excel Table [Ctrl] + [t] in each file. I applied a different Table Style to each Table simply to highlight the fact that there are 3 different Tables in 3 different Excel files. If you need to brush up on Excel Tables or need to start at the beginning:

  1. Excel Table Tutorial – Contextures
  2. Sur la Excel Table
  3. Listing Toward ListObjects

Loop Through Files In A Folder

When I need to loop through files in a folder – I use the FileSystemObject (FSO). The FileSystemObject is a top-level object in the Microsoft Scriping Runtime Library (Scrrun.dll). Here are some additional references if you need to brush up or are not familiar with FSO.

  1. JP Software Tech
  2. Chip Pearson
  3. 4 Guys From Rolla
  4. dataprose.org
  5. MSDN

edit: I am going to use Late Binding in the sample snippets below. A discussion on Late / Early Binding is beyond the scope of this post. Please see the “Additional Resources” at bottom for links to detailed explanation of Late / Early Binding.

Copying Data From Source To Destination

It’s finally time to copy the data from the source workbooks to the destination workbook. I’m using three files with 50 records each, but you could use this code with an unlimited number of records or variable number of records and unlimited number of files (3, 10, 50,…) – as long as you do not exceed 1,048,576 rows (though I would never use that many row in Excel – time to consider a database).

Option Explicit

Sub CopyDataFromSourceFiles()
    
    'Author         :           Winston Snyder
    'Created Date   :           1/26/2014
    'Comments       :           Assumes each source file contains at least one list object (Excel Table)
    
    'Delare variables
        Dim wb                  As Workbook
        Dim wbData              As Workbook
        Dim ws                  As Worksheet
        Dim wsData              As Worksheet
        Dim rngData             As Range
        Dim rngDestination      As Range
        Dim lo                  As ListObject
        Dim fso                 As Object
        Dim fsoFolder           As Object
        Dim fsoFile             As Object
        Dim strSelectedFolder   As String
        Dim strCurrentPath      As String
        Const strSpecifiedPath  As String = "C:\"
        Dim lngRows             As Long
        Dim blnFlag             As Boolean
        
    'Excel environment - speed things up
        With Application
            .ScreenUpdating = False
            .DisplayAlerts = False
            .EnableEvents = False
            .Calculation = xlCalculationManual
        End With
        
    'Initialize variables
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets("Data")
        blnFlag = True
        
    'Clear data from control workbook from previous consolidations
        ws.UsedRange.ClearContents
    
    'Get the current path, so reset the path at the end of the procedure
        strCurrentPath = CurDir()
        
    'Set the target directory to get the user closer to the working folder
    'This will minimize the time the user must spend drilling into the file system
    'once they are presented with the FileDialog
        ChDir (strSpecifiedPath)
    
    'Create a FileSystemObject
        Set fso = GetFSO

    'Prompt the user to select a folder
    'Return the path of the selected folder
        strSelectedFolder = GetSelectedFolder
        
    'Get the FSO Folder of the selected folder
        Set fsoFolder = fso.GetFolder(strSelectedFolder)
        
    'Loop each file in folder
    'Copy data from each file to control workbook
        For Each fsoFile In fsoFolder.Files
            Debug.Print fsoFile.Name
            Set wbData = Workbooks.Open(fsoFile)
            Set wsData = wbData.Worksheets("Sheet1")
            
            'Get next blank row from destination worksheet
            'If first time, need row 1, else, next blank row
                lngRows = GetRows(ws:=ws)
                If blnFlag = False Then lngRows = lngRows + 1
                
            'The Destination Range
                Set rngDestination = ws.Cells(lngRows, 1)
            
            'If first time, include the header row
                With wsData
                    For Each lo In .ListObjects
                        If blnFlag = True Then
                            Set rngData = Union(lo.HeaderRowRange, lo.DataBodyRange)
                            blnFlag = False
                        Else
                            Set rngData = lo.DataBodyRange
                        End If
                    Next lo
                End With
                
            'Copy the Data Range to the Destination Range
                rngData.Copy
                rngDestination.PasteSpecial xlPasteValuesAndNumberFormats
                
            'Close the source file
                wbData.Close
        
        Next fsoFile
        
    'Tidy up
        'Restore to original path
            ChDir (strCurrentPath)
            
        'Restore Excel environment
            With Application
                .ScreenUpdating = True
                .DisplayAlerts = True
                .EnableEvents = True
                .Calculation = xlCalculationAutomatic
            End With
            
        'Destroy objects
            Set fsoFolder = Nothing
            Set fso = Nothing
            Set rngData = Nothing
            Set rngDestination = Nothing
            Set ws = Nothing
            Set wb = Nothing
        
End Sub
'------------------------------------------------------------------------------------
Private Function GetRows(ws As Worksheet) As Long

    Dim r       As Long
    
    With ws
        r = .Cells(Rows.Count, 1).End(xlUp).Row
        GetRows = r
    End With
    
End Function
'------------------------------------------------------------------------------------
Private Function GetFSO()

    Dim fso             As Object
    
    Set fso = CreateObject("Scripting.FileSystemObject")
    Set GetFSO = fso
    
    Set fso = Nothing

End Function
'-------------------------------------------------------------------------------
Private Function GetSelectedFolder() As String
    
    Dim diaFolder       As FileDialog
    Dim strFolder       As String

    Set diaFolder = Application.FileDialog(msoFileDialogFolderPicker)
    With diaFolder
        .AllowMultiSelect = False
        .Show
        strFolder = .SelectedItems(1)
    End With

    GetSelectedFolder = strFolder
End Function

MergeSourceFiles

I formatted the output and hid some rows to show that there are 151 records as expected (3 files * 50 records each + 1 header row).

My favorite part of the code is here

'If first time, include the header row
                With wsData
                    For Each lo In .ListObjects
                        If blnFlag = True Then
                            Set rngData = Union(lo.HeaderRowRange, lo.DataBodyRange)
                            blnFlag = False
                        Else
                            Set rngData = lo.DataBodyRange
                        End If
                    Next lo
                End With

The properties of the ListObject (Excel Table) such as HeaderRowRange and DataBodyRange are 2 reasons why the ListObject is far superior to the Range Object. Couple these kinds of properties with the fact that you can move the Excel Table anywhere on the worksheet you want and add rows to the Table or redact rows from the Table and the consolidation code will still work flawlessly. No Excel Hell! Awesome!

Tidy Up

, , , , , , ,

BorderCollie
I’m a dog person. I have a Yellow Lab, but I’ve always wanted a Border Collie. They are amazing “workhorse”, acrobatic and athletic dogs. Maybe someday I’ll have some land and animals so a Border Collie will be more fitting.

In the meantime, today’s post is not about dogs and farm animals – its about Excel PivotTables.

I like Pivot Tables a lot! I always try to use Pivot Tables before another other solution, if possible, for reporting purposes. But Pivot Table formatting options may not cover the entire spectrum of how we would like to format our Pivots.
PT1_Med
For example, I would like to add cell borders to all Data Range and Row Label items, but not Headers and GrandTotals.
PT_wBorderNotes2
I tried some different PivotTable Styles, but none gave me exactly what I was looking for. In this screen shot, for example, I tried adding adding a border to first column.

ColumnStripe1

There are 2 problems with this:

  1. The Header Row and the Grand Total Row also have the Column Border applied
  2. There does not appear to be a way to apply the same format across all columns

Enter PivotTable Ranges and VBA

Excel PivotTables offer various Ranges within the PivotTable. Jon Peltier covers the various Ranges here, so I won’t recover the information. Make sure you check out Jon’s tutorial – excellent!

DataBodyRange

I colored the DataBodyRange in the PivotTable below with a little VBA
DataBodyRangeFinal

Sub HighlightDataBodyRange()
    'Color the DataBodyRange of a PivotTable

    Dim wb         As Workbook
    Dim ws         As Worksheet
    Dim pt         As PivotTable
    Dim rng        As Range
    Dim lngGrey    As Long
    
    Set wb = ThisWorkbook
    Set ws = wb.Worksheets("Sheet1")
    lngGrey = RGB(217, 217, 217)
    
    With ws
        For Each pt In ws.PivotTables
            Set rng = pt.DataBodyRange
            rng.Interior.Color = lngGrey
        Next pt
    End With
    
    Set rng = Nothing
    Set ws = Nothing
    Set wb = Nothing
    
End Sub

Looks pretty good, except:

  1. The DataBodyRange includes the Grand Total Row
  2. The DataBodyRange does not include the Row Labels

RowRange

I colored the RowRange in the PivotTable below with a little VBA
RowRangeFinal

Sub HighlightRowRange()
    'Color the RowRange of a PivotTable

    Dim wb          As Workbook
    Dim ws          As Worksheet
    Dim pt          As PivotTable
    Dim rng         As Range
    Dim lngGrey     As Long
    
    Set wb = ThisWorkbook
    Set ws = wb.Worksheets("Sheet1")
    lngGrey = RGB(217, 217, 217)
    
    With ws
        For Each pt In ws.PivotTables
            Set rng = pt.RowRange
            rng.Interior.Color = lngGrey
        Next pt
    End With
    
    Set rng = Nothing
    Set ws = Nothing
    Set wb = Nothing
    
End Sub

Looks pretty good, except:

  1. The RowRange includes the Grand Total Row
  2. The RowRange includes the Header Row
  3. The RowRange does not include the DataBodyRange identified previously

I have an understanding of a couple of ranges and their shapes. Now I need to reshape the ranges and merge them together.

Resize A Range

RangeReshape

The heavy dashed line in the screen shot shows what the final shape of each range should be if the VBA code works correctly. I filled the resized Ranges with new colors to show that they have been properly resized.

RangesResizedColored

Here’s the Function I came up with for resizing the Ranges. I don’t like it very much, but it works. I think there should be an enumeration for the Range Types of the Excel PivotTable. Maybe there is and I’m not aware of it.

Private Function GetResizedRange(rng As Range, _
                                 strType As String) As Range

    Dim r           As Long
    Dim c           As Long
    
    With rng
        r = .Rows.Count
        c = .Columns.Count
    End With
    
    Select Case strType
        Case "RowRange"
           Set rng = rng.Offset(1).Resize(r - 2, c)
        Case "DataBodyRange"
            Set rng = rng.Resize(r - 1, c)
    End Select
    
    Set GetResizedRange = rng
    Set rng = Nothing

End Function

Borders

FinalCellBorders
The cell borders look great and the original stated objectives have been achieved. I added the cell borders with this sub:

Private Sub AddBorders(rng As Range)

    Dim lngGrey          As Long
    lngGrey = RGB(217, 217, 217)
    
    With rng.Borders
        .LineStyle = xlContinuous
        .Color = lngGrey
    End With

End Sub

The Complete Code

Here’s the complete code so you can copy pate it in one swoop if you so desire:

Option Explicit
Sub AddCellBordersToPivot()
    'Color the DataBodyRange of a PivotTable

    Dim wb              As Workbook
    Dim ws              As Worksheet
    Dim pt              As PivotTable
    Dim rngType         As Range
    Dim rngRow          As Range
    Dim rngData         As Range
    Dim strRangeType    As String
    
    Set wb = ThisWorkbook
    Set ws = wb.Worksheets("Sheet1")
    
    With ws
        For Each pt In ws.PivotTables
            'RowRange
                Set rngType = pt.RowRange
                strRangeType = "RowRange"
                Set rngRow = GetResizedRange(rng:=rngType, _
                                             strType:=strRangeType)
                
            'DataBodyRange
                Set rngType = pt.DataBodyRange
                strRangeType = "DataBodyRange"
                Set rngData = GetResizedRange(rng:=rngType, _
                                              strType:=strRangeType)
                                             
            'Add borders
                Call AddBorders(rng:=rngRow)
                Call AddBorders(rng:=rngData)
                
        Next pt
    End With
    
    Set rngType = Nothing
    Set rngRow = Nothing
    Set rngData = Nothing
    Set ws = Nothing
    Set wb = Nothing
    
End Sub

Private Sub AddBorders(rng As Range)

    Dim lngGrey          As Long
    lngGrey = RGB(217, 217, 217)
    
    With rng.Borders
        .LineStyle = xlContinuous
        .Color = lngGrey
    End With

End Sub

Private Function GetResizedRange(rng As Range, _
                                 strType As String) As Range

    Dim r           As Long
    Dim c           As Long
    
    With rng
        r = .Rows.Count
        c = .Columns.Count
    End With
    
    Select Case strType
        Case "RowRange"
           Set rng = rng.Offset(1).Resize(r - 2, c)
        Case "DataBodyRange"
            Set rng = rng.Resize(r - 1, c)
    End Select
    
    Set GetResizedRange = rng
    Set rng = Nothing

End Function

Tidy Up

    Final Thoughts

    That’s it for today. I’m a little surprised there is not an easier way to refer to the Ranges I had to reshape here. I think users would like to apply formats separate from Header Rows and Grand Total Rows. How do you handle these issues? Do you know of a way to achieve this formatting using PivotTable Styles that I was not able to find? Where’d I put the dog’s leash? Time for a walk.

    Downloads

    Download the file from SkyDrive. The file name is PivotTable_CellBorders.xlsm

, ,