Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
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?
Solved! Go to Solution.
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.
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.
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.
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.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.
| User | Count |
|---|---|
| 8 | |
| 6 | |
| 6 | |
| 5 | |
| 4 |
| User | Count |
|---|---|
| 25 | |
| 14 | |
| 8 | |
| 8 | |
| 8 |