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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Days difference between when the first items and second item was purchased

Hey PBI Experts - I need help calculating the day difference between when customers purchase the first and second items.
e.g. - when a customer purchases a laptop for the first time and later comes back after some days or months to buy another item, am i trying to calculate the day difference between the first and second transaction dates?  Any idea, please...

3 ACCEPTED SOLUTIONS

Hi,

This calculated column formula works

Column = if(ISBLANK(CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date])))),0,Data[sales_date]-CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date]))))

Hope this helps.

Untitled.png


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

View solution in original post

Hi,

I am not sure how you arrived at those number - mine are different.  I just copied the same calculated column formula which i shared with you ealrier and it worked fine.  If you wish to include both days, just add 1

Column = if(ISBLANK(CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date])))),0,Data[sales_date]-CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date])))+1)

Have you even tried my formula?


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

View solution in original post

Anonymous
Not applicable

@Ashish_Mathur Thanks for the Dax Expression. We had to create a column in the warehouse to bring in another updated_date, and i used the expression you provided in PBI and tweaked it to include the new column, and it works! Thanks 🙌

View solution in original post

15 REPLIES 15
Anonymous
Not applicable

@Ashish_Mathur  - please see attached data link below with the expected output results. Thanks

Link to the Sample_Data  

Hi,

This calculated column formula works

Column = if(ISBLANK(CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date])))),0,Data[sales_date]-CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date]))))

Hope this helps.

Untitled.png


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

@Ashish_Mathur - Here is the attached data and expected result. Thanks
 

partner_keypartner_namesalesperson_keysales_datesalescurrency_keyvendor_keyvendor_namecustomer_keyproduct_keyquantityexpected_results_date_difNote:
206448htl30022/25/20230.06513564341cubic358989695650330first purchase
194440abc30592/19/202324.063564341microsoft352234725451030first purchase
194440abc30323/15/202303561236powerbi3557263654510252828 days diffrence from first purchase
189477bda31223/1/202388.223564444jira3583325854510110first purchase
189477bda31224/10/202348.123566666spring355616945451064141 days diffrence from first purchase
210782ccc31225/25/2023208.253565555aquafina355109205783950first purchase
210782ccc34826/20/20233.543567777hawatour352140795848412626 days diffrence from first purchase
Anonymous
Not applicable

You can try this measure for your desired output,

AverageVisits =
VAR CurrentDate =
    FIRSTDATE ( 'Table'[SaleDate] )
VAR NextDate =
    CALCULATE (
        MIN ( 'Table'[SaleDate] ),
        FILTER (
            ALLEXCEPT ( 'Table', 'Table'[Id] ),
            'Table'[SaleDate] > MIN ( 'Table'[SaleDate] )
        )
    )
VAR DateDiffference =
    DATEDIFF ( CurrentDate, NextDate, DAY )
RETURN
    IF(NextDate <> BLANK(), DateDiffference, 0)
This is the output I gotThis is the output I gotThis is the dataset that I've used.This is the dataset that I've used.
 

Hi,

I am not sure how you arrived at those number - mine are different.  I just copied the same calculated column formula which i shared with you ealrier and it worked fine.  If you wish to include both days, just add 1

Column = if(ISBLANK(CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date])))),0,Data[sales_date]-CALCULATE(MAX(Data[sales_date]),FILTER(Data,Data[partner_key]=EARLIER(Data[partner_key])&&Data[sales_date]<EARLIER(Data[sales_date])))+1)

Have you even tried my formula?


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

@Ashish_Mathur - Sorry, and thank you for your time. The logic you gave was helpful but still did not return the desired output. Here is how i have come about the number: The numbers in the expected result column are days dif, the days dif between when a partner makes their first purchase from one vendor and the second purchase from another vendor. That's what I am trying to achieve. I am trying to see the day's diff between when a partner makes a first and second purchase from a different vendor.  Thanks

WhyIsThis_0-1688610105767.png

 

Please see my post dated June 29.  The result there matches with your expected result.


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

@Ashish_Mathur - Thanks! I have a feeling that the DAX you provided will work, its returns the exact day's diff in the dataset i provided, but it's returning something different in the real dataset I am working on. I need to do some updates on the report dates. I will let you know the outcome. Thanks again

Anonymous
Not applicable

@Ashish_Mathur Thanks for the Dax Expression. We had to create a column in the warehouse to bring in another updated_date, and i used the expression you provided in PBI and tweaked it to include the new column, and it works! Thanks 🙌

You are welcome.


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

@Ashish_Mathur @Ahmedx @Ritaf1983 Thank you all for your professional input. Unfortunately, i tried all the suggested solutions and am still not getting the desired results. To give a live scenario of how my data looks. I have a partner buying from different vendors, i want to calculate the AVERAGE day's difference between the first and second or more purchases by unique partners from these different vendors. Any idea, please...

WhyIsThis_0-1687906724435.png

 



Hi,

Share some data to work with and show the expected result very clearly.


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

Ashish_Mathur
Super User
Super User

Hi,

Write this calculated column formula

Days lapsed since previous purchase = 1*(Data[Date]-calculate(max(data[date]),filter(Data,Data[Customer id]=earlier(Data[Customer id])&&Data[Date]<earlier(Data[Date]))))

Hope this helps.


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

Hi @Anonymous 
Try this measure :

Result_day =
var __atleast2day = COUNTROWS('Table')
var __dynam = TOPN(2, CALCULATETABLE('Table'), 'Table'[date], ASC)
var __first = maxx(__dynam, 'Table'[date])
var __second = minx(__dynam, 'Table'[date])
var __result = if(__atleast2day >1, __first - __second, 0)
return
__result
 
Ritaf1983_0-1687654176222.png

Link to a sample file 

If this post helps, then please consider Accepting it as the solution to help the other members find it more quickly

Regards,
Rita Fainshtein | Microsoft MVP
https://www.linkedin.com/in/rita-fainshtein/
Blog : https://www.madeiradata.com/profile/ritaf/profile

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.