+ Reply to Thread
Results 1 to 10 of 10

Return Date of Next Ocurrance of Day Number

  1. #1
    Registered User
    Join Date
    09-09-2003
    Posts
    12

    Return Date of Next Ocurrance of Day Number

    I need a formula to return the next occurrence of day of the month.

    As well it needs to be at least two weeks after the original date, but can be the date that is exactly two weeks after the original date. I've been working with a forumla:

    =IF(DAY(A1+14)=B1,A1+14,DATE(YEAR(A1+14),MONTH(A1+14)+1,B1))

    A1=3/18/13
    B1= Drop down List (1 or 15 in C1:C2)

    ie. Find the next 1st of the month.
    Original Date: 3/18/13
    Two Weeks After: 4/1/13

    Since it's also the next 1st, it returns 4/1/13

    ie. Find the next 15th of the month.
    Original Date: 3/18/13
    Two Weeks After: 4/1/13

    Should return 4/15/13, but is returning 5/15/13, because A1+14 in that case is already in the next month. I could start nesting more IF statements, but that would get messy considering this is already part of a larger formula.

    Is there any way I can accomplish this cleaner without nesting more IFs?
    Last edited by SiRCYRO; 03-18-2013 at 07:47 PM.

  2. #2
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Return Date of Next Ocurrance of Day Number

    so next first after 28th jan is 1st march?

    =eomonth(A1+14,0)+1
    Last edited by martindwilson; 03-18-2013 at 08:08 PM.
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

  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: Return Date of Next Ocurrance of Day Number

    If the original date is in A1, then:

    Next 1st: =EOMONTH($A1, --NOT(EOMONTH($A1, 0)+1-$A1>=14))+1
    Next 15th: =EOMONTH($A1, --NOT(EOMONTH($A1, 0)+15-$A1>=14))+15
    _________________
    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
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Return Date of Next Ocurrance of Day Number

    Martin's right, it is easier than that...

    Next 1st: =EOMONTH($A1+13, 0)+1 (martin's formula)
    Next 15th: =EOMONTH($A1-1, 0)+15
    Last edited by JBeaucaire; 03-18-2013 at 08:29 PM.

  5. #5
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Return Date of Next Ocurrance of Day Number

    ah but i added 14 and was having trouble working out what was wrong god call jb

  6. #6
    Registered User
    Join Date
    09-09-2003
    Posts
    12

    Re: Return Date of Next Ocurrance of Day Number

    Thanks, works like a charm! I was using EOMONTH() before and it worked about 95% of the time. I've tested yours and it seems to work perfectly, at least where my implementation went wrong.

    If I wanted to accomplish the same thing except without adding the two weeks?

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

    Re: Return Date of Next Ocurrance of Day Number

    To get the next 1st and 15th regardless:

    Next 1st: =EOMONTH($A1, 0)+1
    Next 15th: =EOMONTH($A1-14, 0)+15


    If that takes care of your original query, please select Thread Tools from the menu above and mark the thread as solved. Thanks.

  8. #8
    Registered User
    Join Date
    09-09-2003
    Posts
    12

    Re: Return Date of Next Ocurrance of Day Number

    That almost works, except if the date is the 1st or 15th, it should return that date. ie. 1/1/13 should return 1/1/13 not 2/1/13.

    Thanks.

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

    Re: Return Date of Next Ocurrance of Day Number

    So tweak the $A1 value. for the first, probably $A1-1, for the 15th probably $A1-15. Play around with it.

  10. #10
    Registered User
    Join Date
    09-09-2003
    Posts
    12

    Re: Return Date of Next Ocurrance of Day Number

    I found a way to make it work, I had an error elsewhere in my calculation. Appreciate all the help! Thank you.

+ 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