- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

columns delete in power query
I need power query to find all the columns that have a subtotal of zero and delete them all.
how can I address the same.
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VVFJEsMgDPsL53iGJcXh2L19A5P/f6MRWJ7mgAEj2ZLpPVzDEqqt7ViSEC7jFC2PvSHTwr70cLOUZIRiIFmPMCjSDFAnCJy7F1R7wC4bQzFKmRJAeXg9SEqkNOojJc/moDx5VTfB4vQX+RwH48WeSkNgJddFK6sz3gSydzaY/mmqoxDgH9N+Hkrx8Sk1zZmA8jVUOjtJnAe/ZEwczvcf", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t, Column8 = _t, Column9 = _t, Column10 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Column1", Int64.Type}, {"Column2", Int64.Type}, {"Column3", Int64.Type}, {"Column4", Int64.Type}, {"Column5", Int64.Type}, {"Column6", Int64.Type}, {"Column7", Int64.Type}, {"Column8", Int64.Type}, {"Column9", Int64.Type}, {"Column10", Int64.Type}}),
List1 = List.Transform(Table.ToColumns(#"Changed Type"),(x)=>try List.Sum(x) otherwise null),
List2 = Table.ColumnNames(#"Changed Type"),
ColumnsToBeRemoved = List.RemoveNulls(List.Transform(List.Positions(List1), (i)=>if List1{i}=0 then List2{i} else null)),
Result = Table.RemoveColumns(#"Changed Type",ColumnsToBeRemoved)
in
Result
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VVFJEsMgDPsL53iGJcXh2L19A5P/f6MRWJ7mgAEj2ZLpPVzDEqqt7ViSEC7jFC2PvSHTwr70cLOUZIRiIFmPMCjSDFAnCJy7F1R7wC4bQzFKmRJAeXg9SEqkNOojJc/moDx5VTfB4vQX+RwH48WeSkNgJddFK6sz3gSydzaY/mmqoxDgH9N+Hkrx8Sk1zZmA8jVUOjtJnAe/ZEwczvcf", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t, Column8 = _t, Column9 = _t, Column10 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Column1", Int64.Type}, {"Column2", Int64.Type}, {"Column3", Int64.Type}, {"Column4", Int64.Type}, {"Column5", Int64.Type}, {"Column6", Int64.Type}, {"Column7", Int64.Type}, {"Column8", Int64.Type}, {"Column9", Int64.Type}, {"Column10", Int64.Type}}),
List1 = List.Transform(Table.ToColumns(#"Changed Type"),(x)=>try List.Sum(x) otherwise null),
List2 = Table.ColumnNames(#"Changed Type"),
ColumnsToBeRemoved = List.RemoveNulls(List.Transform(List.Positions(List1), (i)=>if List1{i}=0 then List2{i} else null)),
Result = Table.RemoveColumns(#"Changed Type",ColumnsToBeRemoved)
in
Result

Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Power BI Monthly Update - February 2025
Check out the February 2025 Power BI update to learn about new features.

Subject | Author | Posted | |
---|---|---|---|
06-04-2024 01:21 PM | |||
05-03-2024 03:50 AM | |||
04-13-2024 01:19 PM | |||
05-14-2024 02:20 PM | |||
06-30-2023 02:04 AM |
User | Count |
---|---|
27 | |
25 | |
25 | |
13 | |
9 |
User | Count |
---|---|
24 | |
19 | |
16 | |
13 | |
9 |