Forum Discussion
Returning results with a unique condition
ElElyon while i really appreciate you taking the time to do this, i don't know exactly what you did to achieve this, i just have the results i desired.
I'd need to know what you did in order to recreate it myself against my actual data.
I am glad it solved your problem. I will share the code below, if it still does not make sense.
Let me know, which of the criteria you wanted. And I could look into doing a quick video for you.
for Criteria 1 see the m code below.
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"USER ID", Int64.Type}, {"NAME", type text}, {"STATUS", type text}}),
#"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([STATUS] = "ANI")),
#"Grouped Rows" = Table.Group(#"Filtered Rows", {"USER ID"}, {{"Count", each Table.RowCount(_), type number}, {"New", each _, type table [USER ID=number, NAME=text, STATUS=text]}}),
#"Filtered Rows1" = Table.SelectRows(#"Grouped Rows", each ([Count] = 1)),
#"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows1",{"New"}),
#"Expanded New" = Table.ExpandTableColumn(#"Removed Other Columns", "New", {"USER ID", "NAME", "STATUS"}, {"USER ID", "NAME", "STATUS"})
in
#"Expanded New"
For the Criteria 2 see the m code below.
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"USER ID", Int64.Type}, {"NAME", type text}, {"STATUS", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"USER ID"}, {{"Count", each Table.RowCount(_), type number}, {"New", each _, type table [USER ID=number, NAME=text, STATUS=text]}}),
#"Filtered Rows1" = Table.SelectRows(#"Grouped Rows", each ([Count] = 1)),
#"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows1",{"New"}),
#"Expanded New" = Table.ExpandTableColumn(#"Removed Other Columns", "New", {"USER ID", "NAME", "STATUS"}, {"USER ID", "NAME", "STATUS"})
in
#"Expanded New"
Cheers!
- shade206Jun 16, 2020Brass Contributor
ElElyon Thank you for taking the time, i'm not familiar with Power Queries or any of this, is there are way to do it just via Formula in a cell?
- ElElyonJun 16, 2020Copper Contributor
shade206 Another simple way to achieve this using excel and without going the Power Query path, will be to use the "Filter" function in excel
You should first go to YouTube and watch a quick video on how to use the Filter function, so what I am showing you below make more sense.
I have added a sheet called "Result" to the attached excel file.
the sheet uses the following formula in any cell.
=FILTER(Table1,(Table1[STATUS]="ANI")*(COUNTIFS(Table1[USER ID],Table1[USER ID])=1),"Not Found")
Formula Usage
=Filter(array or table , Condition , Alternate result)
I specified 2 conditions in the excel function above.
Condition 1 = If STATUS is ANI
Condition 2 = if USER ID appear ONCE(1)
I used * symbol for AND to apply both conditions. I would have use + for OR.
You can play with the formula by removing one condition, and you can also try changing the 1 to 2, or even 3 to see the behavior.
Does this work better for you ?
- SergeiBaklanJun 16, 2020Diamond Contributor
With formula
you may use in E2
=IFERROR(INDEX(A$2:A$11,AGGREGATE(15,6,1/(COUNTIFS($A$2:$A$11,$A$2:$A$11)=1)*(ROW($A$2:$A$11)-ROW($A$1)),ROW()-ROW($E$1))),"")
drag it to the right and all down till empty cells appear.