UDF's using other UDF's

M

millsy

Is there any problem with using one UDF within another because I am
having problems:

I am trying to input times as 4 digit integers then use the function
"TimeDiff" to work out the difference between times. Timediff works
fine if used in a spreadsheet cell. I then want to use this function
to work out a relationship between sets of different times. This
function is called "Findcase". Both are listed below. It seems that
the problem lies with the multiple use of TimeDiff within FindCase
because the first calculation WsRs = TimeDiff(Ws, Rs) seems to work but
the others do not. Perhaps it's just a bug in my code that I just
cannot see.

Any ideas?


Function TimeDiff(BeginTime As Integer, EndTime As Integer) As Single

Dim BeginHour As Integer, BeginMinute As Integer
Dim EndHour As Integer, EndMinute As Integer

If EndTime < BeginTime Then EndTime = EndTime + 2400

BeginHour = Int(BeginTime / 100)
BeginMinute = BeginTime - (BeginHour * 100)
BeginTime = (BeginHour * 60) + BeginMinute

EndHour = Int(EndTime / 100)
EndMinute = EndTime - (EndHour * 100)
EndTime = (EndHour * 60) + EndMinute

TimeDiff = (EndTime - BeginTime) / 60

End Function

Function FindCase(Ws As Integer, We As Integer, Rs As Integer, Re As
Integer) As Single
Dim WsRs As Single, RsWe As Single, WsWe As Single, WsRe As Single,
RsWs As Single, WeRe As Single, RsRe As Single

WsRs = TimeDiff(Ws, Rs)
RsWe = TimeDiff(Rs, We)
WsWe = TimeDiff(Ws, We)
WsRe = TimeDiff(Ws, Re)
RsWs = TimeDiff(Rs, Ws)
RsRe = TimeDiff(Rs, Re)

FindCase=0

If WsRs + RsWe = WsWe Then FindCase = FindCase + 1
If RsWs + WsWe + WeRe = RsRe Then FindCase = FindCase + 10
If WsRe + ReWe = WsWe Then FindCase = FindCase + 100
If WsRs + RsRe + ReWe = WsWe Then FindCase = FindCase + 1000

End Function
 
N

Niek Otten

<the first calculation WsRs = TimeDiff(Ws, Rs) seems to work but the others
do not. >

What makes you think so? What does "do not work" mean?

What are the inputs? What results did you expect and what did you get
instead?
 
M

millsy

I know that the first calculation is correct by changing the code s
that I can see its result. One of the inputs I am using is:

Ws = 2300, We=700,Rs=2330, Re=900

If I place a ' in front of all the if statements in the Findcas
function to disable them and change Findcase=0 to Findcase=WsRs I ge
the answer 0.5 which I would expect. If I then change Findcase=WsRs t
Findcase=RsWe I get 16.8333 instead of 7.5. If I then put a ' in fron
of the line WsRs=Timediff(Ws,Rs) I get the correct answer of 7.5 fo
RsWe. The first function call seems to mess up the second an
subsequent ones.

If I use the Timediff function in the spreadsheet I get the correc
answer for RsWe so it is capable of producing the correct answer.

As to the expected output, I would expect Findcase to produce a valu
of 1 using the above inputs
 
N

Niek Otten

If you insert "Option Explicit" in your module you'll find that you use an
undeclared variable ReWe (twice)
Try and see if correcting just that solves your problem

BTW Tools>Options>Edit, check "Require variable declaration" inserts the
"Option Explicit" in you modules automatically, which is strongly
recommended.
 
M

millsy

The change makes no difference other than to highlight the lack of a
declaration. I agree with your advice but I don't see how it was going
to make any difference anyway. Here's the revised code with all
variable declared. I also changed one of the if statements but that
isn't relevant to the error:

Option Explicit


Function TimeDiff(BeginTime As Integer, EndTime As Integer) As Single

Dim BeginHour As Integer, BeginMinute As Integer
Dim EndHour As Integer, EndMinute As Integer

If EndTime < BeginTime Then EndTime = EndTime + 2400

BeginHour = Int(BeginTime / 100)
BeginMinute = BeginTime - (BeginHour * 100)
BeginTime = (BeginHour * 60) + BeginMinute

EndHour = Int(EndTime / 100)
EndMinute = EndTime - (EndHour * 100)
EndTime = (EndHour * 60) + EndMinute

TimeDiff = (EndTime - BeginTime) / 60

End Function



Function FindCase(Ws As Integer, We As Integer, Rs As Integer, Re As
Integer) As Single
Dim WsRs As Single, RsWe As Single, WsWe As Single, WsRe As Single,
RsWs As Single, WeRe As Single, RsRe As Single, ReWe As Single

WsRs = TimeDiff(Ws, Rs)
RsWe = TimeDiff(Rs, We)
WsWe = TimeDiff(Ws, We)
WsRe = TimeDiff(Ws, Re)
RsWs = TimeDiff(Rs, Ws)
RsRe = TimeDiff(Rs, Re)
WeRe = TimeDiff(We, Re)

FindCase = 0

If WsRs + RsWe = WsWe Then FindCase = FindCase + 1
If RsWs + WsWe + WeRe = RsRe Then FindCase = FindCase + 10
If WsRe + ReWe = WsWe Then FindCase = FindCase + 100
If WsRs + RsRe + ReWe = WsWe Then FindCase = FindCase + 1000

End Function
 
N

Niek Otten

You are changing input parameters in Timediff, like BeginTime. If you add a
watch for Ws in FindCase, you can see it changing.

a. Better not do that!
b. Changing the definition of the arguments to ByVal instead of the default
ByRef causes the function to return something, but I don't know enough of
what you're trying to do to say anything about the validity of the result.
ex:

Function TimeDiff(ByVal BeginTime As Integer, ByVal EndTime As Integer) As
Single

BTW I'd always use Long instead of Integer and Double instead of Single:
a. to avoid overflow as much as possible
b. to make optimal use of the 32-bit architecture of your processor
 
N

Niek Otten

BTW it does produce the expected 1 with your example inputs if you introduce
ByVal
But I suggest you reconsider the design of your functions and not not change
input arguments
 
M

millsy

The change to ByVal does seem to work. Thanks very much, I never woul
have found that.

I don't understand what you mean about changing the arguments,
thought that was how functions worked
 
M

millsy

Having looked again I can see what you mean, I have changed the values
of BeginTime and Endtime as part of the function. I don't usually do
that!
 
N

Niek Otten

Fine, millsy, cause you shouldn't!
That's why I recommended changing that instead of just using ByVal
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top