Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello,
I am trying to write a Dax query for the below on e but the expected results are not coming. Could you guys help me in this.
I have sales data which contains the product codes, territory, state, city and sales amount. most product codes are sold in all territories but there are some product codes which are not sold in all territories. I need to create a measure to calculate the percentage of productcodes which are not sold everywhere in territories.
Attaching the sample
Thank you
Solved! Go to Solution.
Hi,
I am not sure how your semantic model looks like, but I tried to create a sample pbix file like below.
Please check the below picture and the attached pbix file.
% of product count not-all-territory: =
VAR _result =
COUNTROWS (
FILTER (
VALUES ( 'product'[product_code] ),
CALCULATE ( COUNTROWS ( SUMMARIZE ( data, territory[territory] ) ) ) <> 4
)
)
VAR _allproduct =
COUNTROWS ( VALUES ( 'product'[product_code] ) )
RETURN
DIVIDE ( _result, _allproduct )
Hi @AshwiniPulipat ,
Thank you @Jihwan_Kim and @aduguid very much for the solution, and I've tried other ways to help you understand the problem:
PercentageNotsoldEverywhere =
VAR _count1 =
CALCULATE (
DISTINCTCOUNT ( 'Table (2)'[Territory] ),
ALLSELECTED ( 'Table (2)' )
)
VAR _count2 =
CALCULATE (
DISTINCTCOUNT ( 'Table (2)'[Territory] ),
ALLEXCEPT ( 'Table (2)', 'Table (2)'[Prouduct code] )
)
RETURN
1 - DIVIDE ( _count2, _count1 )
You change to the new data source you need to use in the following actions.
Hope it helps!
Best regards,
Community Support Team_ Tom Shen
If this post helps then please consider Accept it as the solution to help the other members find it more quickly.
Hi @AshwiniPulipat ,
Thank you @Jihwan_Kim and @aduguid very much for the solution, and I've tried other ways to help you understand the problem:
PercentageNotsoldEverywhere =
VAR _count1 =
CALCULATE (
DISTINCTCOUNT ( 'Table (2)'[Territory] ),
ALLSELECTED ( 'Table (2)' )
)
VAR _count2 =
CALCULATE (
DISTINCTCOUNT ( 'Table (2)'[Territory] ),
ALLEXCEPT ( 'Table (2)', 'Table (2)'[Prouduct code] )
)
RETURN
1 - DIVIDE ( _count2, _count1 )
You change to the new data source you need to use in the following actions.
Hope it helps!
Best regards,
Community Support Team_ Tom Shen
If this post helps then please consider Accept it as the solution to help the other members find it more quickly.
Hi,
I am not sure how your semantic model looks like, but I tried to create a sample pbix file like below.
Please check the below picture and the attached pbix file.
% of product count not-all-territory: =
VAR _result =
COUNTROWS (
FILTER (
VALUES ( 'product'[product_code] ),
CALCULATE ( COUNTROWS ( SUMMARIZE ( data, territory[territory] ) ) ) <> 4
)
)
VAR _allproduct =
COUNTROWS ( VALUES ( 'product'[product_code] ) )
RETURN
DIVIDE ( _result, _allproduct )
ProductTerritoryCombination =
CROSSJOIN (
DISTINCT ( SalesData[ProductCode] ),
DISTINCT ( SalesData[Territory] )
)
Count Total Product-Territory Combinations: Create a measure to count the total number of product-territory combinations.
TotalProductTerritoryCombinations =
COUNTROWS ( ProductTerritoryCombination )
Count Actual Sales Combinations: Create a measure to count the actual number of product-territory combinations that have sales.
ActualProductTerritoryCombinations =
COUNTROWS (
SUMMARIZE (
SalesData,
SalesData[ProductCode],
SalesData[Territory]
)
)
Calculate the Difference: Create a measure to calculate the difference between the total possible combinations and the actual sales combinations.
MissingProductTerritoryCombinations =
[TotalProductTerritoryCombinations] - [ActualProductTerritoryCombinations]
Calculate the Percentage: Finally, create a measure to calculate the percentage of product codes that are not sold in all territories.
PercentageMissingProductTerritoryCombinations =
DIVIDE (
[MissingProductTerritoryCombinations],
[TotalProductTerritoryCombinations]
)
User | Count |
---|---|
25 | |
12 | |
8 | |
6 | |
6 |
User | Count |
---|---|
26 | |
12 | |
11 | |
9 | |
6 |