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
Anonymous
Not applicable

How to get a % of blanks vs nonblanks in a table

I want to get a % of filled rows vs blank rows. 

This is to get a compliance check, where we need to be able to click on the total % blanks at the bottom and get them to filter on those rows, 

I have a table with a lot of columns so ideally I'm looking for something that can be easily copied to other columns.

e.g.

CountyTransmission number
 5555
London4465
Dublin 
67%67%
1 ACCEPTED SOLUTION
v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

If you have many columns, for example

Capture13.JPG

 

In my method,

i open Edit queries, copy the original table,

In the "Table copy",

add an index column from 1,

delete "change type" step from the right step pane,

then select "index" column, next select "Unpivot other columns",

Capture14.JPG

Close&&apply

 

Create measures in "Table copy"

all count = CALCULATE(COUNTA('Table copy'[Value]),ALLEXCEPT('Table copy','Table copy'[Attribute]))

blank count =
IF (
    CALCULATE (
        COUNTBLANK ( 'Table copy'[Value] ),
        ALLEXCEPT ( 'Table copy', 'Table copy'[Attribute] )
    )
        = BLANK (),
    0,
    CALCULATE (
        COUNTBLANK ( 'Table copy'[Value] ),
        ALLEXCEPT ( 'Table copy', 'Table copy'[Attribute] )
    )
)


blank% = [blank count]/[all count]

no blank% = ([all count]-[blank count])/[all count]

Measure = IF(ISINSCOPE('Table copy'[Index]),MAX('Table copy'[Value]),FORMAT([no blank%],"0.00%"))

Capture15.JPG

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

View solution in original post

4 REPLIES 4
v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

If you have many columns, for example

Capture13.JPG

 

In my method,

i open Edit queries, copy the original table,

In the "Table copy",

add an index column from 1,

delete "change type" step from the right step pane,

then select "index" column, next select "Unpivot other columns",

Capture14.JPG

Close&&apply

 

Create measures in "Table copy"

all count = CALCULATE(COUNTA('Table copy'[Value]),ALLEXCEPT('Table copy','Table copy'[Attribute]))

blank count =
IF (
    CALCULATE (
        COUNTBLANK ( 'Table copy'[Value] ),
        ALLEXCEPT ( 'Table copy', 'Table copy'[Attribute] )
    )
        = BLANK (),
    0,
    CALCULATE (
        COUNTBLANK ( 'Table copy'[Value] ),
        ALLEXCEPT ( 'Table copy', 'Table copy'[Attribute] )
    )
)


blank% = [blank count]/[all count]

no blank% = ([all count]-[blank count])/[all count]

Measure = IF(ISINSCOPE('Table copy'[Index]),MAX('Table copy'[Value]),FORMAT([no blank%],"0.00%"))

Capture15.JPG

Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

If the columns are not too many, you could create measures to show each columns' blank row rate.

Create measures

Measure_country =
VAR val =
    (
        CALCULATE ( COUNTROWS ( 'Table' ), ALL ( 'Table' ) )
            - CALCULATE ( COUNTBLANK ( 'Table'[County] ), ALL ( 'Table' ) )
    )
        / CALCULATE ( COUNTROWS ( 'Table' ), ALL ( 'Table' ) )
RETURN
    IF (
        ISINSCOPE ( 'Table'[Index] ),
        MAX ( 'Table'[County] ),
        FORMAT ( val, "0.00%" )
    )

Measure_number =
VAR val =
    (
        CALCULATE ( COUNTROWS ( 'Table' ), ALL ( 'Table' ) )
            - CALCULATE ( COUNTBLANK ( 'Table'[Transmission number] ), ALL ( 'Table' ) )
    )
        / CALCULATE ( COUNTROWS ( 'Table' ), ALL ( 'Table' ) )
RETURN
    IF (
        ISINSCOPE ( 'Table'[Index] ),
        MAX ( 'Table'[Transmission number] ),
        FORMAT ( val, "0.00%" )
    )

Capture5.JPG

 

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

 

v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

It is not clear for me.

click on the total % blanks at the bottom and get them to filter on those rows?

something that can be easily copied to other columns?

The screenshot?

 

Could you clear me so to find a solution for you?

 

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

 

Anonymous
Not applicable

Hi Maggie, 

I want to be able to drillthrough to underlying table data to see the blank cells.

The screenshot is hwat we expect to see but I dont get that at all,

I just get a table with no sums,

and I want to sum all the blanks in the column and get the % of the cells blank vs cells filled. 

Is that more clear?

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.