Results 1 to 5 of 5

Display values from an moving array and display

Threaded View

  1. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Display values from an moving array and display

    Hi.

    can I suggest an alternative approach, altogether. see sheet.

    Firstly, just leave non-playing rounds blank, not with a zero.

    Secondly, the problem i had was accommodating the 3rd player, who scored 36 in all games. Hs Max value was equal to all values... that gave me a headache. So I modified the formula showing the maximum value to be non zero, only when the number did not occur in every round played.

    So (array formula) t calculate an excluded score:
    =IF((SUM(IFERROR(1/COUNTIF(E5:N5,E5:N5),0))=1),"",MAX(E5:N5))

    thirdly, a simpler array formula for the rest:
    =IFERROR(SMALL(IF($E5:$N5<>$S11,IF($E5:$N5<>"",$E5:$N5)),T$4),"")

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...

    This works fine if a player has 2 scores equal to the max (I5 and J5) AND when all games returned the same score (Player 3)
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. how to get first non zero value in an array and display all values after that
    By helloexcel07 in forum Excel Formulas & Functions
    Replies: 12
    Last Post: 05-07-2020, 11:06 AM
  2. Replies: 1
    Last Post: 12-19-2017, 01:26 PM
  3. Display only unique values in an array
    By jrm0523 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 08-16-2012, 03:37 AM
  4. [SOLVED] Count consecutive non-zero values; list first non-zero value; display counts as an array
    By treznick in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 05-17-2012, 08:25 PM
  5. Display an array of values from a column range
    By alexandruc in forum Excel - New Users/Basics
    Replies: 2
    Last Post: 02-12-2012, 03:06 PM
  6. Display Values of Column/Range/Array/Other
    By Laelsa in forum Excel General
    Replies: 1
    Last Post: 11-21-2008, 08:42 PM
  7. Display Values of Column/Range/Array/Other
    By Laelsa in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 11-21-2008, 03:06 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