IF/OFFSET Function not working properly

Ronderbecke

Board Regular
Joined
Oct 4, 2017
Messages
73
Currently I have been using this function plenty of times; however, when adding the additional if statements to the OFFSET it is causing errors. I have tried it multiple ways and simply want to drag down to retrieve the information for customers. The error it gives me now that I have a bunch of IF statements in it is: Formula Parse Error

Am I doing something wrong with this?

=IF(OFFSET('Travis Jones'!$E$9,(ROW('Travis Jones'!C1)-1)*12,0)=IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+4000,"1 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+5500,"2 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+5750,"2.5 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+6000,"3 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+6250,"3.5 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+6500,"4 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+6750,"4.5 Ton",IF('Travis Jones'!$D$9*'Travis Jones'!$F$2)+7000,"5 Ton",))
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Replace = with ,
e.g. =IF(OFFSET('Travis Jones'!$E$9,(ROW('Travis Jones'!C1)-1)*12,0),IF(
 
Upvote 0
What are you trying to do with all these If() statements. I'm guessing that a Vlookup would be more appropriate, but it's hard to tell because your syntax is wrong.
 
Upvote 0
Let's take out all the "'Travis Jones'!" and color to make the formula readable on the forum:

=IF(OFFSET($E$9,(ROW(C1)-1)*12,0)=IF($D$9*$F$2)+4000,"1 Ton",IF($D$9*$F$2)+5500,"2 Ton",IF($D$9*$F$2)+5750,"2.5 Ton",IF($D$9*$F$2)+6000,"3 Ton",IF($D$9*$F$2)+6250,"3.5 Ton",IF($D$9*$F$2)+6500,"4 Ton",IF($D$9*$F$2)+6750,"4.5 Ton",IF($D$9*$F$2)+7000,"5 Ton",))

Now we can see you have many repeated IF($D$9*$F$2)s that don't parse:

=IF(OFFSET($E$9,(ROW(C1)-1)*12,0)=IF($D$9*$F$2)+4000,"1 Ton",IF($D$9*$F$2)+5500,"2 Ton",IF($D$9*$F$2)+5750,"2.5 Ton",IF($D$9*$F$2)+6000,"3 Ton",IF($D$9*$F$2)+6250,"3.5 Ton",IF($D$9*$F$2)+6500,"4 Ton",IF($D$9*$F$2)+6750,"4.5 Ton",IF($D$9*$F$2)+7000,"5 Ton",))

The IF function requires three arguments: =IF(Something_is_True, then_do_something, otherwise_do_something_else). Your IFs are each missing a second and third argument. I suspect you wanted to write something like this:
Code:
=IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+4000, 
  "1 Ton",
  IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+5500,
    "2 Ton",
    IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+5750,
      "2.5 Ton",
      IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+6000,
        "3 Ton",
        IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+6250,
          "3.5 Ton",
          IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+6500,
            "4 Ton",
            IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+6750,
              "4.5 Ton",
              IF(OFFSET($E$9,(ROW(C1)-1)*12,0)<=$D$9*$F$2+7000,
                "5 Ton",))))))))
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top