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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
parry2k
Super User
Super User

Customer purchased more than 1 distinct product

Hello,

 

I have very simple data set, order, customer, product.

 

Order is linked to customer and product on customer id and product id and also date dimension

 

Each customer and product table has their internal unique number, called customer number and product number which is different than id.

 

Question is to find out how many distinct customers (based on customer number) purchased more than one product based on product number not based on the ID in a specific period filtered by date. Also need to include product where product flag = 'Y'

 

sample data set is attached for reference.

 

 

 

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

1 ACCEPTED SOLUTION

Here is what final solution looks like:

 

- I have unique record for customer number and product number 

- Linked sales table with customer number and product number instead of customer id and product id

- used following dax to get the result:

 

Customer Purchased more than 1 product = 
COUNTROWS(
    FILTER('customer', 
        CALCULATE(
            DISTINCTCOUNT(sale[productnumber]),
            FILTER(product,
               product[product_flag] <> "N"
            )
        ) > 1 
    )
)


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

12 REPLIES 12
Ashish_Mathur
Super User
Super User

Hi,

 

What is your expected answer?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thanks @Phil_Seamark @Vvelarde

 

Will check it and get back to you guys.

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

@Phil_Seamarkone thing we are missing your expression is that we need to take distinct count of customer number and product number not customer id and product id, although order table is linked on customer id and product id. Hope it is clear.

 

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Hi @parry2k

 

These should still produce the same result, possibly sligtly faster by not needing to use the relationship for the calc.

 

If it is still slow, I suggest an aggregate table as the basis for the measures and slicers for this one


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Also I try to test the solution against my production datbase which has 1.7 mil rows, it is very slow, kind of not even possible to use.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Vvelarde
Community Champion
Community Champion

@parry2k

 

HI, i had a very similar way to Phil.

 

Morethan1ProductBuyed =
SUMX (
    SUMMARIZE (
        Customer;
        Customer[Customer number];
        "dc"; CALCULATE (
            DISTINCTCOUNT ( 'Product'[Product number] );
            FILTER ( 'Product'; 'Product'[Product Flag] = "Y" )
        )
    );
    IF ( [dc] > 1; 1; 0 )
)

Let me see if works in your scenario

 

Regards

 

Victor

 




Lima - Peru

Hi @Vvelarde

 

I think this one might be slightly quicker again (based on some local testing).

 

It uses SUMMARIZECOLUMNS instead of SUMMARIZE and gets rid of the need for a distinct count.  It still uses 2 iterators and without seeing the actual data it makes it a little tricky to optimise further.   

 

I'd make a calculated table over the 1.7 million rows (if possible) to bring the table down to the lowest grain needed for where ever the measure is going to be used.  Shift as much of the processing into the data load, and leave the calculated measure with the absolutely smallest table it can to work with.

 

Measure 2 = 
    COUNTROWS(
        FILTER(
            SUMMARIZECOLUMNS(
                'Order'[Customer Id],
                FILTER(
                    'Product',
                    'Product'[Product Flag]="Y"
                    ),
                "Max",MAX('Order'[Product Id]),
                "Min",MIN('Order'[Product Id])
                ),
                [Max]<>[Min]
                )
            )

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Thanks @Phil_Seamark I wil try the 2nd measure, I always thinking about creating a calculated table in PowerbI or at semantic layer to overcome the performance issue but at the same time I wanted to see what you experts think of using measure and if that can be avoided.

 

Anyhow I will test it and see if it is better.

 

Cheers,

P



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

HI @parry2k

 

Measures are great and help make Power BI fantastic by being dynamic.  But they come with a processing cost to the end user experience.  This is fine in most scenarios, but if your datasets grow then it's time to see how the underlying model can be structured to minimise the amount of work required for each measure.

 

Remember, every data point or value shown on the report canvas is an execution of a calculated measure. 


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

@Phil_SeamarkStill working on it, I'm doing mix of things, optimize semantic layer and improve on DAX, will post which solution I land up on.

 

Thanks,

P



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Here is what final solution looks like:

 

- I have unique record for customer number and product number 

- Linked sales table with customer number and product number instead of customer id and product id

- used following dax to get the result:

 

Customer Purchased more than 1 product = 
COUNTROWS(
    FILTER('customer', 
        CALCULATE(
            DISTINCTCOUNT(sale[productnumber]),
            FILTER(product,
               product[product_flag] <> "N"
            )
        ) > 1 
    )
)


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Phil_Seamark
Employee
Employee

Hi @parry2k

 

If I have understood you properly I think this calculated measure gets close.

 

This will display the unique number of customers who have purchased 2 or more products in the time range.  Based on your dataset, I get 9 (with no date filter).  Is that what you are after?

 

 

Measure = 
VAR T1 = 
    SUMMARIZE(
        FILTER('Order',RELATED('Product'[Product Flag])="Y"),
-- Group by --- [Customer Id] ,
-- Count distinct products per customer "Distinct Products Purchased" , DISTINCTCOUNT('Order'[Product Id]) ) RETURN COUNTAX( FILTER( T1, [Distinct Products Purchased]>1
), [Customer Id] )

 


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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