+ Reply to Thread
Results 1 to 12 of 12

Calculate Date Six Months from Cell Date, ongoing

  1. #1
    Registered User
    Join Date
    12-08-2009
    Location
    Silver Spring, MD
    MS-Off Ver
    Excel 2003
    Posts
    20

    Calculate Date Six Months from Cell Date, ongoing

    Hello!

    I have a start date for a contract in cell AM1. I need AN1 show a date six months from the start date in AM1. I am fine with that part.

    However, I would like for AN1 to calculate not only a six-month date but also to auto-update to the next six month date from AM1 once the first six month date is about, let's say, one month past. What I am doing is calculating when a six-month inspection needs to be completed; these inspections are ongoing, so I need them to auto-update.

    So let's say a contract was awarded today, 25 JAN 2010. That would be value in AM1.

    I want AN1 to produce a date six months from 25 JAN 2010, which would be 25 JUL 2010 (yes, this way of calculating the six month date is fine). Then around, let's say, 25 AUG 2010, I want AN1 to auto-update to produce the next six month date, which would be 25 JAN 2011 (six months from 25 JUL). Obviously the function would need to relate to TODAY() in some way.

    Is this possible?

  2. #2
    Forum Expert contaminated's Avatar
    Join Date
    05-07-2009
    Location
    Baku, Azerbaijan
    MS-Off Ver
    Excel 2013
    Posts
    1,430

    Re: Calculate Date Six Months from Cell Date, ongoing

    Can you try

    Please Login or Register  to view this content.
    Where A1 is Today's date
    Люди, питающие благие намерения, как раз и становятся чудовищами.

    Regards, ?Born in USSR?
    Vusal M Dadashev

    Baku, Azerbaijan

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Calculate Date Six Months from Cell Date, ongoing

    Building on Contaminated's putting today's date into cell A1 with the formula =TODAY(), try this formula in AN1 and copy down:

    =DATE(YEAR(AM1), MONTH(AM1)+CEILING((A1-AM1)/183,1)*6, DAY(AM1))
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  4. #4
    Registered User
    Join Date
    12-08-2009
    Location
    Silver Spring, MD
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: Calculate Date Six Months from Cell Date, ongoing

    Nope, didn't work. Any other ideas? :o)

  5. #5
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Calculate Date Six Months from Cell Date, ongoing

    I think JB has the right idea but, assuming you want the date to show as 6 months in the future right now try like this

    =DATE(YEAR(AM1),MONTH(AM1)+MAX(6,CEILING(DATEDIF(AM1,A1,"m"),6)),DAY(AM1))

    where A1 has today's date. Always updates to the next date 1 month after the previous. You can shorten if you use EDATE, i.e.

    =EDATE(AM1,MAX(6,CEILING(DATEDIF(AM1,W1,"m"),6)))

  6. #6
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Calculate Date Six Months from Cell Date, ongoing

    Quote Originally Posted by OZover View Post
    Nope, didn't work. Any other ideas? :o)
    OZ, that was a singularly unhelpful post. When something doesn't work, tell what values you tried it against and what you got vs what you expected. (nudge)

  7. #7
    Registered User
    Join Date
    12-08-2009
    Location
    Silver Spring, MD
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: Calculate Date Six Months from Cell Date, ongoing

    Whoops! Sorry! Maybe I have my "date" column formatted incorrectly? Because when I enter in the formulas above, I get #VALUE!

    Since my original spreadsheet has some sensitive information, I am creating a verrrrrry basic version here, where instead of Column AM with the dates, Column B will have the dates. Attached is what I am getting.
    Attached Files Attached Files

  8. #8
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Calculate Date Six Months from Cell Date, ongoing

    Based on your sheet....

    1) put =TODAY() in cell A1...currently there is no equal sign so no date is appearing in A1.

    2) Use this in C1:

    =DATE(YEAR(B1), MONTH(B1)+CEILING(ABS(A1-B1)/183,1)*6, DAY(B1))

    ...I highlighted the tweak I made.

  9. #9
    Registered User
    Join Date
    12-08-2009
    Location
    Silver Spring, MD
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: Calculate Date Six Months from Cell Date, ongoing

    Perfect! Thanks so much!

    What you provided definitely works if the date in Column B is in the first half of the year (in other words, if you add six months to the date, the resulting date will still be in the same year).

    However, if the date is after 6.30 (therefore six months added would result in a date in the following year), the formula doesn't compute. Also, for dates more than six months before TODAY(), the formula doesn't work either.

    ... For instance, in my sample table, attached, I have 6.15.09 in B5. C5 should produce 5.15.10 (since six months added to 6.15.09 is 12.15.09, and since that date has passed, another six months from that date would be 5.15.10). But instead it produces 12.15.2018.

    Any more suggestions?
    Attached Files Attached Files

  10. #10
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Calculate Date Six Months from Cell Date, ongoing

    It works, you just didn't notice your formulas were drifting away from the cell A1.

    =DATE(YEAR(B1), MONTH(B1)+CEILING(ABS($A$1-B1)/183,1)*6, DAY(B1))


    Add those $ signs and then copy it down.

  11. #11
    Registered User
    Join Date
    12-08-2009
    Location
    Silver Spring, MD
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: Calculate Date Six Months from Cell Date, ongoing

    Perfect! Thank you so much!!!

  12. #12
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Calculate Date Six Months from Cell Date, ongoing

    If that takes care of your need, be sure to EDIT your original post, click Go Advanced and mark the PREFIX box [SOLVED].

    ========
    (Also, use the blue "scales" icon in our posts to leave Reputation Feedback, it is appreciated. It is found across from the "time" in each of our posts.)

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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