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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
_Janwi31
Frequent Visitor

Handling missing values

Hey ,

I am working on a sales dashboard where, in one table I have the total target of the year for each salesperson according to department and new/existing customer. In another table, the target achieved to date for each salesperson according to department and new/existing customer is listed. Since some departments or existing/new targets have not been met, they are not in the dataset yet, so when I try to put a visual for any department and/or for new or existing customers, it shows existing data instead.

 

Could you please tell me how I can solve this problem?

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @_Janwi31 ,

 

(1)Create a new table that merges the data from the two tables and fills in the missing data with zeros.

 

CombinedTable = 
UNION (
    SELECTCOLUMNS (
        'TotalTarget',
        "Salesperson", 'TotalTarget'[Salesperson],
        "Department", 'TotalTarget'[Department],
        "CustomerType", 'TotalTarget'[CustomerType],
        "Target", 'TotalTarget'[Target],
        "Achieved", 0
    ),
    SELECTCOLUMNS (
        'TargetAchieved',
        "Salesperson", 'TargetAchieved'[Salesperson],
        "Department", 'TargetAchieved'[Department],
        "CustomerType", 'TargetAchieved'[CustomerType],
        "Target", 0,
        "Achieved", 'TargetAchieved'[Achieved]
    )
)

 

(2)Create a new measure to calculate the sum of the target and realized values for each combination of salesperson, department, and customer type:

 

TotalTargetAndAchieved = 
SUMX (
    SUMMARIZE (
        'CombinedTable',
        'CombinedTable'[Salesperson],
        'CombinedTable'[Department],
        'CombinedTable'[CustomerType],
        "TotalTarget", SUM ( 'CombinedTable'[Target] ),
        "TotalAchieved", SUM ( 'CombinedTable'[Achieved] )
    ),
    [TotalTarget] + [TotalAchieved]
)

(3)Then the result is as follows.

vtangjiemsft_0-1689750940981.png

 

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

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

1 REPLY 1
Anonymous
Not applicable

Hi @_Janwi31 ,

 

(1)Create a new table that merges the data from the two tables and fills in the missing data with zeros.

 

CombinedTable = 
UNION (
    SELECTCOLUMNS (
        'TotalTarget',
        "Salesperson", 'TotalTarget'[Salesperson],
        "Department", 'TotalTarget'[Department],
        "CustomerType", 'TotalTarget'[CustomerType],
        "Target", 'TotalTarget'[Target],
        "Achieved", 0
    ),
    SELECTCOLUMNS (
        'TargetAchieved',
        "Salesperson", 'TargetAchieved'[Salesperson],
        "Department", 'TargetAchieved'[Department],
        "CustomerType", 'TargetAchieved'[CustomerType],
        "Target", 0,
        "Achieved", 'TargetAchieved'[Achieved]
    )
)

 

(2)Create a new measure to calculate the sum of the target and realized values for each combination of salesperson, department, and customer type:

 

TotalTargetAndAchieved = 
SUMX (
    SUMMARIZE (
        'CombinedTable',
        'CombinedTable'[Salesperson],
        'CombinedTable'[Department],
        'CombinedTable'[CustomerType],
        "TotalTarget", SUM ( 'CombinedTable'[Target] ),
        "TotalAchieved", SUM ( 'CombinedTable'[Achieved] )
    ),
    [TotalTarget] + [TotalAchieved]
)

(3)Then the result is as follows.

vtangjiemsft_0-1689750940981.png

 

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

If this post  helps, then please consider Accept it as the solution  to help the other members find it more quickly. 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.