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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
JayMo
Regular Visitor

Custom Column - Count Columns With Data in That Row

I am new to Power BI...so if this is the wrong place to ask, please let me know.

Using the Power Query Editor, I would like to create a custom column that will summarize the count of other columns in that row containing data (not blank). This is based over 20 inividual columns that have the same name prefixed by a single number (example - column1,column2,column3, etc..)

can someone assist me in what that formula should look like?
Thx

1 ACCEPTED SOLUTION
Nolock
Resident Rockstar
Resident Rockstar

Hi @JayMo,

I've written the asked functionality with some test data. Let me know if it fills all your expectations. The code is well commented and split in many steps for better understanding.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTICYiAyAeLEpGQIx83RJ9hVKVYnGiaLgmJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, XYZ = _t, ABC = _t, Column5 = _t, Column6 = _t, Column7 = _t]),
    CountOfNonNullColumns = Table.AddColumn(
        Source, 
        "Count of non null columns", 
        (rec) =>
            let
                // select field names having prefix "Column"
                selectedFieldNames = List.Select(Record.FieldNames(rec), each Text.StartsWith(_, "Column")),
                // create a new record with only these fields
                newRecord = Record.SelectFields(rec, selectedFieldNames),
                // select all valus of this record
                allValuesAsList = Record.ToList(newRecord),
                // transform to a new list where if value is null or empty then 0 else 1
                isNotNullList = List.Transform(allValuesAsList, each if _ = null or _ = "" then 0 else 1),
                // sum it up
                countOfNonNullItems = List.Sum(isNotNullList)
            in
                countOfNonNullItems
    )
in
    CountOfNonNullColumns

View solution in original post

1 REPLY 1
Nolock
Resident Rockstar
Resident Rockstar

Hi @JayMo,

I've written the asked functionality with some test data. Let me know if it fills all your expectations. The code is well commented and split in many steps for better understanding.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTICYiAyAeLEpGQIx83RJ9hVKVYnGiaLgmJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, XYZ = _t, ABC = _t, Column5 = _t, Column6 = _t, Column7 = _t]),
    CountOfNonNullColumns = Table.AddColumn(
        Source, 
        "Count of non null columns", 
        (rec) =>
            let
                // select field names having prefix "Column"
                selectedFieldNames = List.Select(Record.FieldNames(rec), each Text.StartsWith(_, "Column")),
                // create a new record with only these fields
                newRecord = Record.SelectFields(rec, selectedFieldNames),
                // select all valus of this record
                allValuesAsList = Record.ToList(newRecord),
                // transform to a new list where if value is null or empty then 0 else 1
                isNotNullList = List.Transform(allValuesAsList, each if _ = null or _ = "" then 0 else 1),
                // sum it up
                countOfNonNullItems = List.Sum(isNotNullList)
            in
                countOfNonNullItems
    )
in
    CountOfNonNullColumns

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors