SOLVED

Filter row if another row exists below

Copper Contributor

Tricky filter help needed, was hard enough to even search for.

 

What i have is a table of employees who are entering and leaving the building. What i need to do is get a list of employees who are IN the building, so basically removing them from the list if they are marked as OUT and not IN again. This is so HR can see who is in the building right now.

 

The table looks like this:

 

ID               TimeGenerated    UserName          Action

267105916/08/2019 9:34Joe BloggsWest Door OUT
267105616/08/2019 9:26Jane FondaWest Door IN
267105316/08/2019 9:19Corey FeldmanWest Door IN
267105016/08/2019 9:18Joe BloggsWest Door IN
267104716/08/2019 9:18Jane FondaEast Door OUT
267104416/08/2019 9:17Jane FondaWest Door IN

 

So i would need to get a filtered list showing Jane Fonda and Corey Feldman, as Joe Bloggs most recent action was to leave and therefore not in the building.

2 Replies

HI @Erron00 

 

You can achieve required filter by adding a support column and putting below formula in it:

 

=RIGHT(INDEX($D$2:$D$7,MATCH(MAX(INDEX($B$2:$B$7,MATCH(C2,$C$2:$C$7,0))),$B$2:$B$7,0)),3)

If you select Joe Bloggs it will show him out in column E.

clipboard_image_1.png

A sample file is also attached for your reference.

 

Please let me know if it works for you.

Tauqeer

 

 

best response confirmed by Erron00 (Copper Contributor)
Solution

@Erron00 

I would observe that your data is sorted by time of the action.  Therefore you simply need to search for the first occurrence of each UserName in the table and return the associated Action. For a Dynamic Array version of Excel the list of distinct names is given by the formula 'UserName' that refers to

= SORT( UNIQUE( EntryLog[UserName] ) )

where the structured references are given by  converting the data to an Excel Table that I have named 'EntryLog'.  For a traditional version of Excel such a list can be created manually with little inconvenience.

 

The last action for each person is given by

= INDEX( RIGHT(EntryLog[Action],3),

MATCH( UserName, EntryLog[UserName], 0 ) )

With traditional Excel this column would be used to filter the list of distinct names.

 

With DA, however, this can be simplified to create a filtered list of staff currently on site directly

= FILTER( UserName,

INDEX( RIGHT( EntryLog[Action], 2 ) = "IN",

MATCH( UserName, EntryLog[UserName], 0 ) ) )

 

 

1 best response

Accepted Solutions
best response confirmed by Erron00 (Copper Contributor)
Solution

@Erron00 

I would observe that your data is sorted by time of the action.  Therefore you simply need to search for the first occurrence of each UserName in the table and return the associated Action. For a Dynamic Array version of Excel the list of distinct names is given by the formula 'UserName' that refers to

= SORT( UNIQUE( EntryLog[UserName] ) )

where the structured references are given by  converting the data to an Excel Table that I have named 'EntryLog'.  For a traditional version of Excel such a list can be created manually with little inconvenience.

 

The last action for each person is given by

= INDEX( RIGHT(EntryLog[Action],3),

MATCH( UserName, EntryLog[UserName], 0 ) )

With traditional Excel this column would be used to filter the list of distinct names.

 

With DA, however, this can be simplified to create a filtered list of staff currently on site directly

= FILTER( UserName,

INDEX( RIGHT( EntryLog[Action], 2 ) = "IN",

MATCH( UserName, EntryLog[UserName], 0 ) ) )

 

 

View solution in original post