cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Anonymous
Not applicable

Finding columns with only null values

Hi
I have a lot of columns (customised fields) from O-data in Project Online with only null values.

 

Is there a way to show these columns - as I need to delete the customised fields in Project Online that we do not use.

 

Best regards,

Hasse

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

If you only want to know which columns are null columns, here is another method which doesn't require much M code knowledge. 

 

In below table, Column C and D only contain null values. The table has 3 rows in total and its name is "Query1".

vjingzhang_0-1646029670332.png

 

Then in the left-side Queries pane, right click your mouse and select New Query > Blank Query

vjingzhang_2-1646030077946.png

 

You will see a new query appear. In below image, Query2 is the new query. Input the following code in its formula bar. Replace yourTableName with the original table name. 

= Table.Profile(yourTableName)

vjingzhang_3-1646030110194.png

 

You will get some summary statistics of each column in the new table. There is a "Count" column and "NullCount" column. "Count" column means the total rows in this column. "NullCount" means the number of null values in this column. If these two values are the same, it means this column only has null values. 

 

Based on that, you can add a conditional column to compare two values. If they are equal, return "Yes". If not, return "No". 

vjingzhang_4-1646030830324.png

 

Then you can filter the new column to only have rows that value is "Yes". The most left column will tell you which columns only have null values. 

vjingzhang_5-1646031013660.png

 

I get this idea from the following blog. If you want to remove null columns in Power Query Editor, you can follow the detailed steps in this blog. 

Dynamically Remove Null Columns in Power Query with M code (antmanbi.com)

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

8 REPLIES 8
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

If you only want to know which columns are null columns, here is another method which doesn't require much M code knowledge. 

 

In below table, Column C and D only contain null values. The table has 3 rows in total and its name is "Query1".

vjingzhang_0-1646029670332.png

 

Then in the left-side Queries pane, right click your mouse and select New Query > Blank Query

vjingzhang_2-1646030077946.png

 

You will see a new query appear. In below image, Query2 is the new query. Input the following code in its formula bar. Replace yourTableName with the original table name. 

= Table.Profile(yourTableName)

vjingzhang_3-1646030110194.png

 

You will get some summary statistics of each column in the new table. There is a "Count" column and "NullCount" column. "Count" column means the total rows in this column. "NullCount" means the number of null values in this column. If these two values are the same, it means this column only has null values. 

 

Based on that, you can add a conditional column to compare two values. If they are equal, return "Yes". If not, return "No". 

vjingzhang_4-1646030830324.png

 

Then you can filter the new column to only have rows that value is "Yes". The most left column will tell you which columns only have null values. 

vjingzhang_5-1646031013660.png

 

I get this idea from the following blog. If you want to remove null columns in Power Query Editor, you can follow the detailed steps in this blog. 

Dynamically Remove Null Columns in Power Query with M code (antmanbi.com)

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Anonymous
Not applicable

Thank you so much. It worked find 😁

mahoneypat
Microsoft
Microsoft

Here's another way to do it in the query editor.  To see how it works, just create a blank query, open the Advanced Editor and replace the text there with the M code below. The first 3 steps through #"Replaced Value" are just setting up the demo data. You would do the last two steps on your query.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTICYggyVoqNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t, B = _t, C = _t, D = _t, E = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"A", Int64.Type}, {"B", Int64.Type}, {"C", type text}, {"D", type text}, {"E", Int64.Type}}),
    #"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"C", "D"}),
    NotNullColumns = List.Select(Table.ColumnNames(#"Replaced Value"), each Record.Field(#"Replaced Value"{0}, _) <> null),
    KeepNotNullColumns = Table.SelectColumns(#"Replaced Value", NotNullColumns)
in
    KeepNotNullColumns

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Anonymous
Not applicable

Thank you Pat - that's very kind of you. But it is too advanced for me to implement. I'll have to contact external consultants.

ronrsnfld
Memorable Member
Memorable Member

Here's one way:

 

   #"Select Null Columns" = 
        Table.SelectColumns(#"Previous Step",
            List.RemoveNulls(
                List.Accumulate(
                    Table.ColumnNames(#"Previous Step"),
                    {},
                    (state, current)=>
                    state & {
                        if List.NonNullCount(Table.Column(#"Previous Step",current)) = 0 
                        then current 
                        else null
                            }
                )
            )
        )
in 
    #"Select Null Columns"

You would insert it at the point in your existing code where you want to have the "null columns" selected.  Change #"Previous Step" to whatever the name of the previous step is in your existing code; and change your next line of code to refer to #"Select Null Columns" instead of to whatever it presently refers to.

Anonymous
Not applicable

Thank you, but I will go with another solution - see above.

Best regards,

Hasse

Anonymous
Not applicable

Thank you - also very kind of you. But I do not know where to insert your code?

Best regards,
Hasse

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

Thank you 2022 Review

2022 Monthly Feature Releases

We had a great 2022 with a ton of feature releases to help you drive a data culture.

Top Solution Authors
Top Kudoed Authors