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
rax99
Helper V
Helper V

How to convert SQL windowed function to DAX

I have this table:

NormalisedDayNoCustomerDate
0A02/09/2018
24A26/09/2018
0B21/09/2018
4B25/09/2018
0C17/09/2018
8C25/09/2018
9C26/09/2018
9C26/09/2018
0D09/09/2018

 

In SQL worked out the NDayNo. by doing following calc

COALESCE(DATEDIFF(day,FIRST_VALUE(Date) OVER (PARTITION BY Customer ORDER By Date),Date),0)

NDayNo. = So Im working out the first time the customer contacts in the month (=0) and then how many days until next time they contact.

 

How do I calculate this as a DAX query?

1 ACCEPTED SOLUTION

You can create the below calculated column:

NDayNo. =
VAR CurrentCustomer = 'Table'[Customer]
VAR CurrentDate = 'Table'[Date]
VAR FirstDayofCustomer =
    CALCULATE (
        MIN ( 'Table'[Date] ),
        'Table'[Customer] = CurrentCustomer,
        ALL ( 'Table' )
    )
RETURN
    DATEDIFF ( FirstDayofCustomer, CurrentDate, DAY )

View solution in original post

3 REPLIES 3
AkhilAshok
Solution Sage
Solution Sage

If you just want a measure, you could do somethng like this:

 

NDayNo = 
VAR CurrentCustomer =
    MAX ( 'Table'[Customer] )
VAR CurrentDate =
    MAX ( 'Table'[Date] )
VAR FirstDayofCustomer =
    CALCULATE (
        MIN ( 'Table'[Date] ),
        'Table'[Customer] = CurrentCustomer,
        ALL ( 'Table')
    )
RETURN
    DATEDIFF ( FirstDayofCustomer, CurrentDate, DAY )

Thanks, Is there anyway to calculate this as a calc column?

 

Reason being I need to store the value at row level, and for it to dynamically change based on filters applied.

You can create the below calculated column:

NDayNo. =
VAR CurrentCustomer = 'Table'[Customer]
VAR CurrentDate = 'Table'[Date]
VAR FirstDayofCustomer =
    CALCULATE (
        MIN ( 'Table'[Date] ),
        'Table'[Customer] = CurrentCustomer,
        ALL ( 'Table' )
    )
RETURN
    DATEDIFF ( FirstDayofCustomer, CurrentDate, DAY )

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