+ Reply to Thread
Results 1 to 6 of 6

DATES: Calculate the Number of months in each year for a Date Span

  1. #1
    Registered User
    Join Date
    05-05-2008
    Posts
    16

    DATES: Calculate the Number of months in each year for a Date Span

    I have two dates.

    One is a start date and the other is the end date.

    Let’s use 7/15/2006 for the start date and 4/12/2009 for the end date.

    What I need to get to (in one way or the other) would look like this:

    Start End 2006 2007 2008 2009 2010
    7/1/06 4/12/09 5 12 12 4 0

    I know I can use DATEDIF to calculate the number of months between the dates (in this case 33). But I’ve been trying for a long time to get a formula to get the number of months in each year IF the dates span over the course of years. I’d like the formula to be good enough where if it is in just one year, it calculates that and if it spans more than one year (like the example above) it will show that data.

    Can anyone assist or do they know of an existing formula?

    Thanks for the help…

  2. #2
    Forum Expert
    Join Date
    12-29-2004
    Location
    Michigan, USA
    MS-Off Ver
    2013
    Posts
    2,208
    I came up with a real lengthy formula. There is probably a better way to do this, but here you go:

    =IF(OR($A2>DATE(C$1,12,31), $B2<DATE(C$1,1,1)), "", IF($A2<DATE(C$1,1,1), IF($B2>DATE(C$1,12,31), 12, DATEDIF(DATE(C$1,1,1),$B2,"m")), IF($B2>DATE(C$1,12,31), DATEDIF($A2,DATE(C$1,12,31),"m"), DATEDIF($A2,$B2,"m"))))

    This assumes the first year starts in C1, the 2 dates are in A2 and B2, and the formula starts in C2.

    HTH

    Jason
    Last edited by jasoncw; 06-05-2008 at 01:23 PM.

  3. #3
    Forum Moderator Leith Ross's Avatar
    Join Date
    01-15-2005
    Location
    San Francisco, Ca
    MS-Off Ver
    2000, 2003, & 2010
    Posts
    23,258
    Hello chconnol,

    This a user defined function. It is a macro that works just like a worksheet formula. It takes the starting date, ending date, and the year to return the months for.

    Example
    Please Login or Register  to view this content.
    UDF Macro Code
    Please Login or Register  to view this content.
    Adding the Macro
    1. Copy the macro above pressing the keys CTRL+C
    2. Open your workbook
    3. Press the keys ALT+F11 to open the Visual Basic Editor
    4. Press the keys ALT+I to activate the Insert menu
    5. Press M to insert a Standard Module
    6. Paste the code by pressing the keys CTRL+V
    7. Make any custom changes to the macro if needed at this time
    8. Save the Macro by pressing the keys CTRL+S
    9. Press the keys ALT+Q to exit the Editor, and return to Excel.

    Sincerely,
    Leith Ross

  4. #4
    Forum Guru
    Join Date
    08-05-2004
    Location
    NJ
    MS-Off Ver
    365
    Posts
    13,578
    Here's the one I came up with, similar to Jason's
    Please Login or Register  to view this content.
    Attached is the example

    ChemistB
    Attached Files Attached Files

  5. #5
    Registered User
    Join Date
    05-05-2008
    Posts
    16

    Question LEITH ROSS...Used Your Solution...

    First off, thanks for everyone for giving me their insights. One thing I neglected to mention was that I'm using a fiscal calendar year from December 1 through November 30. Some of you (I think) may have figured this out anyway.

    LEITH ROSS: Your solution worked really well. However, I ALSO neglected to mention that in a lot of cases the start and end date could be in the same year. When I tried this sceanrio out on your solution, it calculated the wrong number of months in the same year. I'm not at work now so I don't have the test file I used readily available but I used something like start date 3/1/08 and end date 10/1/08 and it came back with 9 months in 2008. Even I changed the dates so they were just a couple of months apart, the result was always 9 months.

    Do you think you could help me figure out a way to determine the number of months in EACH year if the end dates straddle multiple years AND the number of months if the start and end dates are in the same year?

    Again, I really liked your solution.

    To the others, I didn't test yours yet.

    Thanks again to everyone....

  6. #6
    Forum Moderator Leith Ross's Avatar
    Join Date
    01-15-2005
    Location
    San Francisco, Ca
    MS-Off Ver
    2000, 2003, & 2010
    Posts
    23,258
    Hello chconnol,

    Sorry, I thought I had that condition covered. This UDF covers the condition now if start and end dates are in the same year.
    Please Login or Register  to view this content.
    Sincerely,
    Leith Ross

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. week number based on year start 01/10
    By tony0710 in forum Excel Formulas & Functions
    Replies: 14
    Last Post: 07-02-2014, 12:21 PM
  2. Counting months up to a certain date
    By TTej in forum Excel General
    Replies: 7
    Last Post: 05-07-2008, 05:40 AM
  3. How to calculate how much I can spend each year of a lump sum?
    By Phedwards in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 07-28-2007, 06:19 PM
  4. Getting date to display after number input
    By Hemmiv in forum Excel General
    Replies: 15
    Last Post: 11-27-2006, 09:51 AM
  5. Chart converting date to year
    By EHS in forum Excel Charting & Pivots
    Replies: 1
    Last Post: 11-09-2006, 01:29 PM

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