OFFSET for incrementing formula 3 columns?

slam

Well-known Member
Joined
Sep 16, 2002
Messages
919
Office Version
  1. 365
  2. 2019
I have this formula that I need to copy across multiple columns, but I need to increment the references by 3 columns each time.

Excel Formula:
=1-(SUM('Tracking Compliance Data'!J3:J252)/(SUM('Tracking Compliance Data'!I3:I252)))

So in the next formula, J3 becomes M3, and so on. I think I need to use OFFSET, but am struggling to put it together. Any help would be greatly appreciated!

Thanks
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
If I understood correctly:
For the J formula:
Excel Formula:
SUM(OFFSET('Tracking Compliance Data'!$A$1,3,COLUMN(C1)*3,250,1))

For the I formula (if you want that move as well):
Excel Formula:
SUM(OFFSET('Tracking Compliance Data'!$A$1,3,COLUMN(C1)*3-1,250,1))
 
Upvote 0
Solution
Maybe something like:

Excel Formula:
=1-(CHOOSECOLS(BYCOL('Tracking Compliance Data'!I3:T252,LAMBDA(x,SUM(x))),SEQUENCE(4,,2,3))/CHOOSECOLS(BYCOL('Tracking Compliance Data'!I3:T252,LAMBDA(x,SUM(x))),SEQUENCE(4,,1,3)))
 
Upvote 0
If I understood correctly:
For the J formula:
Excel Formula:
SUM(OFFSET('Tracking Compliance Data'!$A$1,3,COLUMN(C1)*3,250,1))

For the I formula (if you want that move as well):
Excel Formula:
SUM(OFFSET('Tracking Compliance Data'!$A$1,3,COLUMN(C1)*3-1,250,1))

Thank you, I did need both, so have added it as this:

Excel Formula:
=1-SUM(OFFSET('Tracking Compliance Data'!$A$1,3,COLUMN(C1)*3,252,1))/SUM(OFFSET('Tracking Compliance Data'!$A$1,3,COLUMN(C1)*3-1,252,1))

At first glance, it looked like it was working. However, to confirm, I did the same calculation on two of the columns, for example, as =1-(AQ105/AP105). This gave me 80.9524%, but the formula is giving me 80.8443%. I checked the others, and they seem to all be off by a little bit, up to 2%

Did I do something wrong? My data starts in row 3, and the first columns containing data for the formula are I & J.

Thanks!

EDIT: Ah, figured it out. Needed to change the row reference to +2 instead of +3. Working now!

Excel Formula:
=1-SUM(OFFSET('Tracking Compliance Data'!$A$1,2,COLUMN(C1)*3,252,1))/SUM(OFFSET('Tracking Compliance Data'!$A$1,2,COLUMN(C1)*3-1,252,1))
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,205
Members
452,618
Latest member
Tam84

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