Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredJoin us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM. Register now.
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.
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
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
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.