Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
pntlindsay
Frequent Visitor

Eliminating table entries with multiple records

Hi,

I would appreciate help with the following.  I feel the solution is simple but somehow I am missing it.

I have a table with the following data:

 

ID       Date             Result

1         2/11/2019    NEGATIVE

1         1/1/2020      NEGATIVE

1         4/3/2020      POSITIVE

2         2/2/2020      NEGATIVE

3         2/3/2020      NEGATIVE

3         4/4/2020      NEGATIVE 

 

I want to create a table with entries, where there is a NEGATIVE result and where there has not been a subsequent POSITIVE result. Using the above the result will be:

 

ID       Date             Result

2         2/2/2020      NEGATIVE

3         2/3/2020      NEGATIVE

3         4/4/2020      NEGATIVE

 

Thanks in advance for any help with this.

 

Regards, Phillip

 

2 ACCEPTED SOLUTIONS
ryan_mayu
Super User
Super User

@pntlindsay 

you can create a new table

Table = 
VAR tbl=ADDCOLUMNS(Sheet4,"result2",CALCULATE(COUNTX(FILTER(Sheet4,Sheet4[ Result]="POSITIVE"),Sheet4[ Result]),ALLEXCEPT(Sheet4,Sheet4[ID ])))
return SELECTCOLUMNS(FILTER(tbl,ISBLANK([result2])),"ID",Sheet4[ID ],"Date",'Sheet4'[ Date ],"Result",Sheet4[ Result])

1.PNG 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

dax
Community Support
Community Support

Hi @pntlindsay ,

You also could use M code to achieve this goal(use this in power query editor, Transform Data->Advanced editor).

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTLSNzTUNzIwtASy/VzdHUM8w1yVYnUgkob6IDkjA2xyJvrGMLkA/2BPuJwR2FAjrPqMwXLGOOVM9E0w5WIB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, date = _t, result = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"date", type date}, {"result", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"combine", each Text.Combine([result], ","), type text}, {"all", each _, type table [ID=number, date=date, result=text]}}),
    #"Filtered Rows" = Table.SelectRows(#"Grouped Rows", each not Text.Contains([combine], "POSITIVE")),
    #"Expanded all" = Table.ExpandTableColumn(#"Filtered Rows", "all", {"date", "result"}, {"date", "result"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded all",{"combine"})
in
    #"Removed Columns"

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
dax
Community Support
Community Support

Hi @pntlindsay ,

You also could use M code to achieve this goal(use this in power query editor, Transform Data->Advanced editor).

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTLSNzTUNzIwtASy/VzdHUM8w1yVYnUgkob6IDkjA2xyJvrGMLkA/2BPuJwR2FAjrPqMwXLGOOVM9E0w5WIB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, date = _t, result = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"date", type date}, {"result", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"combine", each Text.Combine([result], ","), type text}, {"all", each _, type table [ID=number, date=date, result=text]}}),
    #"Filtered Rows" = Table.SelectRows(#"Grouped Rows", each not Text.Contains([combine], "POSITIVE")),
    #"Expanded all" = Table.ExpandTableColumn(#"Filtered Rows", "all", {"date", "result"}, {"date", "result"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded all",{"combine"})
in
    #"Removed Columns"

Best Regards,
Zoe Zhi

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

amitchandak
Super User
Super User

@pntlindsay , Create a new table like

filter(summarize(Table, Table[ID],, Table[ID] , table[Result], "_1",calculated(countrows(filter(Table,Table[Result]="NEGATIVE")),allexcept(Table[Id]))+0),[_1]=0)

ryan_mayu
Super User
Super User

@pntlindsay 

you can create a new table

Table = 
VAR tbl=ADDCOLUMNS(Sheet4,"result2",CALCULATE(COUNTX(FILTER(Sheet4,Sheet4[ Result]="POSITIVE"),Sheet4[ Result]),ALLEXCEPT(Sheet4,Sheet4[ID ])))
return SELECTCOLUMNS(FILTER(tbl,ISBLANK([result2])),"ID",Sheet4[ID ],"Date",'Sheet4'[ Date ],"Result",Sheet4[ Result])

1.PNG 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.