March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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
Solved! Go to Solution.
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:
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.
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.
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:
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.
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]))
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)
5.remove columns.
The final output is shown below:
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
thank you for your answer. However, i am still havinf negative values in the data.
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
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.
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:-
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
@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.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
User | Count |
---|---|
90 | |
89 | |
85 | |
73 | |
49 |
User | Count |
---|---|
169 | |
144 | |
90 | |
70 | |
58 |