A Microsoft Office (Excel, Word) forum. OfficeFrustration

If this is your first visit, be sure to check out the FAQ by clicking the link above. You may have to register before you can post: click the register link above to proceed. To start viewing messages, select the forum that you want to visit from the selection below.

Go Back   Home » OfficeFrustration forum » Microsoft Excel » Worksheet Functions
Site Map Home Register Authors List Search Today's Posts Mark Forums Read  

Trying To Put IFs into a Function



 
 
Thread Tools Display Modes
  #1  
Old January 10th, 2010, 06:25 PM posted to microsoft.public.excel.worksheet.functions
SkippyPB
external usenet poster
 
Posts: 7
Default Trying To Put IFs into a Function


Ihave one thing I do in a formula that I don't know or haven't figured
out how to make it work in a function.

The formula looks like this:

IF(AND(299Week1!$H3,Week1!$H3350),4,0))+
(IF(AND(349Week1!$H3,Week1!$H3400),6,0))+
(IF(AND(399Week1!$H3,Week1!$H3450),8,0))+
(IF(AND(449Week1!$H3,Week1!$H3500),10,0))+
(IF(Week1!$H3499,12,0)

Simply put, it looks at the value in Worksheet named Week1 - cell H3
(could be H4, H5, H6 depending, also could be Week2 - 17) ) and if
that number falls within the listed values, it awards points.

Any help putting that into a function that will work with the Week and
Offset shown above would be greatly appreciated.

In other words I'd like to have a function that looks like this:

=Bonus (W, Q)

Where the Function Bonus would look something like:

Public Function Bonus(W, Q)
? the incorporated IFs pointing to the proper cells
End Function

Here W is a number that would form the name of the Worksheet to look
at ("Week" & W) and Q would be the offset Pointing to cells starting
at H2 to pick up the value to analyze.

Any help would be most appreciated.

Thanks.

Steve
  #2  
Old January 10th, 2010, 07:28 PM posted to microsoft.public.excel.worksheet.functions
Rick Rothstein[_2_]
external usenet poster
 
Posts: 2,013
Default Trying To Put IFs into a Function

I think this UDF will do what you want...

Function Bonus(WeekNumber As Long, RowOffsetFromH2 As Long) As Double
Dim CellValue As Double
CellValue = Worksheets("Week" & WeekNumber).Range("H2"). _
Offset(RowOffsetFromH2).Value
Select Case CellValue
Case Is 300
Bonus = 0
Case Is 350
Bonus = 4
Case Is 400
Bonus = 6
Case Is 450
Bonus = 8
Case Is 500
Bonus = 10
Case Else
Bonus = 12
End Select
End Function

Note that the RowOffsetFromH2 argument is numbered starting at 0 (for H2),
then going to 1 (for H3), 2 (for H4), etc.

--
Rick (MVP - Excel)


"SkippyPB" wrote in message
news

Ihave one thing I do in a formula that I don't know or haven't figured
out how to make it work in a function.

The formula looks like this:

IF(AND(299Week1!$H3,Week1!$H3350),4,0))+
(IF(AND(349Week1!$H3,Week1!$H3400),6,0))+
(IF(AND(399Week1!$H3,Week1!$H3450),8,0))+
(IF(AND(449Week1!$H3,Week1!$H3500),10,0))+
(IF(Week1!$H3499,12,0)

Simply put, it looks at the value in Worksheet named Week1 - cell H3
(could be H4, H5, H6 depending, also could be Week2 - 17) ) and if
that number falls within the listed values, it awards points.

Any help putting that into a function that will work with the Week and
Offset shown above would be greatly appreciated.

In other words I'd like to have a function that looks like this:

=Bonus (W, Q)

Where the Function Bonus would look something like:

Public Function Bonus(W, Q)
? the incorporated IFs pointing to the proper cells
End Function

Here W is a number that would form the name of the Worksheet to look
at ("Week" & W) and Q would be the offset Pointing to cells starting
at H2 to pick up the value to analyze.

Any help would be most appreciated.

Thanks.

Steve


  #3  
Old January 10th, 2010, 07:30 PM posted to microsoft.public.excel.worksheet.functions
Per Jessen
external usenet poster
 
Posts: 686
Default Trying To Put IFs into a Function

Hi

I reduced your formula to this:

=IF(AND(299Week1!$H3,Week1!$H3350),4,IF(Week1!$H 3400,6,IF(Week1!$H3450,8,IF(Week1!$H3500,10,12) )))



Public Function Bonus(W As Long, Q As Long) As Long
Dim TargetVal As Double
Application.Volatile
TargetVal = Worksheets("Week" & W).Range("H3").Offset(Q, 0)

Select Case TargetVal
Case Is 300
Bonus = 0
Case Is 350
Bonus = 4
Case Is 400
Bonus = 6
Case Is 450
Bonus = 8
Case Is 500
Bonus = 10
Case Else
Bonus = 12
End Select
End Function

Regards,
Per

"SkippyPB" skrev i meddelelsen
news

Ihave one thing I do in a formula that I don't know or haven't figured
out how to make it work in a function.

The formula looks like this:

IF(AND(299Week1!$H3,Week1!$H3350),4,0))+
(IF(AND(349Week1!$H3,Week1!$H3400),6,0))+
(IF(AND(399Week1!$H3,Week1!$H3450),8,0))+
(IF(AND(449Week1!$H3,Week1!$H3500),10,0))+
(IF(Week1!$H3499,12,0)

Simply put, it looks at the value in Worksheet named Week1 - cell H3
(could be H4, H5, H6 depending, also could be Week2 - 17) ) and if
that number falls within the listed values, it awards points.

Any help putting that into a function that will work with the Week and
Offset shown above would be greatly appreciated.

In other words I'd like to have a function that looks like this:

=Bonus (W, Q)

Where the Function Bonus would look something like:

Public Function Bonus(W, Q)
? the incorporated IFs pointing to the proper cells
End Function

Here W is a number that would form the name of the Worksheet to look
at ("Week" & W) and Q would be the offset Pointing to cells starting
at H2 to pick up the value to analyze.

Any help would be most appreciated.

Thanks.

Steve


 




Thread Tools
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

vB code is On
Smilies are On
[IMG] code is Off
HTML code is Off
Forum Jump


All times are GMT +1. The time now is 05:12 PM.


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