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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
breezym5
Frequent Visitor

Fill blank values with 'Other'

Hi there! 

 

I have two tables in PBI model, one called Product and one called Customer. I have product_type and key1 in Product table, customer_id and key2 in Customer. I'm doing a many-to-one relationship between Customer and Product based on key1 and key2. Now, I'd like to count the number of customers for each product_type.

 

So, I've created a table like below where I used product_type from Product table and count distinct customer_ids from Customer table. But I noticed that one of the rows remains blank, and I'm assuming that this is due to unmatching data between Customer and Product. In other words, not all the key2 in Customer are in Product.

Product TypeNumber of Customers
 35
Sandles 65
Sneakers168

 

One solution I've tried was creating a new column in Product table, but it didn't work out as expected:

 

 

ProductType_New = 
IF(
    NOT(ISBLANK(MAXX('Customer', 'Customer'[key2]))),
    MAXX(FILTER('Customer', 'Customer'[key2] = 'Product'[key1]), 'Product'[product_type]),
    "Other"
)

 

 

Can someone please shed some light on how to fill blank values with 'Other'? Thanks in advance for any help!

2 REPLIES 2
FreemanZ
Super User
Super User

hi @breezym5 ,

you are right, blank is added in the visual when the items in the one-side column could not fully cover the items of the many-side column.
it makes more sense to update your product table. 

 

with a simplied dataset like:

product   customer product
A   Amy A
B   Amber B
    Bob B
    Cindy C
    David D

you may create a calcualted table like:

table = 
VAR _table1 =
ADDCOLUMNS(
    DISTINCT(Products[Product]),
    "Count",
    CALCULATE(COUNTROWS(RELATEDTABLE(customer)))
) 
VAR _table2 = 
{(
    "Others", 
    DISTINCTCOUNT(customer[customer]) - SUMX(_table1, [Count])
)}
RETURN UNION(_table1, _table2)

 

it worked like:

FreemanZ_1-1698376906305.png

 

 

it worked like:

 

Jihwan_Kim
Super User
Super User

Hi, 

One of many ways to solve this is to create a new row ("Others") in the product table and a new column ("New Product Key column that contains "Others") customer table in PQ editor, or even go to the further upstream (Datawarehouse or the source) to ask this.

In general situation, this is a situation that we need to stop and ask data warehouse team (or to ask yourself) to check and provide the correct data without having any integrity issue.


If that is not the case, please try something like below as a temporary solution if it suits your requirement.

 

Jihwan_Kim_0-1698375340574.png

 

Jihwan_Kim_1-1698375794715.png

 

Customers count: =
SWITCH (
    TRUE (),
    HASONEVALUE ( 'Product New ct'[Product key] ),
        SWITCH (
            TRUE (),
            SELECTEDVALUE ( 'Product New ct'[Product] ) = "Others",
                COUNTROWS (
                    FILTER (
                        Customer,
                        NOT ( Customer[Product key] IN ALL ( 'Product New ct'[Product key] ) )
                    )
                ),
            MAX ( Customer[Product key] ) = MAX ( Customer[Product key] ),
                COUNTROWS (
                    FILTER (
                        Customer,
                        Customer[Product key] IN VALUES ( 'Product New ct'[Product key] )
                    )
                )
        ),
    COUNTROWS ( Customer )
)

 

 

 


If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.