+ Reply to Thread
Results 1 to 2 of 2

Get cell value from another workbook

Hybrid View

  1. #1
    Forum Contributor
    Join Date
    07-14-2019
    Location
    Dubai
    MS-Off Ver
    2019
    Posts
    927

    Get cell value from another workbook

    Hi

    I want msgbox cell value from another workbook located in desktop, sheet1, range name Text
    How can I do that within VBA without opening the second workbook
    No need query table, only VBA

    Thanks

  2. #2
    Administrator 6StringJazzer's Avatar
    Join Date
    01-27-2010
    Location
    Tysons Corner, VA, USA
    MS-Off Ver
    MS 365 Family 64-bit 2502
    Posts
    27,163

    Re: Get cell value from another workbook

    VBA does not have a built-in way to reference a closed workbook.

    One way to do this is to use VBA to put a formula in a cell to reference the closed workbook, then reference the resulting value of that cell.
    Public Function DataFromClosedBook(Path As String, FileName As String, SheetName As String, RangeAddress As String)
    
       Dim Ref As String
       Dim Destination As Range
       
       Set Destination = ActiveSheet.Range("A1")  ' modify to suit
       Ref = "='" & Path & "\[" & FileName & "]" & SheetName & "'!" & RangeAddress
       
       Destination.Formula = Ref
       MsgBox Destination
       
    End Function

    Another way is using ADO. I have not tested this using a named range, but you may find it helpful.
    ' http://www.rondebruin.nl/win/s3/win024.htm
    
    Public Sub GetData(SourceFile As Variant, SourceSheet As String, _
                       SourceRange As String, TargetRange As Range, Header As Boolean, UseHeaderRow As Boolean)
    ' 30-Dec-2007, working in Excel 2000-2007
        Dim rsCon As Object
        Dim rsData As Object
        Dim szConnect As String
        Dim szSQL As String
        Dim lCount As Long
    
        ' Create the connection string.
        If Header = False Then
            If Val(Application.Version) < 12 Then
                szConnect = "Provider=Microsoft.Jet.OLEDB.4.0;" & _
                            "Data Source=" & SourceFile & ";" & _
                            "Extended Properties=""Excel 8.0;HDR=No"";"
            Else
                szConnect = "Provider=Microsoft.ACE.OLEDB.12.0;" & _
                            "Data Source=" & SourceFile & ";" & _
                            "Extended Properties=""Excel 12.0;HDR=No"";"
            End If
        Else
            If Val(Application.Version) < 12 Then
                szConnect = "Provider=Microsoft.Jet.OLEDB.4.0;" & _
                            "Data Source=" & SourceFile & ";" & _
                            "Extended Properties=""Excel 8.0;HDR=Yes"";"
            Else
                szConnect = "Provider=Microsoft.ACE.OLEDB.12.0;" & _
                            "Data Source=" & SourceFile & ";" & _
                            "Extended Properties=""Excel 12.0;HDR=Yes"";"
            End If
        End If
    
        If SourceSheet = "" Then
            ' workbook level name
            szSQL = "SELECT * FROM " & SourceRange$ & ";"
        Else
            ' worksheet level name or range
            szSQL = "SELECT * FROM [" & SourceSheet$ & "$" & SourceRange$ & "];"
        End If
    
        On Error GoTo SomethingWrong
    
        Set rsCon = CreateObject("ADODB.Connection")
        Set rsData = CreateObject("ADODB.Recordset")
    
        rsCon.Open szConnect
        rsData.Open szSQL, rsCon, 0, 1, 1
    
        ' Check to make sure we received data and copy the data
        If Not rsData.EOF Then
    
            If Header = False Then
                TargetRange.Cells(1, 1).CopyFromRecordset rsData
            Else
                'Add the header cell in each column if the last argument is True
                If UseHeaderRow Then
                    For lCount = 0 To rsData.Fields.Count - 1
                        TargetRange.Cells(1, 1 + lCount).Value = _
                        rsData.Fields(lCount).Name
                    Next lCount
                    TargetRange.Cells(2, 1).CopyFromRecordset rsData
                Else
                    TargetRange.Cells(1, 1).CopyFromRecordset rsData
                End If
            End If
    
        Else
            MsgBox "No records returned from : " & SourceFile, vbCritical
        End If
    
        ' Clean up our Recordset object.
        rsData.Close
        Set rsData = Nothing
        rsCon.Close
        Set rsCon = Nothing
        Exit Sub
    
    SomethingWrong:
        MsgBox "The file name, Sheet name or Range is invalid of : " & SourceFile, _
               vbExclamation, "Error"
        On Error GoTo 0
    
    End Sub
    Jeff
    | | |會 |會 |會 |會 | |:| | |會 |會
    Read the rules
    Use code tags to [code]enclose your code![/code]

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Return cell formula of another workbook based on cell values in current workbook
    By Fullalove in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 07-25-2021, 06:31 PM
  2. [SOLVED] VBA to check if cell A1 in workbook 1 equals cell A1 in workbook 2
    By Rerock in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 09-19-2014, 01:06 PM
  3. [SOLVED] Code to cut cell from one workbook, close same workbook, and paste in different workbook
    By kosherboy in forum Excel Programming / VBA / Macros
    Replies: 30
    Last Post: 03-13-2014, 04:01 PM
  4. Copy cell from one workbook to a specific cell in another workbook
    By omhs.msa in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 12-19-2013, 03:55 PM
  5. Copy Cell From Workbook and Paste to Another Workbook's Cell
    By nih in forum Excel Programming / VBA / Macros
    Replies: 17
    Last Post: 08-12-2009, 12:42 PM
  6. Replies: 3
    Last Post: 08-04-2009, 02:58 PM
  7. Replies: 0
    Last Post: 06-03-2005, 11:05 AM

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1