+ Reply to Thread
Results 1 to 5 of 5

VLOOKUP with a WEEKDAY lookup value

  1. #1
    Registered User
    Join Date
    09-18-2006
    Posts
    25

    VLOOKUP with a WEEKDAY lookup value

    Hi, unsure if I'm going about this the wrong way.
    I'd like to SUM a column where the first column has a certain day. The first column is stored as a date, although displays as a day using the Number format of 'dddd', and the values I need to SUM are displayed in different columns depending on the time of day. I thought a VLOOKUP would work so that I could determine which column I need to SUM, but I cannot get the day bit to work.

    My hope was:
    =SUM(VLOOKUP(2,August!A5:R35,16))
    My problem is I don't know how to make the '2' bit be a weekday value. My understanding of VLOOKUP is basic, so small words would help

    Am I going about this the wrong way? I've attached a sample workbook. In my real example, the only sheet I'll be able to change is the "Analysis" one as it will be in an external workbook.

    Cell F10 in Analysis is my play cell.

    Any suggestions, even if the suggestion is "don't use VLOOKUP" would be greatly appreciated.

    DoorStats_2015.xlsx

  2. #2
    Forum Expert cbatrody's Avatar
    Join Date
    04-15-2014
    Location
    Dubai
    MS-Off Ver
    Microsoft Office 365 ProPlus
    Posts
    2,136

    Re: VLOOKUP with a WEEKDAY lookup value

    Hi,

    See the attached file.

    I have added a helper column to separate the WEEKDAY and used SUMIF to get the total.

    In F10:

    =SUMIF(August!B5:B35,4,August!Q5:Q35)
    Attached Files Attached Files

  3. #3
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,733

    Re: VLOOKUP with a WEEKDAY lookup value

    You can use this formula in F10:

    =SUMPRODUCT(--(TEXT(August!$A$5:$A$35,"ddd")=F$2),August!$R$5:$R$35)

    although it will return zero as there are no values for Mondays. Copy it across to J10, and you will see the total for Friday. You can use the formula for the other months (i.e. copy it up and down), but you will need to change the name of the month on each row as appropriate.

    Hope this helps.

    Pete

  4. #4
    Registered User
    Join Date
    09-18-2006
    Posts
    25

    Re: VLOOKUP with a WEEKDAY lookup value

    Quote Originally Posted by Pete_UK View Post

    =SUMPRODUCT(--(TEXT(August!$A$5:$A$35,"ddd")=F$2),August!$R$5:$R$35)
    Pete, that's great! Thanks. I wondered about the SUMPRODUCT function but wasn't particularly aware of how it worked. So it's basically saying "look for a text version in "ddd" form of F2" (which is the day of the week I want) and return the values in the R column? I can use this for so many things. Thanks so so much!

    cbatrody: I had a look at your solution too and it works well, unfortunately I cannot edit the source tabs so cannot add a hidden helper column Thanks though.

  5. #5
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,733

    Re: VLOOKUP with a WEEKDAY lookup value

    You're welcome - thanks for marking the thread as SOLVED.

    Also, you might like to know that you can directly thank those who have helped you by clicking on the small "star" icon located in the lower left corner of a post that you have found to be helpful (not just in this thread - for any post that has helped you). This also adds to the reputation of the poster (the small green bars in the poster's profile).

    Pete

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. WEEKDAY and VLOOKUP issues
    By Anton2 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 05-04-2015, 11:45 AM
  2. [SOLVED] VLOOKUP, 2 lookup values; then sum the lookup returned
    By pricepeeler in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 10-17-2014, 03:17 PM
  3. [SOLVED] Calculate weekday end date based on sum of weekday start date and cell value
    By Rerock in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 08-01-2014, 09:17 AM
  4. [SOLVED] If Weekday() = vbSaturday Or Weekday() = vbSunday Then
    By Excelnoub in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 06-09-2014, 09:48 AM
  5. How to use vlookup if value of lookup cell is same in lookup range
    By anujteetwal in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 05-09-2014, 05:15 AM
  6. VLOOKUP WEEKDAY Function
    By yesmaybe in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 11-05-2012, 03:14 AM
  7. formula on getting weekday with lookup to other tab.
    By albert28 in forum Excel General
    Replies: 1
    Last Post: 04-08-2010, 12:00 PM

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