+ Reply to Thread
Results 1 to 8 of 8

Extract the column header given the row header and highest value in a subset of a table

  1. #1
    Registered User
    Join Date
    12-18-2012
    Location
    Here
    MS-Off Ver
    2016
    Posts
    10

    Extract the column header given the row header and highest value in a subset of a table

    The below table is in Sheet1. I have the date and the highest number in that date range in Sheet2. I need a formula in Sheet2 that can extract the column header if there are multiple (repetitive) dates in the row headers with the ability to copy down.

    Extras: If there is a tie for high score a given date, is there a way to indicate this? Instead of the name, it returns "Tie"? Not critical

    Sheet2
    A1 = 1/1/2013
    B1 = 271
    C1 should extract "Ben" and should be able to copy this down rows (still assuming I provide the date and high game for the range for each row)

    A2 = 1/8/2013
    B2 = 277
    C2 should extract "Adam" copied from C1

    Sheet1
    (blank) (blank) John Mike Adam Ben Paul
    1/1/2013 Game 1 241 199 102 146 195
    1/1/2013 Game 2 134 143 167 271 108
    1/1/2013 Game 3 174 157 211 180 244
    1/8/2013 Game 1 115 149 215 164 107
    1/8/2013 Game 2 191 257 228 132 202
    1/8/2013 Game 3 194 251 277 275 215

    Thanks in advance!

  2. #2
    Registered User
    Join Date
    01-12-2013
    Location
    United States
    MS-Off Ver
    Excel 2010
    Posts
    20

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    I don't understand, do you want the max for the day or the max for the game?

  3. #3
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    Plop this bad boy into C3 on Sheet2:

    =INDEX(Sheet1!$C$1:$G$1,0,
    IFERROR(MATCH(B1,INDIRECT("Sheet1!C"&1+MATCH(A1,Sheet1!$A$2:$A$7,0)&":G"&1+MATCH(A1,Sheet1!$A$2:$A$7,0)),0),0)+
    IFERROR(MATCH(B1,INDIRECT("Sheet1!C"&2+MATCH(A1,Sheet1!$A$2:$A$7,0)&":G"&2+MATCH(A1,Sheet1!$A$2:$A$7,0)),0),0)+
    IFERROR(MATCH(B1,INDIRECT("Sheet1!C"&3+MATCH(A1,Sheet1!$A$2:$A$7,0)&":G"&3+MATCH(A1,Sheet1!$A$2:$A$7,0)),0),0))

    And copy downwards as far as needed.

  4. #4
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    The formula is matching the date to the list of dates, and then searching each row that contains that date by using a dynamic range. A positive search returns the column # and a bad search returns a 0.

    For you first example it searches 1/1/2013 and finds it on row 1 of the dates.
    It is then searching C(1+match#):G(1+match#), C(2+match#):G(2+match#), C(3+match#):G(3+match#).

    The INDIRECT results in a range of C2:G2, C3:G3, C4:G4. It errors out on the first range and produces a 0, finds a match in the second range in the 4th column, and errors out again in the third range.

    0 + 4 + 0 = 4

    The list of names is then INDEXed, and the 4th name over is Ben.

  5. #5
    Forum Expert
    Join Date
    06-26-2010
    Location
    Austin, TX
    MS-Off Ver
    Excel 2010
    Posts
    1,673

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    This will show a blank if no match, "Tie" if more than one match, and then the name if one match:
    =IFERROR(INDEX(Sheet1!$B$1:$G$1,SUM(IF((Sheet1!$C$2:$G$7=B1)*(Sheet1!$A$2:$A$7=A1),COLUMN(C1:G1)-1,0))),"Tie")
    Pauley
    --------
    If I helped with your issue, I'd appreciate a rep bump (hit the '*' icon to the bottom left of this post).

  6. #6
    Forum Expert
    Join Date
    06-26-2010
    Location
    Austin, TX
    MS-Off Ver
    Excel 2010
    Posts
    1,673

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    Oops, that has a bug if there is more than one winner and they are in some of the early columns. This should fix it:
    =IF(SUM((Sheet1!$C$2:$G$7=B1)*(Sheet1!$A$2:$A$7=A1))>1,"Tie",INDEX(Sheet1!$B$1:$G$1,SUM(IF((Sheet1!$C$2:$G$7=B1)*(Sheet1!$A$2:$A$7=A1),COLUMN(C1:G1)-1,0))))

    Need to use ctrl-shift-enter for it to work.
    Also, the no-winner option is pulling the data from the blank cell next to John. You can fill that with "No one" and that is what will appear. Currently, if it is truly blank, it will show a 0 for no match.

  7. #7
    Registered User
    Join Date
    12-18-2012
    Location
    Here
    MS-Off Ver
    2016
    Posts
    10

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    Both of your answers worked beautifully! I have been trying to figure this out for a while now. Rep bumps for all!

  8. #8
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Extract the column header given the row header and highest value in a subset of a tabl

    Based on your last post in this thread, its apparent that you are satisfied with the solution(s) you've received and have solved your question, but you haven't marked your thread as "SOLVED". I will do it for you this time.

    In future, to mark your thread as Solved, you can do the following -
    Select Thread Tools-> Mark thread as Solved.

    Incase your issue is not solved, you can undo it as follows -
    Select Thread Tools-> Mark thread as Unsolved.
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

+ 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. Replies: 2
    Last Post: 08-09-2012, 09:16 AM
  2. [SOLVED] find the highest text value in a row, and return the corresponding column header
    By bumbling-idiot in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 05-09-2012, 07:09 AM
  3. Replies: 1
    Last Post: 11-10-2010, 11:03 AM
  4. Getting value from next-highest 'header' row
    By gurtz in forum Excel General
    Replies: 15
    Last Post: 01-29-2009, 10:21 PM
  5. Automatically copy row header to column header...
    By Soons in forum Excel General
    Replies: 4
    Last Post: 10-16-2008, 11:38 AM

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