|
Back to: Excel VBA . Got any Excel/VBA Questions? Free Excel Help
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
Excel Dashboard Reports & Excel Dashboard Charts 50% Off Become an ExcelUser Affiliate & Earn Money
Special! Free Choice of Complete Excel Training Course OR Excel Add-ins Collection on all purchases totaling over $64.00. ALL purchases totaling over $150.00 gets you BOTH! Purchases MUST be made via this site. Send payment proof to [email protected] 31 days after purchase date.
Instant Download and Money Back Guarantee on Most Software
Excel Trader Package Technical Analysis in Excel With $139.00 of FREE software!
Microsoft � and Microsoft Excel � are registered trademarks of Microsoft Corporation. OzGrid is in no way associated with Microsoft
Some of our more popular products are below...
Convert Excel Spreadsheets To Webpages | Trading In Excel | Construction Estimators | Finance Templates & Add-ins Bundle | Code-VBA | Smart-VBA | Print-VBA | Excel Data Manipulation & Analysis | Convert MS Office Applications To...... | Analyzer Excel | Downloader Excel
| MSSQL Migration
Toolkit |
Monte Carlo Add-in |
Excel
Costing Templates