Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Solved! Go to Solution.
Hi @DCrowther
Please see the below DAX expressions.
1 This address your requirement and will also address the issue with hard coded year.
Payment Month Count = VAR _NextSheduledDate = 'Table'[Next Scheduled Payment] VAR _NextSheduledYear = YEAR( _NextSheduledDate ) VAR _TaxCutoffDate = IF( DATE( _NextSheduledYear, 4, 5 ) > _NextSheduledDate, DATE( _NextSheduledYear, 4, 5 ), DATE( _NextSheduledYear + 1, 4, 5 ) ) VAR _DateDiff = DATEDIFF( _NextSheduledDate, _TaxCutoffDate, MONTH ) RETURN _DateDiff + IF( DAY( _NextSheduledDate ) <= 5, 1, 0 )
2 Version with hard coded Year
Payment Month Count = VAR _NextSheduledDate = 'Table'[Next Scheduled Payment] VAR _DateDiff = DATEDIFF( _NextSheduledDate, DATE( 2020, 4, 5 ), MONTH ) RETURN _DateDiff + IF( DAY( _NextSheduledDate ) <= 5, 1, 0 )
Sorry, i didnt get to explain the content of my query
I am looking to calculat the number of months between a start date (payment date) and the the end date (end date being UK Tax year of 5/4/2020)
However there are set different start dates (Payment Date) so for example, so may be on on the 1st of the month, some maybe on 15th of the month and some on the 25th, however the DAX DATEDIFF function may result in a slight mis-calculation of payment months remaining depending on the start, can anyone help with this?
I have included below an excel formula that actually works so i am looking for the DAX equivalent
=MONTH(F5)-MONTH(E5)+12*(YEAR(F5)-YEAR(E5))+IF(DAY(F5)>=DAY(E5),1,0)
Regards
Dan
Hi @DCrowther
Can you creater a small data sample + expected result?
Hi Mariusz
Above is the two examples, first image shows how PBI is resulting in a 7 month count no matter if the start date is on the 1st, 15th or 25th. The second image shows how excel can give a different month number calc of 8, depending if the day of the month changes. 8 months should be the correct output.
Hope this helps
Regards
Dan
Hi @DCrowther
Please see the below DAX expressions.
1 This address your requirement and will also address the issue with hard coded year.
Payment Month Count = VAR _NextSheduledDate = 'Table'[Next Scheduled Payment] VAR _NextSheduledYear = YEAR( _NextSheduledDate ) VAR _TaxCutoffDate = IF( DATE( _NextSheduledYear, 4, 5 ) > _NextSheduledDate, DATE( _NextSheduledYear, 4, 5 ), DATE( _NextSheduledYear + 1, 4, 5 ) ) VAR _DateDiff = DATEDIFF( _NextSheduledDate, _TaxCutoffDate, MONTH ) RETURN _DateDiff + IF( DAY( _NextSheduledDate ) <= 5, 1, 0 )
2 Version with hard coded Year
Payment Month Count = VAR _NextSheduledDate = 'Table'[Next Scheduled Payment] VAR _DateDiff = DATEDIFF( _NextSheduledDate, DATE( 2020, 4, 5 ), MONTH ) RETURN _DateDiff + IF( DAY( _NextSheduledDate ) <= 5, 1, 0 )
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
112 | |
93 | |
89 | |
35 | |
35 |
User | Count |
---|---|
154 | |
102 | |
82 | |
64 | |
54 |