cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
New Member

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
Super User III
Super User III

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
New Member

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
Super User III
Super User III

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

Super User III
Super User III

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

Helpful resources

Announcements
secondImage

Congratulations!

We are excited to announce the Power BI Super Users!

Wave Release 2

Check out the updates in Power BI.

Overview of Power BI 2020 release wave 2!

Microsoft Ignite

Microsoft Ignite

Join digitally, March 2–4, 2021 to explore new tech that's ready to implement. Experience the keynote in mixed reality through AltspaceVR!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.

Top Solution Authors