updating formulas that use user-defined functions

Thanks Thanks:  0
Likes Likes:  0
Results 1 to 4 of 4

Thread: updating formulas that use user-defined functions

  1. #1
    Board Regular
    Join Date
    Apr 2002
    Location
    Connecticut, USA
    Posts
    62
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

     
    I've defined a function as follows:

    Function IsDataPoint(CellValue) As Boolean

    If IsNumeric(CellValue) Then
    IsDataPoint = True
    ElseIf CellValue = "contact vendor" Then
    IsDataPoint = False
    ElseIf CellValue = "no quote, too thick" Then
    IsDataPoint = False
    Else
    IsDataPoint = False
    End If

    End Function

    I wrote the function in order to provide a flexible test for whether a certain value is a valid data point. At this time, we do not consider a value of "contact vendor" to be a valid data point, but at some time, we might. So I figured I would just use this function instead of the built-in isnumber function, and change the statements in the isdatapoint function according to whatever our latest definition of "data point" is.

    But, Excel doesn't update the value returned by IsDataPoint when I change the code for the function -- unless I enter the formula window again and hit return. I've tried saving, closing and re-opening; there seems to be no easy automatic updating of the formula to reflect the new definition of the function.

    Is there a workaround?

    Thanks,
    Rob

  2. #2
    Board Regular Jaafar Tribak's Avatar
    Join Date
    Dec 2002
    Location
    Larache--Morocco
    Posts
    6,248
    Post Thanks / Like
    Mentioned
    1 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hi Trf,

    For a Function's result to be updated,the worksheet or workbook needs to Calculaute.
    This can be achieved if a formula is calculated anywhere in the worksheet or by pressing F9.

    In fact this applies to Excel Built-in Functions as well.

    Hope this helps.
    Jaafar.

  3. #3
    MrExcel MVP
    Moderator
    Andrew Poulsom's Avatar
    Join Date
    Jul 2002
    Posts
    73,092
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Try putting:

    Application.Volatile True

    as the first line in your function.

    Normally a UDF is recalculated only when any of its arguments are modified. The above code causes the function to be recalculated whenever any cell is changed.

    as an aside, to force a recalculation even if nothing has changed use Ctrl+Alt+F9.

  4. #4
    Board Regular
    Join Date
    Apr 2002
    Location
    Connecticut, USA
    Posts
    62
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

      
    Thanks Andrew and Rafaaj! Both solutions work perfectly.

    I thought I'd tried recalculating, but I guess not, because that worked.

    Rob

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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

 

 
DMCA.com