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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
hdhillon
Frequent Visitor

Count columns with data only, ignoring blanks

All,

 

I want to add an extra column at the end of my table to count columns with data in them (text or numbers)  Ignoring the blanks

 

Also can I tell it to count only columns 2 to 8 say?

 

Thanks in advance ! 🙂

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @hdhillon 

 

check this approach. It converts the row to a table and then uses List-functions to filter the value-column.

This is the formula of the new column

List.Count(List.Select(Record.ToTable(_)[Value], (item)=> item <>"" and item <>null))

here the complete example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUSpPLQKSxSlpQBKEYnWileACcGEQAySTiFAIEkTSgEAwExKRlCrFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}}),
    CountNonEmptyColumns = Table.AddColumn
    (
        #"Changed Type",
        "Count of non empty columns",
        each List.Count(List.Select(Record.ToTable(_)[Value], (item)=> item <>"" and item <>null))
    )
in
    CountNonEmptyColumns

Jimmy801_0-1605011749153.png

 

uses this formula to specify column number in the variable "ColNumbers "

let 
            ColNumbers = {0,2,3},
            GetColNames = List.Accumulate(ColNumbers, {}, (o,c)=> o & {Record.ToTable(_)[Name]{c}}),
            ColCount = List.Count(List.Select(Table.SelectRows(Record.ToTable(_), (tbl)=> List.Contains(GetColNames, tbl[Name]))[Value], (item)=> item <>"" and item <>null))
        in 
            ColCount

 

Here the complete example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUSpPLQKSxSlpQBKEYnWileACcGEQAySTiFAIEkTSgEAwExKRlCrFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}}),
    CountNonEmptyColumns = Table.AddColumn(#"Changed Type", "Count of non empty columns", each let 
            ColNumbers = {0,2,3},
            GetColNames = List.Accumulate(ColNumbers, {}, (o,c)=> o & {Record.ToTable(_)[Name]{c}}),
            ColCount = List.Count(List.Select(Table.SelectRows(Record.ToTable(_), (tbl)=> List.Contains(GetColNames, tbl[Name]))[Value], (item)=> item <>"" and item <>null))
        in 
            ColCount)
in
    CountNonEmptyColumns

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

View solution in original post

4 REPLIES 4
hdhillon
Frequent Visitor

All,  is there not a simple formula, alot like COUNTA in excel that will count cells with data in them?  Obviously I want to do it for every row here

No @hdhillon - Power Query is not like Excel. There are no ranges to look at columns 2-8 in a simple way. Power Query is like a database table. The solution @Jimmy801 works. There may be other ways - I am sure there are because if you can do it one way, you can probably do it 3-4 different ways. But there is no COUNTA() function or similar function.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
Jimmy801
Community Champion
Community Champion

Hello @hdhillon 

 

check this approach. It converts the row to a table and then uses List-functions to filter the value-column.

This is the formula of the new column

List.Count(List.Select(Record.ToTable(_)[Value], (item)=> item <>"" and item <>null))

here the complete example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUSpPLQKSxSlpQBKEYnWileACcGEQAySTiFAIEkTSgEAwExKRlCrFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}}),
    CountNonEmptyColumns = Table.AddColumn
    (
        #"Changed Type",
        "Count of non empty columns",
        each List.Count(List.Select(Record.ToTable(_)[Value], (item)=> item <>"" and item <>null))
    )
in
    CountNonEmptyColumns

Jimmy801_0-1605011749153.png

 

uses this formula to specify column number in the variable "ColNumbers "

let 
            ColNumbers = {0,2,3},
            GetColNames = List.Accumulate(ColNumbers, {}, (o,c)=> o & {Record.ToTable(_)[Name]{c}}),
            ColCount = List.Count(List.Select(Table.SelectRows(Record.ToTable(_), (tbl)=> List.Contains(GetColNames, tbl[Name]))[Value], (item)=> item <>"" and item <>null))
        in 
            ColCount

 

Here the complete example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUSpPLQKSxSlpQBKEYnWileACcGEQAySTiFAIEkTSgEAwExKRlCrFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}}),
    CountNonEmptyColumns = Table.AddColumn(#"Changed Type", "Count of non empty columns", each let 
            ColNumbers = {0,2,3},
            GetColNames = List.Accumulate(ColNumbers, {}, (o,c)=> o & {Record.ToTable(_)[Name]{c}}),
            ColCount = List.Count(List.Select(Table.SelectRows(Record.ToTable(_), (tbl)=> List.Contains(GetColNames, tbl[Name]))[Value], (item)=> item <>"" and item <>null))
        in 
            ColCount)
in
    CountNonEmptyColumns

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

CNENFRNL
Community Champion
Community Champion

Hi, @hdhillon , you might want to try this solution

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlLSUTIBYgsgdoSyTZVidaLBIlAJIDIDUTBhf59EIGkIkQHpcAJLmYP16ig5Q0VBeoyVYmMB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t]),
    #"Replaced Value" = Table.ReplaceValue(Source,"",null,Replacer.ReplaceValue, Table.ColumnNames(Source)),
    #"Added Custom" = Table.AddColumn(#"Replaced Value", "CountNonBlank", each List.NonNullCount(Record.ToList(_)))
in
    #"Added Custom"

Screenshot 2020-11-10 133311.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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