Forum Discussion
VBA file selection dialog for query
Hi all
I don't know VBA syntax well and I'm stuck! I recorded the macro below to open data from a text file, but I need to be able to select a different filename every time it runs. How can I add a file selection dialog to the following code that will allow me to select something other than the file 0125-FEA-I-S_reduced_input.txt?
Sub Load_k_file()
'
' Select_k_file Macro
'
'
ActiveWorkbook.Queries.Add Name:="0125-FEA-I-S_reduced_input", Formula:= _
"let" & Chr(13) & "" & Chr(10) & " Source = Csv.Document(File.Contents(""C:\Users\jopot\OneDrive\Documents\Timestep\Resources\IT\Software\LS-Dyna\Methodology investigations\Welds\0125-FEA-I-S\0125-FEA-I-S_reduced_input.txt""),9,"""",ExtraValues.Ignore,437)," & Chr(13) & "" & Chr(10) & " #""Changed Type"" = Table.TransformColumnTypes(Source,{{""Column1"", type text}, {""Column2"", type text}, {""Column3"", type text}" & _
", {""Column4"", type text}, {""Column5"", type text}, {""Column6"", type text}, {""Column7"", type text}, {""Column8"", type text}, {""Column9"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & " #""Changed Type"""
With ActiveSheet.ListObjects.Add(SourceType:=0, Source:= _
"OLEDB;Provider=Microsoft.Mashup.OleDb.1;Data Source=$Workbook$;Location=0125-FEA-I-S_reduced_input;Extended Properties=""""" _
, Destination:=Range("$A$3")).QueryTable
.CommandType = xlCmdSql
.CommandText = Array("SELECT * FROM [0125-FEA-I-S_reduced_input]")
.RowNumbers = False
.FillAdjacentFormulas = False
.PreserveFormatting = True
.RefreshOnFileOpen = False
.BackgroundQuery = True
.RefreshStyle = xlInsertDeleteCells
.SavePassword = False
.SaveData = True
.AdjustColumnWidth = True
.RefreshPeriod = 0
.PreserveColumnInfo = True
.ListObject.DisplayName = "_0125_FEA_I_S_reduced_input"
.Refresh BackgroundQuery:=False
End With
End Sub
Thanks!
JP
2 Replies
Try this:
Sub Load_k_file() Dim sFile As String With Application.FileDialog(1) .Filters.Clear .Filters.Add "Text Files (*.txt)", "*.txt" ' Change as desired .InitialFileName = "C:\Users\jopot\OneDrive\Documents\Timestep\Resources\IT\Software\LS-Dyna\Methodology investigations\Welds\0125-FEA-I-S\*.txt" If .Show Then sFile = .SelectedItems(1) Else Beep Exit Sub End If End With ActiveWorkbook.Queries.Add Name:="0125-FEA-I-S_reduced_input", Formula:= _ "let" & Chr(13) & "" & Chr(10) & " Source = Csv.Document(File.Contents(""" & _ sFile & """),9,"""",ExtraValues.Ignore,437)," & Chr(13) & "" & Chr(10) & " #""Changed Type"" = Table.TransformColumnTypes(Source,{{""Column1"", type text}, {""Column2"", type text}, {""Column3"", type text}" & _ ", {""Column4"", type text}, {""Column5"", type text}, {""Column6"", type text}, {""Column7"", type text}, {""Column8"", type text}, {""Column9"", type text}})" & Chr(13) & "" & Chr(10) & "in" & Chr(13) & "" & Chr(10) & " #""Changed Type""" With ActiveSheet.ListObjects.Add(SourceType:=0, Source:= _ "OLEDB;Provider=Microsoft.Mashup.OleDb.1;Data Source=$Workbook$;Location=0125-FEA-I-S_reduced_input;Extended Properties=""""" _ , Destination:=Range("$A$3")).QueryTable .CommandType = xlCmdSql .CommandText = Array("SELECT * FROM [0125-FEA-I-S_reduced_input]") .RowNumbers = False .FillAdjacentFormulas = False .PreserveFormatting = True .RefreshOnFileOpen = False .BackgroundQuery = True .RefreshStyle = xlInsertDeleteCells .SavePassword = False .SaveData = True .AdjustColumnWidth = True .RefreshPeriod = 0 .PreserveColumnInfo = True .ListObject.DisplayName = "_0125_FEA_I_S_reduced_input" .Refresh BackgroundQuery:=False End With End Sub- JohannesJPCopper Contributor