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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
smpa01
Super User
Super User

Ignore missing column while summing column

Hi,

 

My source data consists of following 3 columns C1, C2 and C3. I add these 3 columns to get an extra column called Sum.

Capture.JPG

 

 

The problem is the source data may or may not contain all 3 columns all the time. There are instances when C1 and C2 is present but not C3; C2 and C3 is present but not C1; none of C1, C2 and C3 are present.

 

Is it possible forPQWRY (not DAX)

 

1) to add the values of only the columns that are present (from C1, C2 and C3) and ignore the missing column altogether.

and

2) to produce 0 when none of the columns are present

Like following

Capture.JPG

 

Capture.JPG

Source  Data

 

ProjectC1C2 C3
A111
B222
C333

 

Any help would be greatly appreciated.

 

Thank you in advance.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
1 ACCEPTED SOLUTION

Hey @Stachu,

 

I found a solution courtesy to the following two links

https://blog.crossjoin.co.uk/2015/02/26/handling-added-or-missing-columns-in-power-query/

https://community.powerbi.com/t5/Desktop/Unpivot-removes-rows-with-no-null-values-how-to-keep-them/m...

 

My Base headers are following - Table 0 (2)

Capture.JPG

 

let
    Source = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data0 = Source{0}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Data0, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Bottom Rows" = Table.RemoveLastN(#"Changed Type",3),
    Custom1 = Table.ColumnNames(#"Removed Bottom Rows")
in
    Custom1

I create a another query - Table 0 (3) to find which column is missing from Base headers to the current table

 

 

Capture.JPG

 

let
    Source = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data0 = Source{0}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Data0, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"C3"}),
    PresentColumns = Table.ColumnNames(#"Removed Columns"),
    Source1 = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data01 = Source1{0}[Data],
    #"Promoted Headers1" = Table.PromoteHeaders(Data01, [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers1",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Bottom Rows" = Table.RemoveLastN(#"Changed Type1",3),
    ExpectedColumns = Table.ColumnNames(#"Removed Bottom Rows"),
    Custom1 = List.Difference(ExpectedColumns, PresentColumns),
    #"Converted to Table" = Table.FromList(Custom1, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Promoted Headers2" = Table.PromoteHeaders(#"Converted to Table", [PromoteAllScalars=true]),
    #"Changed Type2" = Table.TransformColumnTypes(#"Promoted Headers2",{{"C3", type any}})
in
    #"Changed Type2"

Finally - Table 0 - to add the missing column to the current table, Replace all null with 0 and then add the columns

 

Capture.JPG

 

 

let
    Source = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data0 = Source{0}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Data0, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"C3"}),
    #"Appended Query" = Table.Combine({#"Removed Columns", #"Table 0 (3)"}),
    Custom1 = Table.TransformColumns(#"Appended Query",{},(x) => Replacer.ReplaceValue(x,null,0)),
    #"Inserted Sum" = Table.AddColumn(Custom1, "Addition", each List.Sum({[C1], [C2], [C3]}), type number)
in
    #"Inserted Sum"

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

View solution in original post

5 REPLIES 5
Stachu
Community Champion
Community Champion

new column like this will work

(try [C1] otherwise 0) + (try [C2] otherwise 0) + (try [C3] otherwise 0)

not sure about the performance impact though



Did I answer your question? Mark my post as a solution!
Thank you for the kudos 🙂

Hi @Stachu,

 

Thank you very much for your reply. You taught me something new today.However, there is glitch.

 

My basic query is following after incorporating what you suggested.

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project", type text}, {"C1", Int64.Type}, {"C2 ", Int64.Type}, {"C3", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each (try [C1] otherwise 0) + (try [#"C2 "] otherwise 0)+ (try [C3] otherwise 0))
in
    #"Added Custom"

Now there is #"Changed Type" step which generates an error once it is missing any column. This step can't be avoided. Now, Is there a way "M" can ignore the transormation of column types in #"Changed Type" step as well.

 

Thank you in advance.

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hey @Stachu,

 

I found a solution courtesy to the following two links

https://blog.crossjoin.co.uk/2015/02/26/handling-added-or-missing-columns-in-power-query/

https://community.powerbi.com/t5/Desktop/Unpivot-removes-rows-with-no-null-values-how-to-keep-them/m...

 

My Base headers are following - Table 0 (2)

Capture.JPG

 

let
    Source = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data0 = Source{0}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Data0, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Bottom Rows" = Table.RemoveLastN(#"Changed Type",3),
    Custom1 = Table.ColumnNames(#"Removed Bottom Rows")
in
    Custom1

I create a another query - Table 0 (3) to find which column is missing from Base headers to the current table

 

 

Capture.JPG

 

let
    Source = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data0 = Source{0}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Data0, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"C3"}),
    PresentColumns = Table.ColumnNames(#"Removed Columns"),
    Source1 = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data01 = Source1{0}[Data],
    #"Promoted Headers1" = Table.PromoteHeaders(Data01, [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers1",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Bottom Rows" = Table.RemoveLastN(#"Changed Type1",3),
    ExpectedColumns = Table.ColumnNames(#"Removed Bottom Rows"),
    Custom1 = List.Difference(ExpectedColumns, PresentColumns),
    #"Converted to Table" = Table.FromList(Custom1, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Promoted Headers2" = Table.PromoteHeaders(#"Converted to Table", [PromoteAllScalars=true]),
    #"Changed Type2" = Table.TransformColumnTypes(#"Promoted Headers2",{{"C3", type any}})
in
    #"Changed Type2"

Finally - Table 0 - to add the missing column to the current table, Replace all null with 0 and then add the columns

 

Capture.JPG

 

 

let
    Source = Web.Page(Web.Contents("https://community.powerbi.com/t5/Desktop/Ignore-missing-column-while-summing-column/m-p/552485")),
    Data0 = Source{0}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Data0, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Project", type text}, {"C1", Int64.Type}, {"C2", Int64.Type}, {"C3", Int64.Type}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"C3"}),
    #"Appended Query" = Table.Combine({#"Removed Columns", #"Table 0 (3)"}),
    Custom1 = Table.TransformColumns(#"Appended Query",{},(x) => Replacer.ReplaceValue(x,null,0)),
    #"Inserted Sum" = Table.AddColumn(Custom1, "Addition", each List.Sum({[C1], [C2], [C3]}), type number)
in
    #"Inserted Sum"

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hi @smpa01

 

It seems you've solved it,right? If so, please accept your answer as solution, that way, other community members will easily find the solution when they get same issue.

 

Regards,

Cherie

Community Support Team _ Cherie Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@v-cherch-msftyes I have solved it in a way and I did not want to accept the solution in case someone else can provide a better solution to this.

 

Anyway, I have accepted my own solution now.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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