OzGrid

Excel: Get Data From Closed Excel Workbooks

< Back to Search results

 Category: [Excel]  Demo Available 

Excel: Get Data From Closed Excel Workbooks

 

Got any Excel/VBA Questions? Free Excel Help

Pull in data from a closed Workbook without having to open it:

As you may be aware it's not possible to pull in data from a closed Workbook (without opening it). The code below is a workaround that has served me very well in the past. 

It places an IF formula in the same range as the UsedRange of the closed Workbook (Book1.xls) within the open Workbook (Book2.xls) and pulls in the data from the closed Workbook (Book1.xls). If the cell it is referencing is blank, it puts an #N/A in it's place. I then use the SpecialCells Method to delete all #N/A errors. Last of all it changes all formulas to Values only. 

You first put some simple code in Book1.xls (the closed Workbook) that will give you the exact area Address of the UsedRange on Sheet1. You must place this in the Private Module of ThisWorkbook i.e Workbook_BeforeSave.

Private Sub Workbook_BeforeSave _

               (ByVal SaveAsUI As  Boolean,Cancel As Boolean)

'Put in the UsedRange Address of Sheet1 Book1.xls (this workbook)

	Sheet2.Cells(1, 1) = Sheet1.UsedRange.Address

End Sub

Now in the Workbook you want to pull the data in (Book2.xls), place this code in a Standard Module.


Sub PullInSheet1()

'''''''''''''''''''''''''''''''

'Written By OzGrid Business Applications

'www.ozgrid.com



'Pulls in all data from sheet1 of a closed workbook.

''''''''''''''''''''''''''''''''



Dim AreaAddress As String



'Clear sheet ready for new data

Sheet1.UsedRange.Clear

'Reference the UsedRange Address of Sheet1 _

in the closed Workbook.

	Sheet1.Cells(1, 1) = "= 'C:\My Documents\OzGrid\" _

				& "[Book1.xls]Sheet2'!RC"

	'Pass the area Address to a String

	AreaAddress = Sheet1.Cells(1, 1)

	With Sheet1.Range(AreaAddress)

       		'If the cell in Sheet1 of the closed workbook is not _

		empty the pull in it's content, else put in an Error.

		.FormulaR1C1 = "=IF('C:\My Documents\OzGrid\" _

    		& "[Book1.xls]Sheet1'!RC="""",NA(),'C:\My Documents\" _

		& "OzGrid\[Book1.xls]Sheet1'!RC)"

 		'Delete all Error cells

		On Error Resume Next

		.SpecialCells(xlCellTypeFormulas, xlErrors).Clear

		On Error GoTo 0

		'Change all formulas to Values only

		.Value = .Value

	End With

End Sub

Last of all place this code in the Private Module of ThisWorkbook i.e Workbook_Open


Private Sub Workbook_Open()

Run "PullInSheet1"

End Sub
 

See also:

Excel: Get File Name From User to Open Workbook Or Save Workbook
Excel VBA Runtime Errors & Preventing Them
Sheet/Worksheet CodeNames
Automatically Run Excel Macros via Workbook & Worksheet Events
Excel: Password Protect/Unprotect All Excel Worksheets in One Go
Excluding Headings/Headers From the Current Region/Table
Excel: Get Text From Excel Cell Comments

 

See also Index to Excel VBA Code and Index to Excel Freebies and Lesson 1 - Excel Fundamentals and Index to how to… providing a range of solutions.

 

Click here to visit our Free 24/7 Excel/VBA Help Forum where there are thousands of posts you can get information from, or you can join the Forum and post your own questions.


Gallery



stars (0 Reviews)