Continue to Site

Eng-Tips is the largest engineering community on the Internet

Intelligent Work Forums for Engineering Professionals

  • Congratulations cowski on being selected by the Eng-Tips community for having the most helpful posts in the forums last week. Way to Go!

Increasing "If" function formula 1

Status
Not open for further replies.

gladkenn

Mechanical
Jul 25, 2004
58
I need to find ways in increasing the formulation of "if" function. "If" function can only accomodate 6 or 7 cells. Ex. =IF(Month="January",MTD!C206,IF(Month="February",MTD!D206,IF(Month="March",MTD!E206,IF(Month="April",MTD!F206,IF(Month="May",MTD!G206,IF(Month="June",MTD!H206)))))).

I need to increase it until december values but "if" function doesnt permit.

Hope you can help.

Gladkenn
 
Replies continue below

Recommended for you

There may be ways of increasing the if.

In the interest of program readability and adapatability, maybe you would consider alternate ways of tackling the problem.

I think vlookup would be one.

Set aside another sheet, call it DataTable
First column (A) is Jan Feb Mar etc (top to bottom)
Second column (B) is =MTD!C206 =MTD!D206 =MTD!E206

(Or find a place where this data is already stored)

Formula is
=VLOOKUP(MONTH,DataTable!$A$1:$B$12,2,FALSE)

=====================================
Eng-tips forums: The best place on the web for engineering discussions.
 
I assume that "Month" is some named cell? Or is it a placeholder for the A1 style reference of the cell containing the text of the month name?

This formula will give you the result you desire in a single cell.

=INDIRECT((ADDRESS(206,2+MONTH(DATEVALUE(Month & " 1, 2005")),1,TRUE,"MTD")))

It's a bit roundabout, though. Its steps are:

1. Append a dummy day and year string to the month string found in the cell named "Month"
2. Turn the above into a date serial with DATEVALUE function
3. Strip the month number (Jan=1, Feb=2, etc) from date serial with MONTH function
4. Add this number to the number 2 to get the column number of the desired column on MTD sheet
5. Use this column number and row number 206 to get A1 style reference string using ADDRESS function with R1C1 style arguments
6. Use indirect function to get value from the cell reference string found in step 5.

Enjoy!
 
Also, the Choose() and Index() commands are helpful. They are under the heading of "Lookup and Reference" in the function help.
 
Yet another solution: find the index of the month by looking it up in a list, then use the index as the column offset relative to the "base" cell MTD!C206
[tt]=OFFSET(MTD!$C$206,0,MATCH(Month,{"January","February","March","April","May","June","July","August","September","October","November","December"},0))[/tt]
In general, if you have to nest more than about 3 IF-statements, look for another solution.

Cheers,
Joerd

Please see FAQ731-376 for tips on how to make the best use of Eng-Tips.
 
I like Joerd's solution; a good demonstration of OFFSET. You can improve the readability by defining a name such as "MONTH_LIST" to be the series of months.

Go to Insert>Name>Define
Use MONTH_LIST as the name and enter
={"January","February","March",...,"December"} as the formula

Now you can enter Joerd's formula as
=OFFSET(MTD!$C$206,0,MATCH(Month,MONTH_LIST,0))

 
bltseattle,
A star for you for the improvement. I always wanted to use the custom (autofill) lists inside a spreadsheet, but this is the best workaround I've seen so far.

Cheers,
Joerd

Please see FAQ731-376 for tips on how to make the best use of Eng-Tips.
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor