cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
JollyRoger01
Helper III
Helper III

How to apply a series of steps designed for a single table to a column of tables

I have the following code provided by one of the very helpful users on here:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZBBCoAgEEXvMmsX3UdcpKagdv9tTf6GqZRgHn7wKV+tpYUMrRPImS74CSKwHQY8bogDLoHX79xHWduAV1mEcxIIKss+yxlElUVguwAd/7uxVvH+hFxf3Rp6Z+Sm91neUbwg9693Bw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, #"20201218" = _t, #"20201221" = _t, #"20201222" = _t, #"20201223" = _t, #"20210104" = _t, #"20210105" = _t, #"20210106" = _t]),
    checkBlank = Table.CombineColumns(Source, Table.ColumnNames(Source), (x)=> if List.MatchesAll(x,each _ = "") then 1 else 0,"check"),
    #"Added Index" = Table.AddIndexColumn(checkBlank, "Index", 0, 1),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Group", each if [Index]=0 then 0 
else if [check] = 0 then List.Sum(List.FirstN( checkBlank[check], [Index])) 
else -1),
    SouceIndex = Table.AddIndexColumn(Source, "Index", 0,1),
    #"Merged Queries" = Table.NestedJoin(SouceIndex, {"Index"}, #"Added Custom", {"Index"}, "Group", JoinKind.LeftOuter),
    #"Expanded Group" = Table.ExpandTableColumn(#"Merged Queries", "Group", {"check", "Group"}, {"check", "Group"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Group", each ([check] = 0)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Index", "check"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"Group"}, {{"allrows", each _, type table }}),
    #"Promote Headers" = Table.TransformColumns(#"Grouped Rows", {{"allrows", each Table.PromoteHeaders(_, [PromoteAllScalars = true])}})
in
    #"Promote Headers"

 

That results in a column of tables and I have named the query 'Tabulated'. I also have the below code that I was planning to apply individually to all of the tables once I expanded them out, but I figured I should be able to do it to all tables before expanding them. It basically removes all the columns that are 0 or blank.

 

let
    Source = Tabulated,
    #"1" = Source{[Group=1]}[allrows],
    Custom1 = Table.ColumnNames(#"1"),
    #"Converted to Table" = Table.FromList(Custom1, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Added Custom" = Table.AddColumn(#"Converted to Table", "Custom", each [a=Table.Column(#"1", [Column1]),
b=List.MatchesAll( a, each _ ="0") or List.MatchesAll( a, each _ ="")][b]),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = false)),
    Custom2 = Table.SelectColumns(#"1",  #"Filtered Rows"[Column1])
in
    Custom2

 

I would like to know how I encapsulate all this and apply it within the previous query so all the columns with zero or blank values are removed from all the tables before I expand them out.

1 ACCEPTED SOLUTION
Vera_33
Solution Sage
Solution Sage

Hi @JollyRoger01 

 

you can convert the second one to a function, and modified your drill down table a little bit, added 0 as you do have digit instead of any type

Vera_33_0-1623309453061.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZBBCoAgEEXvMmsX3UdcpKagdv9tTf6GqZRgHn7wKV+tpYUMrRPImS74CSKwHQY8bogDLoHX79xHWduAV1mEcxIIKss+yxlElUVguwAd/7uxVvH+hFxf3Rp6Z+Sm91neUbwg9693Bw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, #"20201218" = _t, #"20201221" = _t, #"20201222" = _t, #"20201223" = _t, #"20210104" = _t, #"20210105" = _t, #"20210106" = _t]),
    checkBlank = Table.CombineColumns(Source, Table.ColumnNames(Source), (x)=> if List.MatchesAll(x,each _ = "") then 1 else 0,"check"),
    #"Added Index" = Table.AddIndexColumn(checkBlank, "Index", 0, 1),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Group", each if [Index]=0 then 0 
else if [check] = 0 then List.Sum(List.FirstN( checkBlank[check], [Index])) 
else -1),
    SouceIndex = Table.AddIndexColumn(Source, "Index", 0,1),
    #"Merged Queries" = Table.NestedJoin(SouceIndex, {"Index"}, #"Added Custom", {"Index"}, "Group", JoinKind.LeftOuter),
    #"Expanded Group" = Table.ExpandTableColumn(#"Merged Queries", "Group", {"check", "Group"}, {"check", "Group"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Group", each ([check] = 0)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Index", "check"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"Group"}, {{"allrows", each _, type table }}),
    #"Promote Headers" = Table.TransformColumns(#"Grouped Rows", {{"allrows", each Table.PromoteHeaders(_, [PromoteAllScalars = true])}}),
    
    fxRemoveColumns = (x as table) =>
    let
    Source = x,
    Custom1 = Table.ColumnNames(Source),
    #"Converted to Table" = Table.FromList(Custom1, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Added Custom" = Table.AddColumn(#"Converted to Table", "Custom", each [a=Table.Column(Source, [Column1]),
b=List.MatchesAll( a, each _ ="0") or List.MatchesAll( a, each _ ="") or List.MatchesAll( a, each _ =0)][b]),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = false)),
    Custom2 = Table.SelectColumns(Source,  #"Filtered Rows"[Column1])
in
    Custom2,
    
    AddTableColumn = Table.AddColumn(#"Promote Headers","new", each fxRemoveColumns([allrows]))
in
    AddTableColumn

 

 

View solution in original post

2 REPLIES 2
watkinnc
Solution Sage
Solution Sage

Are you concerned that by removing columns from what might be just some of the tables,that when you expand them, the missing column values will be null anyway, assuming you are accounting for that with a MissingField parameter? Or would you prefer to removed ROWS with blanks and zeros from the nested tables?

Vera_33
Solution Sage
Solution Sage

Hi @JollyRoger01 

 

you can convert the second one to a function, and modified your drill down table a little bit, added 0 as you do have digit instead of any type

Vera_33_0-1623309453061.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZBBCoAgEEXvMmsX3UdcpKagdv9tTf6GqZRgHn7wKV+tpYUMrRPImS74CSKwHQY8bogDLoHX79xHWduAV1mEcxIIKss+yxlElUVguwAd/7uxVvH+hFxf3Rp6Z+Sm91neUbwg9693Bw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, #"20201218" = _t, #"20201221" = _t, #"20201222" = _t, #"20201223" = _t, #"20210104" = _t, #"20210105" = _t, #"20210106" = _t]),
    checkBlank = Table.CombineColumns(Source, Table.ColumnNames(Source), (x)=> if List.MatchesAll(x,each _ = "") then 1 else 0,"check"),
    #"Added Index" = Table.AddIndexColumn(checkBlank, "Index", 0, 1),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Group", each if [Index]=0 then 0 
else if [check] = 0 then List.Sum(List.FirstN( checkBlank[check], [Index])) 
else -1),
    SouceIndex = Table.AddIndexColumn(Source, "Index", 0,1),
    #"Merged Queries" = Table.NestedJoin(SouceIndex, {"Index"}, #"Added Custom", {"Index"}, "Group", JoinKind.LeftOuter),
    #"Expanded Group" = Table.ExpandTableColumn(#"Merged Queries", "Group", {"check", "Group"}, {"check", "Group"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Group", each ([check] = 0)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Index", "check"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"Group"}, {{"allrows", each _, type table }}),
    #"Promote Headers" = Table.TransformColumns(#"Grouped Rows", {{"allrows", each Table.PromoteHeaders(_, [PromoteAllScalars = true])}}),
    
    fxRemoveColumns = (x as table) =>
    let
    Source = x,
    Custom1 = Table.ColumnNames(Source),
    #"Converted to Table" = Table.FromList(Custom1, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Added Custom" = Table.AddColumn(#"Converted to Table", "Custom", each [a=Table.Column(Source, [Column1]),
b=List.MatchesAll( a, each _ ="0") or List.MatchesAll( a, each _ ="") or List.MatchesAll( a, each _ =0)][b]),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = false)),
    Custom2 = Table.SelectColumns(Source,  #"Filtered Rows"[Column1])
in
    Custom2,
    
    AddTableColumn = Table.AddColumn(#"Promote Headers","new", each fxRemoveColumns([allrows]))
in
    AddTableColumn

 

 

View solution in original post

Helpful resources

Announcements
MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Power Query PA Forum 768x460.png

Check it out!

Did you know that you can visit the Power Query Forum in Power BI and now Power Apps

Urdu Hindi D365 Bootcamp 768x460.png

Urdu Hindi D365 Bootcamp

Dont miss our very own April Dunnam’s The Developer Guide to the Galaxy! Find out what the Power Platform has to offer for the traditional developer.

Top Solution Authors
Top Kudoed Authors