+ Reply to Thread
Results 1 to 6 of 6

Find Specific Days for Referance to Formula

  1. #1
    Registered User
    Join Date
    07-01-2009
    Location
    California
    MS-Off Ver
    Excel 2003
    Posts
    3

    Question Find Specific Days for Referance to Formula

    Hello,

    I have a column with dates for a month in descending order. I have another column where I manually enter values of work received on those days. Now, I want to create a formula that locates each Monday, then refers to the column immediatly to the right of the date in order to return a daily average of work received.

    The reason I want to do this is because I create a new worksheet each month and it would save me a lot of time of manually changing my formula and picking out each Monday by hand.

    Example :

    Monday 46
    Tuesday 77
    Wednesday 12
    Monday 36

    I need the formula to automatically find the 46, 36, then return an average. Thank you!

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

    Re: Find Specific Days for Referance to Formula

    If A2:A32 contains dates and B2:B32 contains amounts you can get an average for monday by using the formula

    =AVERAGE(IF(WEEKDAY(A2:A32)=2,B2:B32))

    This is an array formula that needs to be confirmed with CTRL+SHIFT+ENTER so that curly braces appear around the formula in the formula bar

    Change the 2 to a 3 for Tuesday etc.

    If A2:A32 actually contains the day, e.g. "Saturday", "Monday" etc.you can use this formula

    =SUMIF(A2:A32,"Monday",B2:B32)/COUNTIF(A2:A32,"Monday")

  3. #3
    Registered User
    Join Date
    07-01-2009
    Location
    California
    MS-Off Ver
    Excel 2003
    Posts
    3

    Re: Find Specific Days for Reference to Formula

    Amazing! This worked like a charm, thanks a bunch! The CNTL-SHIFt-ENTER thing is a little strange but I can get used to it.

    Also, one more quick question if you don't mind. Sometimes in the case of holidays, I remove a row of data, which removes the date and tally. All of the formulas based on this recover from this deletion except for my date formula which is used to remove Sundays and fill series.

    =IF(WEEKDAY(C4)=7,C4+2,C4+1)

    I enter 1/1/2009 in the first cell and it automatically fills out the month skipping sundays. When I remove a line, obviously the remaining days freak out. Any help in keeping the series in tact, skipping sundays and the lines I remove? Thank you!

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

    Re: Find Specific Days for Referance to Formula

    Rather than deleting rows why don't you list all your holidays somewhere, e.g. H1:H10 then make your formula to generate the dates this in C5 copied down

    =MIN(IF(WEEKDAY(C4)+{1,2,3,4,5}<>1,IF(ISNA(MATCH(C4+{1,2,3,4,5},H$1:H$10,0)),C4+{1,2,3,4,5})))

    This will ignore all Sundays and those dates listed in H1:H10

    Assumes that you never have 5 consecutive holidays/Sundays

  5. #5
    Registered User
    Join Date
    07-01-2009
    Location
    California
    MS-Off Ver
    Excel 2003
    Posts
    3

    Talking Re: Find Specific Days for Referance to Formula

    Sorry for the long reply.

    The above formula you created for me works great for removing holidays so thank you for solving that problem for me.

    You mentioned that it would remove sundays as well, did you mean that I should manually enter the sundays in with the holidays or should the formula automatically remove them for me? Currently, the formula won't automatically remove them, was wondering if there is a way for it to do so. Thanks again!

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

    Re: Find Specific Days for Referance to Formula

    Apologies, I misplaced a parenthesis. Try this version

    =MIN(IF(WEEKDAY(C4+{1,2,3,4,5})<>1,IF(ISNA(MATCH(C4+{1,2,3,4,5},H$1:H$10,0)),C4+{1,2,3,4,5})))

    You only have to list holidays in the holiday range. This version should correctly list all dates except Sundays and holidays.......

+ 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