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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
rangeet1
Frequent Visitor

Delete match negative and positive rows

I have ran into a problem where the purchase and refund are both shown in my data. I want to get rid of both matching values. Both  vaues are  under a unique Customer ID. 

 

Thank you 

1 ACCEPTED SOLUTION
v-yalanwu-msft
Community Support
Community Support

Hi, @rangeet1 ;

Try it;

let  
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8vAzMDBX0lFSUTA1UIrVQRYwQxcwRxewQBfQxTBEF2qKc6iBgQVYxAhdwBhdwARdwNAAXUQXLBQLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Customer ID" = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer ID", type text}, {"Amount", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","$ ","",Replacer.ReplaceText,{"Amount"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Replaced Value",{{"Amount", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type1", "Original", each [Customer ID]&" "&Text.From([Amount])),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Opposite", each [Customer ID]&" "&Text.From([Amount]*-1)),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.2", each if List.Contains(#"Added Custom"[Original],[Opposite]) then "" else 1),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom2", each ([Custom.2] = 1)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Original", "Opposite", "Custom.2"})
in
    #"Removed Columns"

The final output is shown below:

vyalanwumsft_0-1642499470434.pngvyalanwumsft_1-1642499476573.png


Best Regards,
Community Support Team_ Yalan Wu
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

12 REPLIES 12
v-yalanwu-msft
Community Support
Community Support

Hi, @rangeet1 ;

Is your file very large? Can you remove sensitive information and share simple files?

 

Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

v-yalanwu-msft
Community Support
Community Support

Hi, @rangeet1 ;

Try it;

let  
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8vAzMDBX0lFSUTA1UIrVQRYwQxcwRxewQBfQxTBEF2qKc6iBgQVYxAhdwBhdwARdwNAAXUQXLBQLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Customer ID" = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer ID", type text}, {"Amount", type text}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","$ ","",Replacer.ReplaceText,{"Amount"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Replaced Value",{{"Amount", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type1", "Original", each [Customer ID]&" "&Text.From([Amount])),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Opposite", each [Customer ID]&" "&Text.From([Amount]*-1)),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.2", each if List.Contains(#"Added Custom"[Original],[Opposite]) then "" else 1),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom2", each ([Custom.2] = 1)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Original", "Opposite", "Custom.2"})
in
    #"Removed Columns"

The final output is shown below:

vyalanwumsft_0-1642499470434.pngvyalanwumsft_1-1642499476573.png


Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

v-yalanwu-msft
Community Support
Community Support

Hi, @rangeet1;

You could complete it in power query .

1.add custom column.

= Table.AddColumn(#"Changed Type", "Original", each Number.ToText([Customer ID]) &" "& Number.ToText( [Amount]))

vyalanwumsft_0-1642400093012.png

2.add another custom column.

= Table.AddColumn(#"Added Custom1", "Opposite", each Number.ToText([Customer ID]) &" "& Number.ToText( [Amount]*-1))

3.add 3rd custom column.

= Table.AddColumn(#"Added Custom", "Flag", each if List.Contains(#"Added Custom"[Original],[Opposite]) then "" else 1)

4.filter rows.(1)

vyalanwumsft_1-1642400192210.png

5.remove columns.

vyalanwumsft_2-1642400228347.png

The final output is shown below:

vyalanwumsft_3-1642400253030.png

let  
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQwUNJRMjVQitWBccyQOebIHAtkji6KJl24LkMgzwiZY4zMMUHmgLQieLpgbiwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Customer ID" = _t, Amount = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer ID", Int64.Type}, {"Amount", Int64.Type}}),
#"Added Custom1" = Table.AddColumn(#"Changed Type", "Original", each Number.ToText([Customer ID]) &" "& Number.ToText( [Amount])),
#"Added Custom" = Table.AddColumn(#"Added Custom1", "Opposite", each Number.ToText([Customer ID]) &" "& Number.ToText( [Amount]*-1)),
#"Added Custom2" = Table.AddColumn(#"Added Custom", "Flag", each if List.Contains(#"Added Custom"[Original],[Opposite]) then "" else 1),
#"Filtered Rows" = Table.SelectRows(#"Added Custom2", each [Flag] <> null and [Flag] <> ""),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Original", "Opposite", "Flag"})
in
#"Removed Columns"


Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

I have tried to follow these steps. However, the last step is taking a lot

of time to load.
Thanks

Thank you for your reply. 
If my data type for Customer ID is a 'text' . For example, HN007 or CU008. My amount is a decimal currency ' $ 7.9' or '$100.0'. how can i apply this?

 

Thank you 

Syndicate_Admin
Administrator
Administrator

thank you for your answer. However, i am still havinf negative values in the data.

rangeet1
Frequent Visitor

rangeet1_0-1642054660263.png


This is what i am looking for. Remove matching negative and positive amount

thank you 

Hi,

If you want to do this at the visual level, then simply drag Customer ID to the tabel visual and write this measure

Measure = sum(data[amount])

Apply a filter of >0


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

thank you
But i still have the postive values in the data. with your

formula i can only eliminate the negative values. But i have the corresponding positive values that i want to delete as well.

Hi,

This M code works

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer ID", type text}, {"Amount", Int64.Type}}),
    #"Inserted Absolute Value" = Table.AddColumn(#"Changed Type", "Absolute Value", each Number.Abs([Amount]), Int64.Type),
    #"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Inserted Absolute Value", {{"Absolute Value", type text}}, "en-IN"),{"Customer ID", "Absolute Value"},Combiner.CombineTextByDelimiter(";", QuoteStyle.None),"Merged"),
    #"Grouped Rows" = Table.Group(#"Merged Columns", {"Merged"}, {{"GroupTables", each _, type table [Amount=nullable number, Merged=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "CountRows", each Table.RowCount([GroupTables])),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([CountRows] = 1)),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Filtered Rows", "Merged", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Merged.1", "Merged.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Merged.1", Int64.Type}, {"Merged.2", Int64.Type}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"GroupTables", "CountRows"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Merged.1", "Customer ID"}, {"Merged.2", "Amount"}}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns",{{"Customer ID", type text}})
in
    #"Changed Type2"

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi @rangeet1 ,

 

Create measure like this and use it as filter:-

Measure 4 = 
VAR amt = -1 * MAX('Table (5)'[Amount])
var cust_id = MAX('Table (5)'[Customer ID])
RETURN
    COUNTROWS (
        FILTER (
            ALL( 'Table (5)' ),
            'Table (5)'[Amount] = amt
                && 'Table (5)'[Customer ID] = cust_id )
    )

 

Ouput:-

Samarth_18_0-1642063262328.png

 

Thanks,

Samarth

Best Regards,
Samarth

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
Connect on Linkedin

amitchandak
Super User
Super User

@rangeet1 , We need to check do there have any common ID, using that we can suppress.


Can you share sample data and sample output in table format? Or a sample pbix after removing sensitive data.

 

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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