+ Reply to Thread
Results 1 to 5 of 5

Help change Friday to following Monday

  1. #1
    David
    Guest

    Help change Friday to following Monday

    XL2000
    I currently use the following formula to return the Friday before the 17th
    of the month if the 17th falls on a weekend:

    =DATE(YEAR(NOW()),MONTH(NOW()),17)-MAX(0,WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW
    ()),17),2)-5)
    (Excuse the wrapping, please)

    What I would like instead, is a formula to return the date of the following
    Monday if the 17th falls on a weekend. I don't want to use the Workday()
    function, because the file will often be viewed on machines that don't have
    the Analysis Toolpak available.

    Simple for someone who knows how(?), but not for me

    --
    David

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

    =DATE(YEAR(NOW()),MONTH(NOW()),17)+CHOOSE(WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW()),17)),1,0,0,0,0,0,2)

  3. #3
    SimonCC
    Guest

    RE: Help change Friday to following Monday

    Try:
    =DATE(YEAR(NOW()),MONTH(NOW()),17)+8-WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW()),17),2)

    -Simon

    "David" wrote:

    > XL2000
    > I currently use the following formula to return the Friday before the 17th
    > of the month if the 17th falls on a weekend:
    >
    > =DATE(YEAR(NOW()),MONTH(NOW()),17)-MAX(0,WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW
    > ()),17),2)-5)
    > (Excuse the wrapping, please)
    >
    > What I would like instead, is a formula to return the date of the following
    > Monday if the 17th falls on a weekend. I don't want to use the Workday()
    > function, because the file will often be viewed on machines that don't have
    > the Analysis Toolpak available.
    >
    > Simple for someone who knows how(?), but not for me
    >
    > --
    > David
    >


  4. #4
    David
    Guest

    Re: Help change Friday to following Monday

    daddylonglegs wrote

    >
    > Here's one way....
    >
    > =DATE(YEAR(NOW()),MONTH(NOW()),17)+CHOOSE(WEEKDAY(DATE(YEAR(NOW()),MONT
    > H(NOW()),17)),1,0,0,0,0,0,2)
    >
    >


    That works as desired. Many thanks.

    --
    David

  5. #5
    David
    Guest

    RE: Help change Friday to following Monday

    This works under limited conditions, but fails to satisfy my requirements:
    If the 17th falls outside the weekend (M-F), leave it as the 17th. It
    instead *always* returns the following Monday.

    Thanks for the effort anyway.

    --
    David

    =?Utf-8?B?U2ltb25DQw==?= wrote

    > Try:
    > =DATE(YEAR(NOW()),MONTH(NOW()),17)+8-WEEKDAY(DATE(YEAR(NOW()),MONTH(NOW
    > ()),17),2)
    >
    > -Simon
    >
    > "David" wrote:
    >
    >> XL2000
    >> I currently use the following formula to return the Friday before the
    >> 17th of the month if the 17th falls on a weekend:
    >>
    >> =DATE(YEAR(NOW()),MONTH(NOW()),17)-MAX(0,WEEKDAY(DATE(YEAR(NOW()),MONT
    >> H(NOW ()),17),2)-5)
    >> (Excuse the wrapping, please)
    >>
    >> What I would like instead, is a formula to return the date of the
    >> following Monday if the 17th falls on a weekend. I don't want to use
    >> the Workday() function, because the file will often be viewed on
    >> machines that don't have the Analysis Toolpak available.
    >>
    >> Simple for someone who knows how(?), but not for me
    >>
    >> --
    >> David
    >>



+ 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