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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
bparikh
Regular Visitor

Date difference in Months - Power Query

Hello Experts,

 

I've two DateTime columns and am trying to find the difference in Months by adding a new column but getting an error.

I'm using = Date.Month ([Date1] - [Date2])

Date1 & Date2 both are - DateTime format

 

The erros is mentioned below,

Expression.Error: The Date value must contain the Date component.
Details:
974.00:00:00

 

Any help will be really appreciated.

 

Thanks in advance.

1 ACCEPTED SOLUTION
Fowmy
Super User
Super User

@bparikh 

if you need the number of months between the dates then add the following, it should work for Date/Time

 = Number.Round(Number.From(([Date 2] - [Date 1])/( 365.25 / 12 )) ,0 )

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

View solution in original post

9 REPLIES 9
LeTapia
New Member

What about this function

(Date1 as date , Date2 as date)=>
let
    Source =
            List.Generate(
                () => [y=Date.From(Date1)],
                each [y] <= Date.From(Date2),
                each [y = Date.AddMonths([y] ,1)],
                each [y]
            ),
    Months=List.Count(Source)
in
    Months
lbendlin
Super User
Super User

The correct answer is 

 

Date.Year([Date2])*12+Date.Month([Date2])-Date.Year([Date1])*12-Date.Month([Date1])
Atulnnnn
New Member

I want to calculate datediff, for example if start date is 4may and end date is 4june then if I select may month it should return days only from 4may to31 may, if I select June it should give 1june to 4june only. Please help me with this, 

rmsolfest
Advocate I
Advocate I

This is a little late response, but some may still find it helpful.

 

These can be standard columns in one's common date table for easy reference, filtering & and calculating offsets (including month difference).

diff_Year = [Year] - Date.Year( DateTime.LocalNow() )


diff_Month = 12 * ( [Year] - Date.Year( DateTime.LocalNow() ) ) + [Month Number] - Date.Month(DateTime.LocalNow())

Fowmy
Super User
Super User

@bparikh 

if you need the number of months between the dates then add the following, it should work for Date/Time

 = Number.Round(Number.From(([Date 2] - [Date 1])/( 365.25 / 12 )) ,0 )

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Wow - it worked ! Thanks a lot Fowmy.

 

Just curious, what was wrong in my approach. 

Subtracting dates in Power Query doesn't return days @bparikh - it returns a duration, that is why I used the Duration function in my solution. Fowmy converted the dates to numbers (same numbers you'd see in Excel with an unformatted date) to do the days. You should check out the Duration functions like Duration.TotalDays I used. They are a bit more flexible when a time component comes in, and can be very powerful. Also helps you understand how Power Query handles dates, times, and the differences between them.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
edhans
Super User
Super User

There is no Power Query function like DATEDIFF in DAX, so there are at least two ways to approach this.

 

= Duration.TotalDays(Duration.From([Date2] - [Date1]))

 

That would return the total days. You could then do something like:

 

= Number.IntegerDivide( TheTotalDays, 30)

 

That would give you an approximation of the months. 

If you want to count the actual months, you could do this:

 

                let
                    varTimePeriod1 = Date.Year([Date1]) * 100 + Date.Month([Date1]),
                    varTimePeriod2 = Date.Year([Date2]) * 100 + Date.Month([Date2])
                in
                varTimePriod2 - varTimePeriod1

 

That would turn May 1, 2021 to 202105, and August 15, 2021 to 202108. Then 202108-202105 = 3 months.

But note that it would also return 1 month for a June 30 and July 1 date difference, and 0 months for June 1 and June 30, so it depends on your scenario as to whether the counting days in the first example or just the year/month combo is more relevant to your situation.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

This was a great solution, but didn't quite work for me. I made a slight modification for my needs.

With the provided code, there were some issues when comparing a date in Dec to a date in Jan. I wanted those to show up as only 1 month difference.

So instead I calculated the number of months since the year 0, and subtracted the difference between those.


let
today = Date.From(DateTime.LocalNow()),
varTimePeriod1 = Date.Year(today) * 12 + Date.Month(today),
varTimePeriod2 = Date.Year([Date]) * 12 + Date.Month([Date])

in
varTimePeriod2 - varTimePeriod1

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.

Top Solution Authors