VBA Help import file data from a specfic tab

AussieVic

Active Member
Joined
Jan 9, 2009
Messages
364
Hi, the below code imports data from the file path "rngOtcRg", how can i add to this so that the code imports from a specific tab, i have named range "rngMonth" where the cell will house the month which will reflect the worksheet which the code needs to find, if worksheet found then import data.

Code:
Sub RG()

Dim strFileName          As String
Dim lstRow               As Long
Dim lstRowSrc            As Range
Dim lstSrcCellRwNum      As Long
Dim shtDst               As Excel.Worksheet
Dim shtSrc               As Excel.Worksheet
Dim wkbThis              As ThisWorkbook
Dim wkbSrc               As Workbook
Dim shtTask              As Excel.Worksheet

  
Set shtTask = ThisWorkbook.Worksheets("Tasks")
 
 Application.ScreenUpdating = False
 
    strFileName = Range("rngOtcRg") & ".xls"

    If Dir(strFileName) = "" Then
            MsgBox prompt:="The File does not exist", _
            Buttons:=vbOKOnly + vbInformation
        GoTo ExitRoutine
      Else
         Set wkbSrc = Workbooks.Open(strFileName)
         Set shtSrc = wkbSrc.Worksheets(1)
         Set wkbThis = ThisWorkbook
         Set shtDst = wkbThis.Sheets("RawData")
    End If
     
    'Copy data from Downloaded data to Raw Worksheet
    With shtSrc
        Set lstRowSrc = .Cells(.Rows.Count, "A").End(xlUp)
                lstSrcCellRwNum = lstRowSrc.Row
         With .Range("A1:M" & lstSrcCellRwNum)
            On Error Resume Next
                Intersect(shtDst.UsedRange, shtDst.Range("A10:M" & Rows.Count)).ClearContents
            On Error GoTo 0
            .Copy shtDst.Range("A1")
            .EntireColumn.AutoFit
         End With
        Application.DisplayAlerts = False
            ActiveWorkbook.Close
        Application.DisplayAlerts = True

End Sub
 

Some videos you may like

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,276
Code:
Sub RG()

Dim strFileName          As String
Dim lstRow               As Long
Dim lstRowSrc            As Range
Dim lstSrcCellRwNum      As Long
Dim shtDst               As Excel.Worksheet
Dim shtSrc               As Excel.Worksheet
Dim wkbThis              As ThisWorkbook
Dim wkbSrc               As Workbook
Dim shtTask              As Excel.Worksheet

  
Set shtTask = ThisWorkbook.Worksheets("Tasks")
 
 Application.ScreenUpdating = False
 
    strFileName = shtTask.Range("rngOtcRg") & ".xls"
    
    ChDir "C:\temp"

    If Dir(strFileName) = "" Then
            MsgBox prompt:="The File does not exist", _
            Buttons:=vbOKOnly + vbInformation
        GoTo ExitRoutine
      Else
         Set wkbSrc = Workbooks.Open(strFileName)
         
         On Error Resume Next   ' Suspend error checking
            Set shtSrc = wkbSrc.Sheets(shtTask.Range("rngMonth").Value)
         On Error GoTo 0        ' Resume error checking
         If shtSrc Is Nothing Then
            MsgBox "Can't locate sheet " & shtTask.Range("rngMonth").Value & " in " & wkbSrc.Name
            GoTo ExitRoutine
         End If
         Set wkbThis = ThisWorkbook
         Set shtDst = wkbThis.Sheets("RawData")
    End If
    
    'Copy data from Downloaded data to Raw Worksheet
    With shtSrc
        Set lstRowSrc = .Cells(.Rows.Count, "A").End(xlUp)
                lstSrcCellRwNum = lstRowSrc.Row
         With .Range("A1:M" & lstSrcCellRwNum)
            On Error Resume Next
                Intersect(shtDst.UsedRange, shtDst.Range("A10:M" & Rows.Count)).ClearContents
            On Error GoTo 0
            .Copy shtDst.Range("A1")
            .EntireColumn.AutoFit
         End With
        Application.DisplayAlerts = False
            ActiveWorkbook.Close
        Application.DisplayAlerts = True
        
    End With
    
ExitRoutine:

End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,108,816
Messages
5,525,061
Members
409,617
Latest member
Lenaf

This Week's Hot Topics

Top