Formula to Calculate QTD and YTD

mackcracknsack

New Member
Joined
Dec 3, 2015
Messages
11
Hi,

I am looking for a formula to calculate QTD and YTD data.

Brief explanation of my model, it will contain 3 years of actuals (2015-2017) and 1 year of current budget/plan data, all of which are broken out monthly. I will have 4 QTD calcs (actuals & plan) and 4 YTD calcs.
I also have a lead sheet to enter the current month which will determine the calculation for both YTD (sum x amount of periods for March, April, Sept etc) once cell B5 is changed. The month entry on my lead sheet also works out the current Qtr which will calculate QTD for Q1 (Jan-Mar) or 2 months of Qtr 2 (Apr & May)

The year to date calculation will be cumulative and just keep adding up the months of the year
The QTD calc will contain only 1,2 or 3 months data for the current quarter all being determined by the inputted month

ABCDEFGHIJKLMNOPQRSTUVWXYzAAABACAD
1MarQ1
220172017 Plan
3JanFebMarAprMayJunJulAugSepOctNovDecJanFebMarAprMayJunJulAugSepOctNovDec2017 QTD2017 YTD2017 Plan QTD2017 Plan YTD
4Gross Sales123123123123123123123123
5Net Sales123123123123123123123123
6Expenses-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3

<tbody>
</tbody>



Thanks for help
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Hi,

see if this helps:


Excel 2016 (Windows) 64 bit
ABCDEFGHIJKLMNOPQRSTUVWXYZAAABACAD
1MarQ1
220172017 Plan
3JanFebMarAprMayJunJulAugSepOctNovDecJanFebMarAprMayJunJulAugSepOctNovDec2017 QTD2017 YTD2017 Plan QTD2017 Plan YTD
4Gross Sales1231231231231231231231236666
5Net Sales1231231231231231231231236666
6Expenses-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-1-2-3-6-6-6-6
Sheet1
Cell Formulas
RangeFormula
AA4=SUM(OFFSET($C4,0,((ROUNDUP(MATCH($B$1,C$3:N$3,0)/3,0)-1)*3),,MATCH($B$1,C$3:N$3,0)-((ROUNDUP(MATCH($B$1,C$3:N$3,0)/3,0)-1)*3)))
AB4=SUM(OFFSET($C4,0,0,1,MATCH($B$1,$C$3:$N$3,0)))
AC4=SUM(OFFSET($O4,0,((ROUNDUP(MATCH($B$1,O$3:Z$3,0)/3,0)-1)*3),,MATCH($B$1,O$3:$Z$3,0)-((ROUNDUP(MATCH($B$1,O$3:Z$3,0)/3,0)-1)*3)))
AD4=SUM(OFFSET($O4,0,0,1,MATCH($B$1,$C$3:$N$3,0)))
 
Upvote 0
I was surfing through posts and saw this.
Wanted to thank you as I had a situation where this approach was very insightful and worked for me.
Appreciate your time!
 
Upvote 0
Hey,

I am trying to do a similar calculation in my table but for Q1, Q2 , Q3 & Q4.
The way my formulas work in my tables, some data has already flowed into May but I do not want to factor this into my Qtr2 calc as it should only contain 1 month of data i.e April.

The calculation will all be based from the helper cell in B1 with current month selected.
Hopefully the formulas can be set up for Qtr3 and Qtr4 and they will be populated once we hit those months.
 
Upvote 0

Forum statistics

Threads
1,215,214
Messages
6,123,661
Members
449,114
Latest member
aides

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