Extract partial filename and populate in spreadsheet

CBHodgetts

New Member
Joined
Nov 29, 2010
Messages
7
Hi All I have manage to "cobble" some script to import a numner of files into a single consolidate list. In Coulmn A of the file produced, it inserts the full path and filename. Is there a way of only inserting the filename?

Code:

Code:
Private Declare Function SetCurrentDirectoryA Lib _
"kernel32" (ByVal lpPathName As String) As Long
Sub ChDirNet(szPath As String)
SetCurrentDirectoryA szPath
End Sub
 
Sub MergeSpecificWorkbooks2()
Dim MyPath As String
Dim SourceRcount As Long, Fnum As Long
Dim mybook As Workbook, BaseWks As Worksheet
Dim sourceRange As Range, destrange As Range
Dim rnum As Long, CalcMode As Long
Dim SaveDriveDir As String
Dim FName As Variant
 
' Set application properties.
With Application
CalcMode = .Calculation
.Calculation = xlCalculationManual
.ScreenUpdating = False
.EnableEvents = False
End With
SaveDriveDir = CurDir
' Change this to the path\folder location of the files.
ChDirNet "X:\Management Support\ADDO REPORTING PROJECT\ATB\(B) Phase Two Report Tracker & Issues Log"
[I][COLOR="Red"]FName = Application.GetOpenFilename(filefilter:="Excel Files (*.xl*), *.xl*", Title:="Choose Tracker Files", _
MultiSelect:=True)[/COLOR][/I]

If IsArray(FName) Then
' Add a new workbook with one sheet.
Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
rnum = 1
 
' Loop through all files in the myFiles array.
For Fnum = LBound(FName) To UBound(FName)
Set mybook = Nothing
On Error Resume Next
Set mybook = Workbooks.Open(FName(Fnum))
On Error GoTo 0
If Not mybook Is Nothing Then
On Error Resume Next
With mybook.Worksheets(2)
Set sourceRange = .Range("A5:N200")
End With
If Err.Number > 0 Then
Err.Clear
Set sourceRange = Nothing
Else
' If the source range uses all columns then
' skip this file.
If sourceRange.Columns.Count >= BaseWks.Columns.Count Then
Set sourceRange = Nothing
End If
End If
On Error GoTo 0
If Not sourceRange Is Nothing Then
SourceRcount = sourceRange.Rows.Count
If rnum + SourceRcount >= BaseWks.Rows.Count Then
MsgBox "There are not enough rows in the target worksheet."
BaseWks.Columns.AutoFit
mybook.Close savechanges:=False
GoTo ExitTheSub
Else
' Copy the file name in column A.
With sourceRange
[I][COLOR="Red"]BaseWks.Cells(rnum, "A"). _
Resize(.Rows.Count).Value = FName(Fnum)[/COLOR][/I]
End With
' Set the destination range.
Set destrange = BaseWks.Range("B" & rnum)
' Copy the values from the source range
' to the destination range.
With sourceRange
Set destrange = destrange. _
Resize(.Rows.Count, .Columns.Count)
End With
destrange.Value = sourceRange.Value
rnum = rnum + SourceRcount
End If
End If
mybook.Close savechanges:=False
End If
Next Fnum
 
' tidy up data
Cells.EntireColumn.AutoFit
Rows("1:1").Select
Selection.AutoFilter
Selection.AutoFilter Field:=2, Criteria1:="="
Rows("12:12").Select
Range(Selection, Selection.End(xlDown)).Select
Selection.Delete Shift:=xlUp
Selection.AutoFilter Field:=2
Selection.AutoFilter Field:=3, Criteria1:="Drop"
Rows("12:12").Select
Range(Selection, Selection.End(xlDown)).Select
Selection.Delete Shift:=xlUp
Range("B346").Select
Selection.AutoFilter Field:=3
ActiveWindow.SmallScroll Down:=-15
BaseWks.Columns.AutoFit
BaseWks.Rows.AutoFit
End If
ExitTheSub:
' Restore the application properties.
With Application
.ScreenUpdating = True
.EnableEvents = True
.Calculation = CalcMode
End With
ChDirNet SaveDriveDir
End Sub

Many thanks in advance for any assistance, as this is driving me mad...

