Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon'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.
Hi!
I am having troubles with calculating the maximum difference between two consecutive purchases for each customer. Note that this is not the same as date difference between first and last purchase.
I have two tables (Purchase_table and Customer_table) which are related via CustomerID. In the Purchase_table the same CustomerID's are existing multiple times. As shown in the example pictures, I would like to calculate values for the column Max_diff_betw_purch. In the example I manually inputted value "8" for customer "1001", since it is the date difference between his second and third purchase, which is bigger than the difference between his first and second purchase.
Any help with this? I would prefer to do this with Power BI Desktop in data mode by adding a new column (Max_diff_betw_purch).
Sincerely,
L
Solved! Go to Solution.
You can use this column in the Customers Table
Max_diff_between_Purchase = VAR temp = CALCULATETABLE ( VALUES ( Purchase_table[PurchaseDate] ) ) VAR temp1 = ADDCOLUMNS ( temp, "Days", DATEDIFF ( [PurchaseDate], MINX ( FILTER ( temp, [PurchaseDate] > EARLIER ( [PurchaseDate] ) ), [PurchaseDate] ), DAY ) ) RETURN MAXX ( temp1, [Days] )
Please see attached file with your sample data
You can use this column in the Customers Table
Max_diff_between_Purchase = VAR temp = CALCULATETABLE ( VALUES ( Purchase_table[PurchaseDate] ) ) VAR temp1 = ADDCOLUMNS ( temp, "Days", DATEDIFF ( [PurchaseDate], MINX ( FILTER ( temp, [PurchaseDate] > EARLIER ( [PurchaseDate] ) ), [PurchaseDate] ), DAY ) ) RETURN MAXX ( temp1, [Days] )
Perfect, thank you Zubair! Your column worked like a charm.
I really appreciate the help!
-L
Please see attached file with your sample data
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
143 | |
85 | |
66 | |
51 | |
45 |
User | Count |
---|---|
216 | |
89 | |
82 | |
66 | |
57 |