XL: TREND Function Works Differently in Functions Than in Macros

ID: Q171719

The information in this article applies to:

SUMMARY

When you use the Microsoft Excel TREND function in a Sub procedure in a Microsoft Visual Basic for Applications macro, the function behaves differently than when you use it in a custom function.

This article explains how to use the TREND function in a Visual Basic

Sub procedure.

MORE INFORMATION

Microsoft provides programming examples 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. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

   http://www.microsoft.com/support/supportnet/refguide/

You can use the TREND function in a custom function like you do in a spreadsheet. For example, the following function works correctly when called by a formula in a worksheet:

   Function NewTrend(KnownYs, NewXs)

      NewTrend = Application.Trend(KnownYs, , NewXs, True)

   End Function

However, if this function is called by a subroutine in a module, one of the following error messages appears.

Microsoft Excel 97

   Unable to get the Trend property of the WorksheetFunction class

Microsoft Excel 5.0 and 7.0, Microsoft Excel 98

   Type mismatch

When you use similar code in the Sub procedure, these error messages also appear. For example, the error messages appear when you run the following code in a Sub procedure:

   Sub TrendError()
      MsgBox Application.Trend(Worksheets(1).Range("A1:D1").Value, , _
         5, True)
   End Sub

Using the TREND Function in a Sub Procedure

The methods in this article for using a TREND function in a Sub procedure require that the argument for new x's be passed as a Single or a Double data type. Note that the TREND function also returns an array and that it is necessary to pull the desired element to view the result of the function.

Microsoft Excel 97:

The following sample macro uses a TREND function in a Sub procedure in Microsoft Excel 97:

   Sub GoodTrend()

      Dim NewXs as Single
      NewXs = 5
      Result = Application.WorksheetFunction.Trend( _
         Worksheets(1).Range("A1:D1").Value, , NewXs, True)
      MsgBox Result(1)

   End Sub

Microsoft Excel 5.0 and 7.0 and Microsoft Excel 98:

The following sample macro uses a TREND function in a Sub procedure in Microsoft Excel 5.0, 7.0, and 98:

   Sub GoodTrend()

      Dim NewXs as Single
      NewXs = 5
      Result = Application.Trend(Worksheets(1).Range("A1:D1").Value, _
         , NewXs, True)
      MsgBox Result(1)

   End Sub

NOTE: This macro works with horizontal or vertical ranges.

Additional query words: XL97 XL98 XL7 XL5

Keywords          : kbprg kbdta kbdtacode xlformula KbVBA 
Version           : MACINTOSH:5.0,98; WINDOWS:7.0,97,5.0
Platform          : MACINTOSH WINDOWS
Issue type        : kbinfo

Last Reviewed: May 18, 1999