XL: ATP Functions Return Error When Created Through AutomationLast reviewed: March 13, 1998Article ID: Q172107 |
The information in this article applies to:
SYMPTOMSWhen you add an Analysis ToolPak function in a cell in a Microsoft Excel spreadsheet, the function returns the #NAME? error.
CAUSEThis problem occurs when the following conditions are true:
When you use Automation to start the versions of Microsoft Excel listed at the beginning of this article, the Analysis ToolPak add-in is not loaded even if you previously loaded it or you loaded it by running a macro.
WORKAROUNDMicrosoft provides examples of Visual Basic for Applications procedures for illustration only, without warranty either expressed or implied, including, but not limited to the implied warranties of merchantability and/or fitness for a particular purpose. The Visual Basic procedures in this article are provided 'as is' and Microsoft does not guarantee that they can be used in all situations. While Microsoft support engineers can help explain the functionality of a particular macro, they will not modify these examples to provide added functionality, nor will they help you construct macros to meet your specific needs. If you have limited programming experience, you may want to consult one of the Microsoft Solution Providers. Solution Providers offer a wide range of fee-based services, including creating custom macros. For more information about Microsoft Solution Providers, call Microsoft Customer Information Service at (800) 426-9400. To work around this problem, load the Analysis ToolPak. To do this, clear the check box for the add-in in the Add-Ins dialog box in Microsoft Excel or use code to unload it, and then use code to reload the add-in. The following example is created in Visual Basic 4.0 and works with both versions of Microsoft Excel listed at the beginning of this article. With very little modification, you can use the code in Microsoft Access 97 and Microsoft Word 97. The sample code creates a Microsoft Excel workbook and places several Analysis ToolPak functions in cells. It does not make any difference whether the Analysis ToolPak is selected in the last session of Microsoft Excel. By using the Installed property of the AddIns class you allow the Analysis ToolPak to be unloaded, and then loaded through code.
Sub Main() ' Declares all the variables to be used. Dim xlApp As Object ' Will be used for the application object. Dim xlWB As Object ' Will be used for the workbook object. Dim xlsheet As Object ' Will be used for the spreadsheet object. ' Starts an instance of Microsoft Excel. Set xlApp = CreateObject("excel.application") ' Makes Microsoft Excel visible. xlApp.Visible = True ' Starts a new workbook. xlApp.workbooks.Add Template:="Workbook" ' Unloads and loads the Analysis Toolpak. xlApp.AddIns("Analysis ToolPak").Installed = False xlApp.AddIns("Analysis ToolPak").Installed = True ' Assigns the variables to their respective objects. Set xlWB = xlApp.ActiveWorkbook Set xlsheet = xlWB.activesheet ' Assigns formulas to cells on the spreadsheet. With xlsheet .Activate .range("A1").Formula = "1/1/97" .range("A2").Formula = "7/14/97" .range("A3").Formula = "=EDATE(R[-2]C,2)" .range("A4").Formula = "=EOMONTH(R[-3]C,3)" .range("A5").Formula = "=NETWORKDAYS(R[-4]C,R[-3]C,2)" End With ' Saves the file. xlApp.ActiveWorkbook.SaveAs filename:="C:\OLEtest.xls" ' Closes Microsoft Excel. xlApp.quit ' Clears the variables Set xlsheet = Nothing Set xlWB = Nothing Set xlApp = Nothing End SubOpen the Oletest.xls file to verify that values in cells A3:A5 are calculated without error.
STATUSMicrosoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article. We are researching this problem and will post new information here in the Microsoft Knowledge Base as it becomes available.
|
Additional query words: XL97 OLE Analysis ToolPak
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |