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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Customer's first order date measure tuning

I developed the following measure in order to report on the customer first order date, using publicly available Contoso data model. I want to put this measure on the table visual with the granularity of order.

 

Here is the code:

DEFINE
    MEASURE customer[FirstOrderDate] =
        CALCULATE (
            MIN ( Sales[Order Date] ),
            FILTER (
                ALL (Sales),
                Sales[CustomerKey] = SELECTEDVALUE ( sales[CustomerKey] )
            )
        )
EVALUATE
SUMMARIZECOLUMNS (
    Customer[CustomerKey],
    Sales[Order Number],
    FILTER ( customer, Customer[CustomerKey] = 6 ),
    "FirstOrderDate", [FirstOrderDate]
)

It produce the correct values for a filtered customer. However, when I run this against full customer base, it throws a timeout. Any idea on how to improve the measure so it could calculate succesfully, without timeouts?

 

kamilzet___0-1618657262766.png

 

Link to DAX.DO: https://dax.do/wxU6NNRHrencrg/

 

1 ACCEPTED SOLUTION
daxer-almighty
Solution Sage
Solution Sage

 

DEFINE
    MEASURE Customer[FirstOrderDate] =
        CALCULATE (
            MIN ( Sales[Order Date] ),
            // This works for any set of customers
            // not only one. If there is a set of
            // customers visible in the current context
            // the date of the first order for the
            // whole set of customers is returned.
            VALUES ( Sales[CustomerKey] ),
            ALL ( )
        )
EVALUATE
    SUMMARIZECOLUMNS (
        Customer[CustomerKey],
        Sales[Order Number],
        "FirstOrderDate", [FirstOrderDate]
    )

Piece of advice: NEVER, ever filter a table if you can filter a column. To know why this is so, please grab yourself the book "The Definitive Guide to DAX" by The Italians and read.

 

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

@daxer-almighty It works super-fast. However, it's still not clear to me, as your measure definition looks totally different then mine - may I ask you for additional explanation on how this measure actually evaluates?

@Anonymous 

 

You should start reading the articles on www.sqlbi.com if you want to know how to write correct and fast DAX. There is no better way and, in fact, no OTHER way (apart from their book). I've read this book "The Definitive Guide to DAX" by Marco Russo and Alberto Ferrari at least 4 times, cover to cover. I'd suggest you do the same if you dare 🙂 (But that's what has made me a DAX guru).

 

How does my measure work? It's rather a simple formula but it takes a tiny bit of knowledge to do it. 

DEFINE
    MEASURE Customer[FirstOrderDate] =
        CALCULATE (
            MIN ( Sales[Order Date] ),
            // VALUES ( Sales... ) gets the currently
            // visible customer keys in Sales and re-applies
            // them after ALL ( ) has got rid of all
            // the other filters. This is how you make sure
            // that your measure only calculates in a different
            // filter context, one where only the column Sales[CustomerKey]
            // has a filter on it.
            VALUES ( Sales[CustomerKey] ),
            // The directive ALL ( ) removes ALL
            // FILTERS from the model.
            ALL ( )
        )
....

 

Anonymous
Not applicable

@daxer-almighty One additional question regarding discussed topic - As a given customer could be given different Customer IDs in my data setup (due to SCD), I wanted to replace:

VALUES(Sales[CustomerKey])

 with

Values(Customer[CustomerEmail])

but then measure slowed down drastically. Could you please advice me on how to achieve this. I imagine I need some sort of LOOKUPVALUE, that should be passed to VALUES(), however VALUES() does not accept expression as a parameter. Thanks in advance for your help!

daxer-almighty
Solution Sage
Solution Sage

 

DEFINE
    MEASURE Customer[FirstOrderDate] =
        CALCULATE (
            MIN ( Sales[Order Date] ),
            // This works for any set of customers
            // not only one. If there is a set of
            // customers visible in the current context
            // the date of the first order for the
            // whole set of customers is returned.
            VALUES ( Sales[CustomerKey] ),
            ALL ( )
        )
EVALUATE
    SUMMARIZECOLUMNS (
        Customer[CustomerKey],
        Sales[Order Number],
        "FirstOrderDate", [FirstOrderDate]
    )

Piece of advice: NEVER, ever filter a table if you can filter a column. To know why this is so, please grab yourself the book "The Definitive Guide to DAX" by The Italians and read.

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors