Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 2
Default User Defined Forumla and persistence

Hi,
I have a new problem with Excel... and it appear to me in the world of the
"User Defined Formulas".

If I write a new formula like this (into a VBA module):

Function TEST(RngName As String, Optional FncName As String = "SUM") As
Variant
Application.Volatile

Dim TheCaller As Range
Set TheCaller = Application.Caller

Dim R As Range
Set R = ActiveWorkbook.Names(RngName).RefersToRange

TEST = Application.Evaluate(FncName & "(" & R.Address & ")")
End Function

and I use it in a sheet (e.g. "Sheet 1") it works fine... but when I go to
another sheet (e.g. "Sheet 3") and I forse a recalculus (F9 shortcut) when I
return to "Sheet 1" the function show the 0 (ZERO) value :(

Why? Something idea?

Thanks in adavance



Eros Pedrini


  #2   Report Post  
Posted to microsoft.public.excel.programming
external usenet poster
 
Posts: 968
Default User Defined Forumla and persistence

Hi Eros,

When Application.Evaluate evaluates a string containing a range reference
that is not qualified by a worksheet, it assumes it is on the active sheet.
So when you change sheet you get a different answer.

So you either need to use Worksheet.evaluate (which assumes the unqualified
reference is on Worksheet) or use .address(External:=True) which gives you a
qualified reference.

For more limitations and advice on EVALUATE see
http://www.DecisionModels.com/calcsecretsh.htm


Charles
______________________
Decision Models
FastExcel 2.1 now available
www.DecisionModels.com

"Eros Pedrini" wrote in message
...
Hi,
I have a new problem with Excel... and it appear to me in the world of the
"User Defined Formulas".

If I write a new formula like this (into a VBA module):

Function TEST(RngName As String, Optional FncName As String = "SUM") As
Variant
Application.Volatile

Dim TheCaller As Range
Set TheCaller = Application.Caller

Dim R As Range
Set R = ActiveWorkbook.Names(RngName).RefersToRange

TEST = Application.Evaluate(FncName & "(" & R.Address & ")")
End Function

and I use it in a sheet (e.g. "Sheet 1") it works fine... but when I go to
another sheet (e.g. "Sheet 3") and I forse a recalculus (F9 shortcut) when
I
return to "Sheet 1" the function show the 0 (ZERO) value :(

Why? Something idea?

Thanks in adavance



Eros Pedrini




Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
"User-defined type not defined" message in Excel RW1946 Excel Discussion (Misc queries) 0 August 31st 05 12:14 PM
Workspace faux user-defined type not defined Chris S[_2_] Excel Programming 3 November 11th 04 05:51 PM
User-defined data type; Error: Only User-defined types... tiger_PRM Excel Programming 1 July 18th 04 03:32 PM
User Defined type not defined Karpagam Excel Programming 1 May 16th 04 05:41 PM
Word.Document - user defined type not defined jowatkins[_7_] Excel Programming 0 January 20th 04 08:46 AM


All times are GMT +1. The time now is 01:51 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
Copyright ©2004-2024 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"