Excel Formula Question

jerrymoon1

Board Regular
Joined
Nov 15, 2006
Messages
139
I was given the formula below to calculate the quarter to date number. The months from 1/1/05 thru 12/31/07 are in cells C3-AL3.

First - can anyone explain the formula so I may understand it and possibly modify it for other uses

Second - wherever the formula has 3:3 and I copy it to the next cell below it, I have to change the 4:4 to a 3:3 - any suggestions on how to do this easily.

By the way, the formulas are in column AO, staring on row 4.

=SUM(OFFSET(A3,1,MATCH(DATE(YEAR(Date!$C$6),INT((MONTH(Date!$C$6)+2)/3)*3-2,1),3:3,0)-1,1,MATCH(Date!$C$6,3:3,0)-MATCH(DATE(YEAR(Date!$C$6),INT((MONTH(Date!$C$6)+2)/3)*3-2,1),3:3,0)+1))

Thanks for your help!
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
I was given the formula below to calculate the quarter to date number.

Can you explain what that means exactly?

What is this supposed to do?
 
Upvote 0
The formula is calculating the quarter to date based on a date that is entered in a tab labeled "Date" For example if I enter 5/1/07 it adds up the values for 4/1/07 and 5/1/07. It also works for the years 2005 and 2006. If I enter 12/1/05 it will add up Oct-Dec 05.
 
Upvote 0
As far as the row references go, just use absolute references instead of relative ones, instead of 3:3, use $3:$3

Not sure that the formula needs to be that complicated, but I'm still not sure of your layout.
 
Upvote 0
Monthly data is in columns, beginning with 1/1/05 in column C through 12/1/07 in column AL. The formula to calculate the quarter to date is in column AO. Column A list the location and column B list all the expense accounts for the location.
 
Upvote 0
Your formula references cell C6 (although it looks like it's on a different sheet), what's in C6? Is there only 1 value under each date or a whole bunch of them?
 
Upvote 0
Cell C6 reference is on another sheet. In my current version the value is currently 5/1/2007 (in this format). There is multiple data under each month. There are approximately 900 rows of data underneath the date (20 locations with about 45 expense accounts below each.

Example A4 has Dallas for the location, the expense accounts are listed in column B, example B4 has Rent, b5 has utilities, etc. Then cell A50 is for Houston, then cell b50 has rent, b51 has utilities, etc...
 
Upvote 0
Since you mentioned copying it down, I am guessing that you want totals per row, not complete totals by date. I think this will work:

=SUM(OFFSET($C4:$AO4,,MATCH(DATE(YEAR(Date!$C$6),(-INT(-MONTH(Date!$C$6)/3)+2)*3-8,1),$C$3:$AO$3,0)-1,,3))
 
Upvote 0
Your assumption is correct. Could you rxplain how the formula works and what the additional criteris is, such as the -1,,3 at the end.

Thanks
 
Upvote 0
OK, SUM is pretty self explanatory.

The first row is $C4:$A04.

Based on the date in $C$6 on sheet Date:
We want to use that year.
This part:
(-INT(-MONTH(Date!$C$6)/3)+2)*3-8
will generate a starting month of 1, 4, 7 or 10 (There are other ways to get this, but this is what I came up with).

and we will create a date of the year, starting month and day 1

We will then locate where this is in Range $C$3:$AO$3 using MATCH and subtract 1 (the -1 part) because we want to OFFSET from the beginning of this range 1 less than this. For example, if it matched the first position, we want it to stay there, not offset 1 column, so we subtract 1.

The final ,3 means we want to return 3 columns.

So to break it down:
=SUM(OFFSET($C4:$AO4,,MATCH(DATE(YEAR(Date!$C$6),(-INT(-MONTH(Date!$C$6)/3)+2)*3-8,1),$C$3:$AO$3,0)-1,,3))

We want to SUM the range in $C4:$AO4, we don't want to offset any rows, we want to start in the column where it found the date we want, we don't want to change the number of rows, and we want to sum 3 columns.

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,221,057
Messages
6,157,655
Members
451,429
Latest member
Zaimon

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