Home |
Search |
Today's Posts |
|
#1
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
Dear All
I'm afraid I have another question on this highly active topic. I am using some code that I found here on Google Groups, a bit of John Walkenbach's work I think. Any way, the code results in a Browse for folder dialogue box with three buttons... Make New Folder, OK and Cancel. My problem lies with the Cancel button, when pressed the macro hangs, most likely for the following reason... I use the string (folder path) to open three files in that directory. When the macro is debugged and I pause the mouse pointer over the string variable, it shows a row of squares too long to fit in the tool tips box (presumably, the font isn't available to show what it really is). Hence, it is trying to open a non-existent file path. What I would like to do is add a line saying "If (string) = (whatever 'Cancel' returns) Then GoTo Cancelled:" before the string is used. I have tried the following remedies (none of which has worked) - Putting the string in a cell so I can read it (it comes out blank). - Putting If (string) = "" ... - Putting If (string) = Null ... - Etc etc... For full details of the code, just ask (I'd like to resist cluttering up the screen for as long as possible, and I barely understand the code I have copied anyway!) Many thanks Rob |
#2
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
How about something like:
If fileToOpen = "False" Then Exit Sub Mike F "Rob" wrote in message oups.com... Dear All I'm afraid I have another question on this highly active topic. I am using some code that I found here on Google Groups, a bit of John Walkenbach's work I think. Any way, the code results in a Browse for folder dialogue box with three buttons... Make New Folder, OK and Cancel. My problem lies with the Cancel button, when pressed the macro hangs, most likely for the following reason... I use the string (folder path) to open three files in that directory. When the macro is debugged and I pause the mouse pointer over the string variable, it shows a row of squares too long to fit in the tool tips box (presumably, the font isn't available to show what it really is). Hence, it is trying to open a non-existent file path. What I would like to do is add a line saying "If (string) = (whatever 'Cancel' returns) Then GoTo Cancelled:" before the string is used. I have tried the following remedies (none of which has worked) - Putting the string in a cell so I can read it (it comes out blank). - Putting If (string) = "" ... - Putting If (string) = Null ... - Etc etc... For full details of the code, just ask (I'd like to resist cluttering up the screen for as long as possible, and I barely understand the code I have copied anyway!) Many thanks Rob |
#3
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
Hi Mike
Thanks for the suggestion but that doesn't work. I tried it woth out the quotes too and just got a type mismatch error as it's a string not boolean. Here's the code, maybe that'll shed some light. Const BIF_RETURNONLYFSDIRS = 1 Const BIF_NEWDIALOGSTYLE = &H40 Const MAX_PATH = 260 Type BrowseInfo hWndOwner As Long pidlRoot As Long pszDisplayName As Long lpszTitle As String ulFlags As Long lpfn As Long lParam As Long iImage As Integer End Type Declare Function GetActiveWindow Lib "user32" () As Long Declare Function SHBrowseForFolder Lib "shell32" _ (pBrInfo As BrowseInfo) As Long Declare Function SHGetPathFromIDList Lib "shell32" _ (ByVal pidList As Long, _ ByVal lpBuffer As String) As Long Declare Sub CoTaskMemFree Lib "ole32.dll" _ (ByVal pMem As Long) Option Explicit Sub Open_Files() Dim filepath As String filepath = SelectFolder("Please Choose the location of the .txt files") Workbooks.OpenText Filename:= _ filepath + "\file1.txt" _ , Origin:=xlMSDOS, StartRow:=1, DataType:=xlDelimited, TextQualifier:= _ xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, Semicolon:=False, _ Comma:=False, Space:=False, Other:=False, FieldInfo:=Array(1, 1), _ TrailingMinusNumbers:=True 'repeat open for files 2 and 3 End Sub Public Function SelectFolder(sTitle) As String Dim nPos As Long Dim pidList As Long Dim nResult As Long Dim sPath As String Dim pBInfo As BrowseInfo sPath = String(MAX_PATH, Chr(0)) sTitle = sTitle & Chr(0) With pBInfo 'Set the owner window (current active Window) .hWndOwner = GetActiveWindow() .lpszTitle = sTitle .ulFlags = BIF_RETURNONLYFSDIRS + BIF_NEWDIALOGSTYLE End With pidList = SHBrowseForFolder(pBInfo) If pidList < 0 Then SHGetPathFromIDList pidList, sPath CoTaskMemFree pidList nPos = InStr(sPath, Chr(0)) If nPos 0 Then sPath = Left(sPath, nPos - 1) End If End If SelectFolder = sPath End Function Alls you have to do to get this to work is copy the code to a new worksheet/module as normal. Then copy the following into notepad and save it as 'file1.txt', then run the macro and navigate to wherever you saved it. Time Volt drop Battery current 40 0.005 19.8 180 0.002 9.9 Thanks again Rob |
#4
![]()
Posted to microsoft.public.excel.programming
|
|||
|
|||
![]()
Hi Rob,
See codes & examples for browse for folder from Chip Pearson's site. http://www.cpearson.com/excel/BrowseFolder.htm Regards, Shah Shailesh http://members.lycos.co.uk/shahweb/ Excel Add-ins *** Sent via Developersdex http://www.developersdex.com *** |
#5
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
After this line:
filepath = SelectFolder("Please Choose the location of the .txt files") Add this: Dim x As Long Dim sTemp As String For x = 1 To Len(filepath) If Mid$(filepath, x, 1) < Chr$(0) Then sTemp = sTemp & Mid$(filepath, x, 1) End If Next ' let's see what we got: If Len(sTemp) 0 Then Debug.Print sTemp Else Debug.Print "User canceled" exit sub End If ' Then resume with the rest of the code In article .com, Rob wrote: Hi Mike Thanks for the suggestion but that doesn't work. I tried it woth out the quotes too and just got a type mismatch error as it's a string not boolean. Here's the code, maybe that'll shed some light. Const BIF_RETURNONLYFSDIRS = 1 Const BIF_NEWDIALOGSTYLE = &H40 Const MAX_PATH = 260 Type BrowseInfo hWndOwner As Long pidlRoot As Long pszDisplayName As Long lpszTitle As String ulFlags As Long lpfn As Long lParam As Long iImage As Integer End Type Declare Function GetActiveWindow Lib "user32" () As Long Declare Function SHBrowseForFolder Lib "shell32" _ (pBrInfo As BrowseInfo) As Long Declare Function SHGetPathFromIDList Lib "shell32" _ (ByVal pidList As Long, _ ByVal lpBuffer As String) As Long Declare Sub CoTaskMemFree Lib "ole32.dll" _ (ByVal pMem As Long) Option Explicit Sub Open_Files() Dim filepath As String filepath = SelectFolder("Please Choose the location of the .txt files") Workbooks.OpenText Filename:= _ filepath + "\file1.txt" _ , Origin:=xlMSDOS, StartRow:=1, DataType:=xlDelimited, TextQualifier:= _ xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, Semicolon:=False, _ Comma:=False, Space:=False, Other:=False, FieldInfo:=Array(1, 1), _ TrailingMinusNumbers:=True 'repeat open for files 2 and 3 End Sub Public Function SelectFolder(sTitle) As String Dim nPos As Long Dim pidList As Long Dim nResult As Long Dim sPath As String Dim pBInfo As BrowseInfo sPath = String(MAX_PATH, Chr(0)) sTitle = sTitle & Chr(0) With pBInfo 'Set the owner window (current active Window) .hWndOwner = GetActiveWindow() .lpszTitle = sTitle .ulFlags = BIF_RETURNONLYFSDIRS + BIF_NEWDIALOGSTYLE End With pidList = SHBrowseForFolder(pBInfo) If pidList < 0 Then SHGetPathFromIDList pidList, sPath CoTaskMemFree pidList nPos = InStr(sPath, Chr(0)) If nPos 0 Then sPath = Left(sPath, nPos - 1) End If End If SelectFolder = sPath End Function Alls you have to do to get this to work is copy the code to a new worksheet/module as normal. Then copy the following into notepad and save it as 'file1.txt', then run the macro and navigate to wherever you saved it. Time Volt drop Battery current 40 0.005 19.8 180 0.002 9.9 Thanks again Rob -- Steve Rindsberg, PPT MVP PPT FAQ: www.pptfaq.com PPTools: www.pptools.com ================================================ |
#6
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
Thanks Steve, it worked! Pressing cancel now exits the sub (actually,
I have used a Msgbox to give the user the option to repeat or exit). However, still being quite green in VBA, I have no idea HOW this works. As far as I can tell the for/next loop goes through all the characters in "filepath" and adds each valid character to the end of "sTemp" (which starts empty), i.e. if there are no valid characters, the output is empty or "". It then looks at the length of sTemp and if zero, takes that as a 'cancel'. Is that right? Also some other things that I don't understand, why are there $ signs after some of the functions? And what does Debug.Print do? I am running Office 2003 (Excel Version 11.6355.6360 SP1) if that helps. Sorry to reward your efforts with another question, but I have built the majority of my macro using codes from Google Groups, I want to make sure I'm understanding it all. Thanks again Rob PS For those (like me) who don't know what any of the commands do, type them in VBA, highlight and press F1, it should help to make the code clearer. |
#7
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
In article .com, Rob wrote:
Thanks Steve, it worked! Pressing cancel now exits the sub (actually, I have used a Msgbox to give the user the option to repeat or exit). However, still being quite green in VBA, I have no idea HOW this works. As far as I can tell the for/next loop goes through all the characters in "filepath" and adds each valid character to the end of "sTemp" (which starts empty), i.e. if there are no valid characters, the output is empty or "". It then looks at the length of sTemp and if zero, takes that as a 'cancel'. Is that right? Got it in one, sir. And if you dig further into the code that calls the browse dialog, you'll see why this is necessary: it starts with a fixed length string padded with nulls (necessary for the api call, as I understand it) so a string full of nulls is what you get back when the user cancels. I'm betting that somewhere else in the code this originally came from there's some sort of "StripNulls" function or subroutine that got left out. Also some other things that I don't understand, why are there $ signs after some of the functions? Left, Mid, Right return Variants (that happen to contain strings) Left$, Mid$, Right$ return Strings We want a string here, so why muddy the water with more complex data types that eat more memory? And what does Debug.Print do? I am running Office 2003 (Excel Version 11.6355.6360 SP1) if that helps. While in the IDE, press Ctrl+G then run the code. Debug.Print puts messages in the Immediate window but never shows them to the user. Very handy. Sorry to reward your efforts with another question, but I have built the majority of my macro using codes from Google Groups, I want to make sure I'm understanding it all. No problem. I'm no whiz at this by a long shot, but most of what I know has been absorbed here and in other groups like it. The wealth of knowledge and the willingness to share it is astonishing. Still, if you intend to take this very far, it'd be wise to find a book on VB that suits your taste and get a handle on the fundamentals. PS For those (like me) who don't know what any of the commands do, type them in VBA, highlight and press F1, it should help to make the code clearer. And if the Help in these products were up to the standards set in, say, VB5 and Office 97, you could actually learn to code this way. ;-) -- Steve Rindsberg, PPT MVP PPT FAQ: www.pptfaq.com PPTools: www.pptools.com ================================================ |
#8
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
Steve Rindsberg wrote:
After this line: filepath = SelectFolder("Please Choose the location of the .txt files") Add this: Dim x As Long Dim sTemp As String For x = 1 To Len(filepath) If Mid$(filepath, x, 1) < Chr$(0) Then sTemp = sTemp & Mid$(filepath, x, 1) End If Next I'd suggest, instead, that the original SelectFolder function be corrected, so this isn't necessary... pidList = SHBrowseForFolder(pBInfo) If pidList < 0 Then SHGetPathFromIDList pidList, sPath CoTaskMemFree pidList nPos = InStr(sPath, Chr(0)) If nPos 0 Then sPath = Left(sPath, nPos - 1) End If End If SelectFolder = sPath There already is TrimNull functionality there, but it only happens *if* the function succeeds. If the user cancels, or the function fails for any other reason, the full buffer of vbNullChar's is returned. This could be easily fixed by altering that algorithm like this: pidList = SHBrowseForFolder(pBInfo) If pidList Then SHGetPathFromIDList pidList, sPath CoTaskMemFree pidList nPos = InStr(sPath, Chr(0)) If nPos 0 Then sPath = Left(sPath, nPos - 1) End If Else sPath = "" End If SelectFolder = sPath ' let's see what we got: If Len(sTemp) 0 Then Debug.Print sTemp Else Debug.Print "User canceled" exit sub End If ' Then resume with the rest of the code Still need that, either way. Later... Karl -- Working Without a .NET? http://classicvb.org/petition |
#9
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
Hey Rob?
VB Lesson One: Listen to this Peterson guy. In article , Karl E. Peterson wrote: Steve Rindsberg wrote: After this line: filepath = SelectFolder("Please Choose the location of the .txt files") Add this: Dim x As Long Dim sTemp As String For x = 1 To Len(filepath) If Mid$(filepath, x, 1) < Chr$(0) Then sTemp = sTemp & Mid$(filepath, x, 1) End If Next I'd suggest, instead, that the original SelectFolder function be corrected, so this isn't necessary... pidList = SHBrowseForFolder(pBInfo) If pidList < 0 Then SHGetPathFromIDList pidList, sPath CoTaskMemFree pidList nPos = InStr(sPath, Chr(0)) If nPos 0 Then sPath = Left(sPath, nPos - 1) End If End If SelectFolder = sPath There already is TrimNull functionality there, but it only happens *if* the function succeeds. If the user cancels, or the function fails for any other reason, the full buffer of vbNullChar's is returned. This could be easily fixed by altering that algorithm like this: pidList = SHBrowseForFolder(pBInfo) If pidList Then SHGetPathFromIDList pidList, sPath CoTaskMemFree pidList nPos = InStr(sPath, Chr(0)) If nPos 0 Then sPath = Left(sPath, nPos - 1) End If Else sPath = "" End If SelectFolder = sPath ' let's see what we got: If Len(sTemp) 0 Then Debug.Print sTemp Else Debug.Print "User canceled" exit sub End If ' Then resume with the rest of the code Still need that, either way. Later... Karl -- Steve Rindsberg, PPT MVP PPT FAQ: www.pptfaq.com PPTools: www.pptools.com ================================================ |
#10
![]()
Posted to microsoft.public.excel.programming,microsoft.public.office.developer.vba
|
|||
|
|||
![]()
Hi Rob,
Which version of Office are you using? If XP or later, you can use the FileDialog object to browse for a folder. -- Regards Jonathan West - Word MVP www.intelligentdocuments.co.uk Please reply to the newsgroup Keep your VBA code safe, sign the ClassicVB petition www.classicvb.org "Rob" wrote in message oups.com... Dear All I'm afraid I have another question on this highly active topic. I am using some code that I found here on Google Groups, a bit of John Walkenbach's work I think. Any way, the code results in a Browse for folder dialogue box with three buttons... Make New Folder, OK and Cancel. My problem lies with the Cancel button, when pressed the macro hangs, most likely for the following reason... I use the string (folder path) to open three files in that directory. When the macro is debugged and I pause the mouse pointer over the string variable, it shows a row of squares too long to fit in the tool tips box (presumably, the font isn't available to show what it really is). Hence, it is trying to open a non-existent file path. What I would like to do is add a line saying "If (string) = (whatever 'Cancel' returns) Then GoTo Cancelled:" before the string is used. I have tried the following remedies (none of which has worked) - Putting the string in a cell so I can read it (it comes out blank). - Putting If (string) = "" ... - Putting If (string) = Null ... - Etc etc... For full details of the code, just ask (I'd like to resist cluttering up the screen for as long as possible, and I barely understand the code I have copied anyway!) Many thanks Rob |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Browse button on form for folder path | Excel Discussion (Misc queries) | |||
Browse for folder - Jim Rech's | Excel Programming | |||
Jim Rech's Browse for Folder | Excel Programming | |||
Browse for folder | Excel Programming | |||
Browse For Folder start directory | Excel Programming |