+ Reply to Thread
Results 1 to 7 of 7

cumulative comparison with last year of month to date

  1. #1
    Registered User
    Join Date
    07-09-2012
    Location
    Rockford, Illinois
    MS-Off Ver
    Excel 2007
    Posts
    12

    cumulative comparison with last year of month to date

    I am wondering how to calculate a cumulative total of data up to the current date of the month in comparison of daily activity in a month to last year.
    As the attached example shows, I have two columns, one for the days of the month for this year and one column with the days for last year. I need to compare the total for the days of this year with the total of the days for last year, but only up til the last day of this month which has data entered.

    I could create a another column to do this but wanted to calculate it in one cell without creating another column. thanks, johnbtor
    Attached Files Attached Files

  2. #2
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,726

    Re: cumulative comparison with last year of month to date

    You can put this formula in D6:

    =IF(B6=0,"",(B6-C6)/C6)

    Format as prcentage with 2 dp, and then copy down. That will duplicate what you have manually in column D.

    Then in another cell you can put this formula:

    =(SUM(B$6:B36)-SUM(INDIRECT("C$6:C"&5+COUNTIF(B6:B36,">0"))))/SUM(INDIRECT("C$6:C"&5+COUNTIF(B6:B36,">0")))

    which will give you the ratio for the totals up to the latest non-zero entry in column B (assuming all entries are non-zero for previous days).

    Hope this helps.

    Pete

  3. #3
    Forum Moderator - RIP Richard Buttrey's Avatar
    Join Date
    01-14-2008
    Location
    Stockton Heath, Cheshire, UK
    MS-Off Ver
    Office 365, Excel for Windows 2010 & Excel for Mac
    Posts
    29,464

    Re: cumulative comparison with last year of month to date

    Hi and welcome to the forum.

    One way (probably of several!) is

    -(1-SUMIF(B6:B36,">0")/SUMIFS(C6:C36,B6:B36,">0"))
    Richard Buttrey

    RIP - d. 06/10/2022

    If any of the responses have helped then please consider rating them by clicking the small star icon below the post.

  4. #4
    Registered User
    Join Date
    07-09-2012
    Location
    Rockford, Illinois
    MS-Off Ver
    Excel 2007
    Posts
    12

    Re: cumulative comparison with last year of month to date

    this works also! thanks! Love learning about these different ways to approach these challenges. thanks again.

  5. #5
    Forum Expert Cutter's Avatar
    Join Date
    05-24-2004
    Location
    Ontario,Canada
    MS-Off Ver
    Excel 2010
    Posts
    6,451

    Re: cumulative comparison with last year of month to date

    @ johnbtor

    Based on your last post it seems that you are satisfied with the solution(s) you've received but you haven't marked your thread as SOLVED. I'll do that for you now but please keep in mind for your future threads that Rule #9 requires you to do that yourself. If your problem has not been solved you can use Thread Tools (located above your first post) and choose "Mark this thread as unsolved".
    Thanks.

    Also, as a new member of the forum, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of those who helped.

  6. #6
    Registered User
    Join Date
    07-09-2012
    Location
    Rockford, Illinois
    MS-Off Ver
    Excel 2007
    Posts
    12

    Re: cumulative comparison with last year of month to date

    Just had one question. I am wondering why one needs to take -(1-Sumif). Seems that makes the answer 1 less than the desired answer?

  7. #7
    Forum Moderator - RIP Richard Buttrey's Avatar
    Join Date
    01-14-2008
    Location
    Stockton Heath, Cheshire, UK
    MS-Off Ver
    Office 365, Excel for Windows 2010 & Excel for Mac
    Posts
    29,464

    Re: cumulative comparison with last year of month to date

    Simply because it's shorter than the alternative
    =-(SUMIFS(C6:C36,B6:B36,">0")-SUMIF(B6:B36,">0"))/SUMIFS(C6:C36,B6:B36,">0")

    The original formula starts by dividing the total of 2011 by 2012 total to give 4469/4785 = .99396
    But of course you want the difference between 2011 & 2012 divided by 2011, hence the need to deduct the result above from 1 to give -0.06603

    Regards

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1