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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
AshwiniPulipat
Frequent Visitor

Need help in writing DAX query formula

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

AshwiniPulipat_0-1719143685478.png

Thank you

2 ACCEPTED SOLUTIONS
Jihwan_Kim
Super User
Super User

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.

Jihwan_Kim_1-1719145105763.png

 

 

 

Jihwan_Kim_0-1719145078394.png

 

 

% 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 )

 

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.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

View solution in original post

v-xingshen-msft
Community Support
Community Support

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 )

vxingshenmsft_0-1719302004160.png

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.

 

View solution in original post

3 REPLIES 3
v-xingshen-msft
Community Support
Community Support

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 )

vxingshenmsft_0-1719302004160.png

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.

 

Jihwan_Kim
Super User
Super User

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.

Jihwan_Kim_1-1719145105763.png

 

 

 

Jihwan_Kim_0-1719145078394.png

 

 

% 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 )

 

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.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

aduguid
Super User
Super User

  • Create a Calculated Table: First, create a calculated table that lists all the unique combinations of product codes and territories.

 

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]
)

 

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.

Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

Find out what's new and trending in the Fabric community.