[VBA] Check column if empty, fill in filename for multiple files

stupideye

New Member
Joined
Aug 6, 2019
Messages
14
Hello,

Looking for some help on a seemingly simple issue. I have some VBA code here that I've scrounged up from searching for a solution to my problem, but I've hit a wall with the final bit.

I'm trying to have this do:
1. Look in a folder
2. In each Excel file in the folder, open them, insert a empty column A
3. In every row that isn't blank in column B, put the filename in column A
4. The filename of these files is for example "Sales January 1, 2020", I'm looking to only keep the date part of it.. I know how to do that with a formula, but not in VBA

The following code does everything except for 3 and 4. Any advice on this one?

Thank you in advance!

VBA Code:
Sub FillDate()
    Dim MyPath As String, FilesInPath As String
    Dim MyFiles() As String, Fnum As Long
    Dim mybook As Workbook
    Dim CalcMode As Long
    Dim sh As Worksheet
    Dim ErrorYes As Boolean


    'Fill in the path\folder where the files are
    MyPath = "E:\Path1\2020\Path2\Database\Path3\"

    'Add a slash at the end if the user forget it
    If Right(MyPath, 1) <> "\" Then
        MyPath = MyPath & "\"
    End If

    'If there are no Excel files in the folder exit the sub
    FilesInPath = Dir(MyPath & "*.xl*")
    If FilesInPath = "" Then
        MsgBox "No files found"
        Exit Sub
    End If

    'Fill the array(myFiles)with the list of Excel files in the folder
    Fnum = 0
    Do While FilesInPath <> ""
        Fnum = Fnum + 1
        ReDim Preserve MyFiles(1 To Fnum)
        MyFiles(Fnum) = FilesInPath
        FilesInPath = Dir()
    Loop

    'Change ScreenUpdating, Calculation and EnableEvents
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    'Loop through all files in the array(myFiles)
    If Fnum > 0 Then
        For Fnum = LBound(MyFiles) To UBound(MyFiles)
            Set mybook = Nothing
            On Error Resume Next
            Set mybook = Workbooks.Open(MyPath & MyFiles(Fnum))
            On Error GoTo 0

            If Not mybook Is Nothing Then


                'Change cell value(s) in one worksheet in mybook
                On Error Resume Next
                With mybook.Worksheets(1)
                    If .ProtectContents = False Then
                    'Insert new column
                        Columns("A:A").Insert Shift:=xlToRight, _
                        CopyOrigin:=xlFormatFromLeftOrAbove             
                    Else
                        ErrorYes = True
                      
                    End If
                End With


                If Err.Number > 0 Then
                    ErrorYes = True
                    Err.Clear
                    'Close mybook without saving
                    mybook.Close savechanges:=False
                Else
                    'Save and close mybook
                    mybook.Close savechanges:=True
                End If
                On Error GoTo 0
            Else
                'Not possible to open the workbook
                ErrorYes = True
            End If

        Next Fnum
    End If

    If ErrorYes = True Then
        MsgBox "There are problems in one or more files, possible problem:" _
             & vbNewLine & "protected workbook/sheet or a sheet/range that not exist"
    End If

    'Restore ScreenUpdating, Calculation and EnableEvents
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = CalcMode
    End With
End Sub

What it should do (if the filename was "Sales January 1, 2020.xls")(italic text is what the VBA would fill in):

Col ACol BCol C
January 1, 20201234$10
January 1, 2020567$12

 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
in each excel file:
- is it always the first sheet/only sheet?
- would you rather instead of creating a new column it just replace blanks?
 
Upvote 0
in each excel file:
- is it always the first sheet/only sheet?
- would you rather instead of creating a new column it just replace blanks?
Always the first and only sheet. They're always called "Main File". They're all formatted the same way.
No - basically I'm making a file that has a full year of these, and I want column A to record the date the file was generated (which is always in the file name).
 
Upvote 0
okay and lastly do you want the date formatted in the way you have in your example? January 1,2020
is it always 1 word before the date? any patterns with the file name helps as dates are the devil.
 
Upvote 0
okay and lastly do you want the date formatted in the way you have in your example? January 1,2020
is it always 1 word before the date? any patterns with the file name helps as dates are the devil.
Doesn't matter too much but sure!
Yes, always 1 word and always the same word "Sales ".
 
Upvote 0
okay add these variables at the top

VBA Code:
Dim theDATE As String, lastRow As Long
Dim i As Long

below the line Set mybook = Workbooks.Open
add

VBA Code:
'extracts the date text from the file name
theDATE = CreateObject("Scripting.FileSystemObject").GetBaseName(mybook.Name)
theDATE = Format(Trim(Mid(theDATE, InStr(theDATE, " ") + 1)), "[$-en-US]mmmm d, yyyy;@")

'checks column B for blanks and writes them to column A
With mybook.Sheets(1)

