+ Reply to Thread
Results 1 to 7 of 7

Help creating a date range with beginning and ending days of the month.

  1. #1
    Registered User
    Join Date
    04-27-2012
    Location
    america
    MS-Off Ver
    Excel 2010
    Posts
    4

    Help creating a date range with beginning and ending days of the month.

    Hello, I am currently using this formula =TEXT(DATE(2012, 1, 1)+(ROW(1:1)-1)*7, "mm/dd/yy")&"-"&TEXT(DATE(2012, 1, 1)+(ROW(1:1)-1)*7+6, "mm/dd/yy") to give me the range of every week.
    That works but when it reaches the end of month it continues in the same cell. Is it possible so at the end of the month the range would stay within the month instead of increasing to next month?

    Here let me try to explain visually.

    01/01/12-01/07/12
    01/08/12-01/14/12
    01/15/12-01/21/12
    01/22/12-01/28/12
    01/29/12-02/04/12 <-- can this be 01/29/12-01/31/12 ?

    And next month would be per week in each coulmn as well and so on.

    02/01/12-02/04/12
    02/05/12-02/11/12
    02/12/12-02/18/12
    02/19/12-02/25/12
    02/26/12-02/29/12

    03/01/12-03/03/12

    I hoped I explained that correctly. I have been looking for a solution for what seems like forever and any help would be appreciated.
    Thank you.

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

    Re: Help creating a date range with beginning and ending days of the month.

    That's so much plumbing already to put into one cell... and now you want to quadruple it.... ugh.

    To keep life simple, I would do this in separate columns... far off to the right out of sight if you just don't want to see it.

    To get it going...

    AA1: 1/1/2012
    AB1: =AA1+6

    Now the good stuff:

    AA2: =MIN(AB1+1, AA1+7)
    AB2: =IF(AND(AB1-AA1<6,DAY(AA2)=1),AA1+6,MIN(AA2+6,EOMONTH(AA2,0)))

    Copy AA2:AB2 down as far as you'd like.

    Then back in your first cell to "put it together", for instance

    A1: =TEXT(AA1,"mm/dd/yyyy") &" - " & TEXT(AB1,"mm/dd/yyyy")
    ....copied down.
    _________________
    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!)

  3. #3
    Registered User
    Join Date
    04-27-2012
    Location
    america
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: Help creating a date range with beginning and ending days of the month.

    That is pretty awesome what you did there. Just curious though, is there another way of doing it in one cell where there isnt that extra block of dates and you just dont feel like writing it all out or is that it. Thanks for the help.

  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: Help creating a date range with beginning and ending days of the month.

    In a world where columns and rows are free, I find it personally abhorrent to construct formulas so monstrous as to be indecipherable once complete. I alway go for "readability".

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

    Re: Help creating a date range with beginning and ending days of the month.

    This is what I mean, the second formula is virtually unreadable:

    A1: 01/01/2012 - 01/07/2012 (first week is entered manually in that exact format
    A2: =TEXT(MIN(DATEVALUE(RIGHT(A1,10))+1, DATEVALUE(LEFT(A1,10))+7),"mm/dd/yyyy") &" - " &TEXT( IF(AND(RIGHT(A1,10)-LEFT(A1,10)<6, DAY(MIN(RIGHT(A1,10)+1, LEFT(A1,10)+7))=1),LEFT(A1,10)+6,MIN(MIN(RIGHT(A1,10)+1, LEFT(A1,10)+7)+6,EOMONTH(MIN(RIGHT(A1,10)+1, LEFT(A1,10)+7),0))),"mm/dd/yyyy")

    ...A2 is copied downward.

  6. #6
    Registered User
    Join Date
    04-27-2012
    Location
    america
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: Help creating a date range with beginning and ending days of the month.

    So what you are saying is that there probably is a way but you dont see the point. Thats cool. Thanks for your help.

  7. #7
    Registered User
    Join Date
    04-27-2012
    Location
    america
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: Help creating a date range with beginning and ending days of the month.

    My god, that is pretty incredible.That is in fact exactly what I have been looking for. I now see what you mean. I cant even imagine how you were able to construct that. If I could give you anymore rep I would. Thanks for your help JBeaucaire.

+ 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