+ Reply to Thread
Results 1 to 7 of 7

Rounding a given date up to a specific day of the week

  1. #1
    Registered User
    Join Date
    11-29-2012
    Location
    Scotland
    MS-Off Ver
    Excel 2010
    Posts
    3

    Rounding a given date up to a specific day of the week

    Hi all,

    I have just joined this forum looking for help with a formula in Excel 2010:

    I have a list of dates that I need to round up to the Friday that follows that particular date.

    i.e. If the given date is Friday 23rd November - Thursday 29th November inclusive, the cell should then show Friday 30th November in each case.

    Example 1 - In cell A2 I have Fri 23rd Nov, so in B2 I would then require Fri 30th Nov (I'm using UK short date format, i.e. 30/11/2012)
    Example 2 - In cell A3 I have Thu 29th Nov, so in B3 I would then require Fri 30th Nov (30/11/2012)
    Example 3 - In cell A4 I have Fri 30th Nov, so in B4 I would then require Fri 7th December (07/12/2012)

    I would like a formula that would take care of this for a list of dates that I am using, thus rounding the date up to the beginning of a Friday-Thursday working week (bizarre, I know, but that is the requirement)

    Any help would be very much appreciated.

    Thank you
    Last edited by Paul4679; 11-29-2012 at 11:52 AM.

  2. #2
    Forum Expert Ace_XL's Avatar
    Join Date
    06-04-2012
    Location
    UAE
    MS-Off Ver
    2016
    Posts
    6,074

    Re: Rounding a given date up to a specific day of the week

    try..

    =A1-WEEKDAY(A1)+6+IF(WEEKDAY(A1)>=6,7,0)
    Life's a spreadsheet, Excel!
    Say thanks, Click *

  3. #3
    Forum Expert Jakobshavn's Avatar
    Join Date
    08-17-2012
    Location
    Lakehurst, NJ, USA
    MS-Off Ver
    Excel 2007
    Posts
    1,970

    Re: Rounding a given date up to a specific day of the week

    =a1+choose(weekday(a1),5,4,3,2,1,7,6)
    Gary's Student

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

    Re: Rounding a given date up to a specific day of the week

    one way
    =A2+CHOOSE(WEEKDAY(A2,2),4,3,2,1,7,6,5)
    "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

  5. #5
    Registered User
    Join Date
    11-29-2012
    Location
    Scotland
    MS-Off Ver
    Excel 2010
    Posts
    3

    Re: Rounding a given date up to a specific day of the week

    Perfect and that was very fast - thank you Ace_XL

  6. #6
    Registered User
    Join Date
    11-29-2012
    Location
    Scotland
    MS-Off Ver
    Excel 2010
    Posts
    3

    Re: Rounding a given date up to a specific day of the week

    Thank you also Jakobshavn and martindwilson

    Just goes to show there's more than one way to skin a cat

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

    Re: Rounding a given date up to a specific day of the week

    This formula will also give you the same result

    =A1+8-WEEKDAY(A1+2)
    Audere est facere

+ 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