Forum Discussion

Zdenek_Moravec's avatar
Zdenek_Moravec
Brass Contributor
Mar 10, 2021
Solved

Count values with max date in filtered excel table

Dear colleagues

I still record Covid tests in an excel table

NameTest ResultTest date
Alannegative01.01.2021
Brednegative01.01.2021
Alanpositive01.02.2021
Cindypositive01.01.2021
Brednegative02.03.2021
Alannegative01.03.2021
Cindynot tested 
Bredpositive05.03.2021

and the request is to get number of negative and positive people. The person is negative or positive based on his latest test. (so negative=1 (Alan from 1.3.), positive=1 (Bred from 5.3.), not tested =1 (Cindy from "not tested" row)

The table is used in a dashboard with slicer, so the result should also reflect the filtered table.

See attachment with details.

Thank You

Zdenek Moravec

Cesky Krumlov, Czech Republic

  • SergeiBaklan's avatar
    SergeiBaklan
    Mar 14, 2021

    Zdenek_Moravec 

    Hi Zdenec,

     

    Filtered rows - in Excel there are two functions which could ignore hided rows or columns - SUBTOTAL() and AGGREGATE(). To check if row is hided you need to use one of these functions. There are few variants, here we use AGGREGATE() within helper column.

     

    Empty cell counting - sorry, I didn't think about that. If array is empty FILTER by default returns an error, and COUNTA doesn't care that's error or not, counts it as any other value. We may use third parameters in FILTER which will be returned in case of empty array, check if it is returned and take zero as final result, otherwise count number of values in returned array. Resulting formula

    =LET(
      visible, FILTER( T_Data[Name], T_Data[Helper],-1),
      IF(INDEX(visible,1)<> -1, COUNTA(UNIQUE( visible)), 0)
    )

7 Replies

  • SergeiBaklan's avatar
    SergeiBaklan
    Diamond Contributor

    Zdenek_Moravec 

    I assume you are on Excel 365. With that

    I'd add Helper column to the table with formula

     

    =IF([@[Test date]]="",99999,[@[Test date]])*AGGREGATE(3,5,[@Name])

     

    It returns zero for hided by filter rows, 99999 if date is missed and Test date otherwise.

    When number of employees

     

    =COUNTA(UNIQUE( FILTER( T_Data[Name], T_Data[Helper])))

     

    and number of positive employees

     

    =SUM(
        (MAXIFS(T_Data[Helper],T_Data[Name],T_Data[Name],T_Data[Helper],">0") =
          IF(T_Data[Helper],T_Data[Helper],-1  ))*
         (T_Data[Test Result]="positive")
    )

     

    Same for negative and not tested

    • Zdenek_Moravec's avatar
      Zdenek_Moravec
      Brass Contributor
      Hello Sergei
      Thank You very much, it really works.
      May I ask You to explain MAXIFS "criteria range=name, criteria=name"
      And IF helper, then helper, else =-1
      Thank You
      Zdenek
      • SergeiBaklan's avatar
        SergeiBaklan
        Diamond Contributor

        Zdenek_Moravec 

        Hi Zdenek,

         

        Let assume we filtered the table on ACC

        and let split our formula on parts

        Here

        =MAXIFS(T_Data[Helper],T_Data[Name],T_Data[Name])

        returns max date from helper against each name in the table. For hided rows helper is zero, otherwise max of available dates for the name in row. Without that we will have only one max value for all names.

        Next is helper column which we would like to compare with previous result and return 1 if dates are equal (i.e. date in helper is equal to max date for the name), otherwise zero. 

        But if simply compare these two arrays all hided rows also return 1 (0=0), thus we use IF() to change helper for hided rows on -1.

         

        In addition, the part T_Data[Name],T_Data[Helper],">0" in formula is not needed, it is from my initial variant and I forgot to remove. Finally formula could be

        =SUM(
            (MAXIFS(T_Data[Helper],T_Data[Name],T_Data[Name]) =
              IF(T_Data[Helper],T_Data[Helper],-1  ))*
             (T_Data[Test Result]="positive")
        )

Resources