'inserts column into workbook
.Columns("A:A").Insert Shift:=xlToRight, CopyOrigin:=xlFormatFromLeftOrAbove

    lastRow = .UsedRange.Rows.Count
    For i = 1 To lastRow
        If IsEmpty(.Range("B" & i)) Then
        .Range("A" & i).Value = theDATE
        .Range("A" & i).NumberFormat = "[$-en-US]mmmm d, yyyy;@"
        End If
    Next i
End With
 
Upvote 0
test on a copy of your workbooks/excel files
wouldnt want this affecting your data
 
Upvote 0
Hey, thanks for that. Not sure if I'm missing something here but it's not quite working. It successfully creates a new column A, but that's it, it's empty. Here's where I'm at, any ideas?

VBA Code:
Sub FillDate()
    Dim MyPath As String, FilesInPath As String
    Dim MyFiles() As String, Fnum As Long
    Dim mybook As Workbook
    Dim CalcMode As Long
    Dim sh As Worksheet
    Dim ErrorYes As Boolean
    Dim theDATE As String, lastRow As Long
    Dim i As Long

    'Fill in the path\folder where the files are
    MyPath = "E:\Path1\2020\Path2\Database\Path3\"

    'Add a slash at the end if the user forget it
    If Right(MyPath, 1) <> "\" Then
        MyPath = MyPath & "\"
    End If

    'If there are no Excel files in the folder exit the sub
    FilesInPath = Dir(MyPath & "*.xl*")
    If FilesInPath = "" Then
        MsgBox "No files found"
        Exit Sub
    End If

    'Fill the array(myFiles)with the list of Excel files in the folder
    Fnum = 0
    Do While FilesInPath <> ""
        Fnum = Fnum + 1
        ReDim Preserve MyFiles(1 To Fnum)
        MyFiles(Fnum) = FilesInPath
        FilesInPath = Dir()
    Loop

    'Change ScreenUpdating, Calculation and EnableEvents
    With Application
        CalcMode = .Calculation
        .Calculation = xlCalculationManual
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    'Loop through all files in the array(myFiles)
    If Fnum > 0 Then
        For Fnum = LBound(MyFiles) To UBound(MyFiles)
            Set mybook = Nothing
            On Error Resume Next
            Set mybook = Workbooks.Open(MyPath & MyFiles(Fnum))
            
            'extracts the date text from the file name
    theDATE = CreateObject("Scripting.FileSystemObject").GetBaseName(mybook.Name)
    theDATE = Format(Trim(Mid(theDATE, InStr(theDATE, " ") + 1)), "[$-en-US]mmmm d, yyyy;@")

'checks column B for blanks and writes them to column A
With mybook.Sheets(1)

'inserts column into workbook
        .Columns("A:A").Insert Shift:=xlToRight, CopyOrigin:=xlFormatFromLeftOrAbove
            lastRow = .UsedRange.Rows.Count
            
    For i = 1 To lastRow
        If IsEmpty(.Range("B" & i)) Then
        .Range("A" & i).Value = theDATE
        .Range("A" & i).NumberFormat = "[$-en-US]mmmm d, yyyy;@"
        End If
    Next i
End With
            
            On Error GoTo 0
            If Not mybook Is Nothing Then


                'Change cell value(s) in one worksheet in mybook
                On Error Resume Next
                With mybook.Worksheets(1)
                    If .ProtectContents = False Then
                    End If
                End With


                If Err.Number > 0 Then
                    ErrorYes = True
                    Err.Clear
                    'Close mybook without saving
                    mybook.Close savechanges:=False
                Else
                    'Save and close mybook
                    mybook.Close savechanges:=True
                End If
                On Error GoTo 0
            Else
                'Not possible to open the workbook
                ErrorYes = True
            End If

        Next Fnum
    End If

    If ErrorYes = True Then
        MsgBox "There are problems in one or more files, possible problem:" _
             & vbNewLine & "protected workbook/sheet or a sheet/range that not exist"
    End If

    'Restore ScreenUpdating, Calculation and EnableEvents
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = CalcMode
    End With
End Sub
 
Upvote 0
what is the value stored in lastRow?

it could also be that cells in B are not truly empty so you could change isempty line to
VBA Code:
If .Range("B" & i).value = "" Then

or

VBA Code:
If Len(.Range("B" & i).value) < 1 Then

or any other instance of checking for blank cells

if those dont work then i need to know lastRow value and theDATE value
 
Upvote 0
what is the value stored in lastRow?

it could also be that cells in B are not truly empty so you could change isempty line to
VBA Code:
If .Range("B" & i).value = "" Then

or

VBA Code:
If Len(.Range("B" & i).value) < 1 Then

or any other instance of checking for blank cells

if those dont work then i need to know lastRow value and theDATE value
DataBlake, you're a legend! The second option you gave works perfectly.

Thank you very much for your help! All the best.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,176
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top