CBHodgetts
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Search backwards until you find a backslash then select everything after that:-
Code:
BaseWks.Cells(rnum, "A"). _
Code:
[COLOR=black]Resize(.Rows.Count).Value = [/COLOR][COLOR=black][COLOR=red][B]Mid([/B][/COLOR]FName(Fnum)[COLOR=red][B],InStrRev(FName(Fnum),"\")+1)[/B][/COLOR]
[/COLOR]
 
Upvote 0
Ruddles, you are a legend, many many thanks. It worked like a treat.

Would you know how to only display part of the filename, such as droping the file extension?

Kind Regards
CBHodgetts
 
Upvote 0
Yes, using a similar technique but searching for the last dot.

You've already seen how to get rid of the path, although I would usually do it very slightly differently:-
Code:
iSlash=InStrRev(FullFileName,"\")
If iSlash=0 Then [COLOR=green]' in case the path isn't there and it's just the filename[/COLOR]
  ShortFileName=FullFileName
Else
  ShortFileName=Mid(FullFileName,iSlash+1)
Endif

To drop the extension, I'd do this:-
Code:
iDot=InStrRev(ShortFileName,".")
If iDot=0 Then [COLOR=green]' in case the workbook hasn't been saved yet and is just called Book1[/COLOR]
  RootFileName=ShortFileName
  RootFileExt=""
Else 
  RootFileName=Left(ShortFileName,iDot-1)
  RootFileExt=Mid(ShortFileName,iDot+1)
End If

You don't have to test for iSlash being zero if you're 100% certain there will always be a backslash in the string, i.e. that the filename will have a complete path, and you don't need to test for iDot being zero if you're sure the filename will always have a dot in it, like you've loaded it from disk. However if it might possibly be a new workbook then it will be called just Book1 or something without a dot, so you'd have to check.

If you don't check for zeroes and you do one day encounter one, your program will crash, and your aim as a program designer is not to have it crash but to detect these sorts of occurrences and cope with them silently.

Shout if anything's unclear or if you have any further questions.
 
Last edited:
Upvote 0
Sorry mate,

should really learn to read through before i click post, what i meant to say was, where should this go in the current code, and how does it interplay with the dropping of the filepath?

Many thnaks
 
Upvote 0
I merely supplied you with a generic method for stripping off the path and extension but I don't know where it goes! At what point do you want to drop the extension?

Are you saying that, where you originally stored the full path, where I supplied the code for stripping off the path, you want to strip off the extension as well?
 
Upvote 0
Hi Mate thanks for coming back to me,

yes is the simple answer, although i have a feeling it isn't a simple solution lol.

I want to strip the filepath and the file extension before it is added to the consolidated spreadsheet that is created.

Code:
Resize(.Rows.Count).Value = Mid(FName(Fnum),InStrRev(FName(Fnum),"\")+1)

This works perfectly but it still leaves the extension on.

Any ideas?
 
Upvote 0
That line you quoted above, replace it with this:-
Code:
[FONT=Courier New][SIZE=1]Dim iSlash As Integer, iDot As Integer[/SIZE][/FONT]
[SIZE=1][FONT=Courier New]Dim FullFileName As String, ShortFileName As String, PathName As String[/FONT][/SIZE]
[FONT=Courier New][SIZE=1]Dim RootFileName As String, RootFileExt As String[/SIZE][/FONT]
 
[SIZE=1][FONT=Courier New]FullFileName = FName(Fnum)[/FONT][/SIZE]
 
[SIZE=1][FONT=Courier New]iSlash = InStrRev(FullFileName, "\")[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]If iSlash = 0 Then[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]  ShortFileName = FullFileName[/FONT][/SIZE]
[FONT=Courier New][SIZE=1]  PathName = ""[/SIZE][/FONT]
[SIZE=1][FONT=Courier New]Else[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]  ShortFileName = Mid(FullFileName, iSlash + 1)[/FONT][/SIZE]
[FONT=Courier New][SIZE=1]  PathName = Left(FullFileName, iSlash)[/SIZE][/FONT]
[SIZE=1][FONT=Courier New]End If[/FONT][/SIZE]
 
[FONT=Courier New][SIZE=1]iDot = InStrRev(ShortFileName, ".")[/SIZE][/FONT]
[SIZE=1][FONT=Courier New]If iDot = 0 Then[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]  RootFileName = ShortFileName[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]  RootFileExt = ""[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]Else[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]  RootFileName = Left(ShortFileName, iDot - 1)[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]  RootFileExt = Mid(ShortFileName, iDot + 1)[/FONT][/SIZE]
[SIZE=1][FONT=Courier New]End If[/FONT][/SIZE]
 
[FONT=Courier New][SIZE=1][COLOR=green]' by the time you get here, you have the following variables:-[/COLOR][/SIZE][/FONT]
[FONT=Courier New][SIZE=1][COLOR=#008000]'[/COLOR][/SIZE][/FONT]
[FONT=Courier New][SIZE=1][FONT=Courier New][SIZE=1][COLOR=green]'   FullFileName  - the full file name including path and extension, e.g. [/COLOR][COLOR=red]c:\temp\wibble.txt[/COLOR][/SIZE][/FONT]
[FONT=Courier New][SIZE=1][COLOR=green]'   PathName      - the path where the file is located, e.g. [/COLOR][COLOR=red]c:\temp\[/COLOR][/SIZE][/FONT]
[SIZE=1][FONT=Courier New][FONT=Courier New][SIZE=1][COLOR=green]'   ShortFileName - just the file name including extension, e.g. [/COLOR][COLOR=red]wibble.txt[/COLOR][/SIZE][/FONT]
[SIZE=1][FONT=Courier New][FONT=Courier New][SIZE=1][COLOR=green]'   [COLOR=blue]RootFileName[/COLOR]  - the bit of the file name before the dot, e.g. [/COLOR][COLOR=red]wibble[/COLOR][/SIZE][/FONT]
[/FONT][/SIZE][/FONT][/SIZE][/SIZE][/FONT][FONT=Courier New][SIZE=1][COLOR=green][FONT=Courier New][SIZE=1]'   RootFileExt   - the bit of the file name after the dot, e.g. [COLOR=red]txt[/COLOR][/SIZE][/FONT][/COLOR]
 
  BaseWks.Cells(rnum, "A").Resize(.Rows.Count).Value = [COLOR=blue]RootFileName[/COLOR][/SIZE][/FONT]
 
Upvote 0
Hi Ruddles

Sorry for the slow response , been out of the office for a few days.

I tried this and it worked like a dream, thank you very much for all of your help. Your are a legend.

Kind Regards:smile:
CBHodgetts
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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