Consulting

Results 1 to 5 of 5

Thread: Get data from protected file, changes required in existing code

  1. #1

    Get data from protected file, changes required in existing code

    Hi,

    I Have 25 files saved in a folder. I have one master file where I run a macro to merge data from all those files and collate in my master file.
    I use the below macro which is working perfectly for me
    [vba]'' code taken from http://www.rondebruin.nl/copy3.htm
    '' Modified by Arvind on 09/11/2009

    Sub Basic_Example_1()
    Dim MyPath As String, FilesInPath As String
    Dim MyFiles() 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 FirstCell As String

    'Fill in the path\folder where the files are
    MyPath = "C:\Documents and Settings\MT45\Desktop\Steve Peck Projects\Test files"

    '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

    'Add a new workbook with one sheet
    'Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
    Set BaseWks = ActiveWorkbook.Worksheets("Data")
    rnum = 2

    '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

    On Error Resume Next

    With mybook.Worksheets(2)
    FirstCell = "A2"
    Set sourceRange = .Range(FirstCell & ":" & RDB_Last(3, .Cells))
    'Test if the row of the last cell >= then the row of the FirstCell
    If RDB_Last(1, .Cells) < .Range(FirstCell).Row Then
    Set sourceRange = Nothing
    End If
    End With

    If Err.Number > 0 Then
    Err.Clear
    Set sourceRange = Nothing
    Else
    'if SourceRange use 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 "Sorry there are not enough rows in the sheet"
    BaseWks.Columns.AutoFit
    mybook.Close savechanges:=False
    GoTo ExitTheSub
    Else

    ' 'Copy the file name in column A
    'With sourceRange
    ' BaseWks.Cells(rnum, "A"). _
    ' Resize(.Rows.Count).Value = MyFiles(Fnum)
    'End With

    'Set the destrange
    Set destrange = BaseWks.Range("A" & rnum)

    'we copy the values from the sourceRange to the destrange
    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
    BaseWks.Columns.AutoFit
    End If

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



    Function RDB_Last(choice As Integer, rng As Range)
    'Ron de Bruin, 5 May 2008
    ' 1 = last row
    ' 2 = last column
    ' 3 = last cell
    Dim lrw As Long
    Dim lcol As Integer

    Select Case choice

    Case 1:
    On Error Resume Next
    RDB_Last = rng.Find(What:="*", _
    after:=rng.Cells(1), _
    Lookat:=xlPart, _
    LookIn:=xlFormulas, _
    SearchOrder:=xlByRows, _
    SearchDirection:=xlPrevious, _
    MatchCase:=False).Row
    On Error GoTo 0

    Case 2:
    On Error Resume Next
    RDB_Last = rng.Find(What:="*", _
    after:=rng.Cells(1), _
    Lookat:=xlPart, _
    LookIn:=xlFormulas, _
    SearchOrder:=xlByColumns, _
    SearchDirection:=xlPrevious, _
    MatchCase:=False).Column
    On Error GoTo 0

    Case 3:
    On Error Resume Next
    lrw = rng.Find(What:="*", _
    after:=rng.Cells(1), _
    Lookat:=xlPart, _
    LookIn:=xlFormulas, _
    SearchOrder:=xlByRows, _
    SearchDirection:=xlPrevious, _
    MatchCase:=False).Row
    On Error GoTo 0

    On Error Resume Next
    lcol = rng.Find(What:="*", _
    after:=rng.Cells(1), _
    Lookat:=xlPart, _
    LookIn:=xlFormulas, _
    SearchOrder:=xlByColumns, _
    SearchDirection:=xlPrevious, _
    MatchCase:=False).Column
    On Error GoTo 0

    On Error Resume Next
    RDB_Last = rng.Parent.Cells(lrw, lcol).Address(False, False)
    If Err.Number > 0 Then
    RDB_Last = rng.Cells(1).Address(False, False)
    Err.Clear
    End If
    On Error GoTo 0

    End Select
    End Function[/vba].
    However I have a problem if those 25 files are protected. I do have list of files and their respective password to open those file. Is it possible to give the passwords and file names declared in the code so that when a macro runs it doest not ask for password.

    Regards
    Arvind
    I have also asked the same questio on the below link.
    Cross post : http://www.excelforum.com/excel-prog...ml#post2197038

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Password is a property of the Open method, so just pas it there.

    Hold a list of wokbook names and passwords, and use Find with the workbook name, and get the name offset by one column.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  3. #3

    Hi

    Thanks for your suggesstion.

    I would really appreciate very much if you could help me on this As I am not an expert in VBA, I guess something like the below piece of code can be used, I am not sure how do I add this..
    [vba] On Error Resume Next
    Set wbSource = Workbooks.Open(Filename:=rCell.Value, _
    ReadOnly:=True, _
    Password:=rCell.Offset(, 1).Value)
    If Err.Number > 0 Then
    MsgBox "Wrong pwd supplied for: " & rCell.Value, 0, vbNullString
    Err.Clear
    On Error Goto 0
    Goto NextFile
    End If [/vba]

    Thanks for your help
    Arvind

  4. #4
    VBAX Expert Tinbendr's Avatar
    Joined
    Jun 2005
    Location
    North Central Mississippi (The Pines)
    Posts
    993
    Location
    This now becomes hard coded to the twenty five.

    If it needs to stay dynamic, meaning that more files would be included, but not always used, then it'll get more complicated.

    I only included code up to where the last changes occurs.

    (not tested)

    [vba]
    Sub MergeThe25()
    Dim MyPath As String, FilesInPath As String
    Dim MyFiles(24, 1) 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 FirstCell As String

    'Fill in the path\folder where the files are
    MyPath = "C:\Documents and Settings\MT45\Desktop\Steve Peck Projects\Test files"

    '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
    MyFiles(0, 0) = "Filename1.xls": MyFiles(0, 1) = "Password1"
    MyFiles(1, 0) = "Filename2.xls": MyFiles(1, 1) = "Password2"
    MyFiles(2, 0) = "Filename3.xls": MyFiles(2, 1) = "Password3"
    MyFiles(3, 0) = "Filename4.xls": MyFiles(3, 1) = "Password4"
    'etc.

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

    'Add a new workbook with one sheet
    'Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
    Set BaseWks = ActiveWorkbook.Worksheets("Data")
    rnum = 2

    '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, 0), Password:=MyFiles(Fnum, 1))
    On Error GoTo 0[/vba]

    David


  5. #5
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Quote Originally Posted by aravindhan_3
    Thanks for your suggesstion.

    I would really appreciate very much if you could help me on this As I am not an expert in VBA, I guess something like the below piece of code can be used, I am not sure how do I add this..
    [vba] On Error Resume Next
    Set wbSource = Workbooks.Open(Filename:=rCell.Value, _
    ReadOnly:=True, _
    Password:=rCell.Offset(, 1).Value)
    If Err.Number > 0 Then
    MsgBox "Wrong pwd supplied for: " & rCell.Value, 0, vbNullString
    Err.Clear
    On Error Goto 0
    Goto NextFile
    End If [/vba]

    Thanks for your help
    Arvind
    You need to build a table of workbook names and passwords, on a hidden sheet say, and then lookup the workbook name. Lookup Find in help, it is easy to use.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •