Results 1 to 6 of 6
  1. #1
    Star Lounger
    Join Date
    Jan 2001
    Posts
    93
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Finding field name for the maximum value (2000)

    I have a table of data with field headings in the first row and records names in the first column. I want to be able to find the field name where the maximum value in the records occurs, preferably without a macro. I would like this value to be recorded in the Max field (see attachment). Can any one help please ?

    PaulJ
    Attached Files Attached Files

  2. #2
    Platinum Lounger
    Join Date
    Feb 2001
    Location
    Weert, Limburg, Netherlands
    Posts
    4,812
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Finding field name for the maximum value (2000)

    This array formula finds the first field that contains a maximum value:

    =INDEX($B$1:$R$1,MATCH(MAX(B2:R2),B2:R2,0))

    press control-shift-enter to enter the formula on row 2 and then copy down.
    Jan Karel Pieterse
    Microsoft Excel MVP, WMVP
    www.jkp-ads.com
    Professional Office Developers Association

  3. #3
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Finding field name for the maximum value (2000)

    In your workbook, you have a field Mean; I suppose that should be Max. You can use a formula like

    =OFFSET($A$1,0,MATCH(MAX(B2:R2),B2:R2,0))

    Comments:
    MAX(B2:R2) finds the maximum value in the record in row 2.
    MATCH(MAX(B2:R2);B2:R2;0) finds the first column in the record that contains the max value.
    OFFSET($A$1,0,MATCH(MAX(B2:R2),B2:R2,0)) finds the value in the first row (the field names) in the column that contains the max value.

    See attached workbook.
    Attached Files Attached Files

  4. #4
    Star Lounger
    Join Date
    Jan 2001
    Posts
    93
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Finding field name for the maximum value (2000)

    Many thanks for eveyones help in this. I have gone with the OFFSET function in the end but the other options have certainly opened my eyes !! I will definitely be investigating them further.
    Thanks

    Paul

  5. #5
    3 Star Lounger
    Join Date
    Jan 2002
    Location
    The Hague, Netherlands
    Posts
    283
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Finding field name for the maximum value (2000

    What Jan Karel has suggested needs NOT to be array-entered. It would be more efficient than the one with OFFSET (Sorry Hans) for the latter is a volatile function that prolongs the recalc times.

    Aladin
    Microsoft MVP - Excel

  6. #6
    Platinum Lounger
    Join Date
    Feb 2001
    Location
    Weert, Limburg, Netherlands
    Posts
    4,812
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Finding field name for the maximum value (2000

    Hi Aladin,

    <<What Jan Karel has suggested needs NOT to be array-entered>>

    Of course, silly me.
    Jan Karel Pieterse
    Microsoft Excel MVP, WMVP
    www.jkp-ads.com
    Professional Office Developers Association

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •