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
onlycallisto
New Member

Timezone conversion issues in PowerQuery

Hi, I am having essentially this same problem, but the solution from this post is not working for me: 
https://community.fabric.microsoft.com/t5/Power-Query/Convert-Date-Time-in-UTC-to-Local-Time-with-Da...

PowerBI is interpreting our UTC data as actually being local, which is incorrect, so I can't just use the converto to local time function.

onlycallisto_0-1719184607625.png

So I need to manually update the times to either +12 or +13 hours (NZ)  depending on the time of year due to daylight savings. 
Here is the M query I have tried to use: 

 

(datetimecolumn as datetime) =>

let

date = DateTime.Date(datetimecolumn),
time = DateTime.Time(datetimecolumn),
ForwardDate = Date.StartOfWeek(#date(Date.Year(date), 9, 30), Day.Sunday),
BackDate = Date.StartOfWeek(#date(Date.Year(date), 4, 7), Day.Sunday),

isSummerTime =
		(date = ForwardDate and time >= #time(2,0,0))
	    or
		(date > ForwardDate and date < BackDate) 
		or 
		(date = BackDate and time < #time(2,0,0)),

timeZone = 12 + Number.From(isSummerTime),

NZ_time = 
            DateTime.From(date) 
            + #duration(0,Time.Hour(time),Time.Minute(time),Time.Second(time))  
            + #duration(0, timeZone, 0, 0)

in
    NZ_time


When I use this, it seemed to just add 12 hours to everything. I played around with it, and there seems to be an issue with the isSummerTime variable, it only returns TRUE when it is exactly the ForwardDate: 

onlycallisto_2-1719184957299.png

Can someone explain what is wrong with my query that the isSummerTime statement is not working properly?

1 ACCEPTED SOLUTION
onlycallisto
New Member

I've figured it out! 
It's because NZ summer wraps around the new year. 

So I need to calculate WinterTime instead and adjust the calculation like so: 

(datetimecolumn as datetime) =>

let

date = DateTime.Date(datetimecolumn),
time = DateTime.Time(datetimecolumn),
ForwardDate = Date.StartOfWeek(#date(Date.Year(date), 9, 30), Day.Sunday),
BackDate = Date.StartOfWeek(#date(Date.Year(date), 4, 7), Day.Sunday),

isWinterTime =
		(date = BackDate and time >= #time(2,0,0))
	    or
		(date > BackDate and date < ForwardDate) 
		or 
		(date = ForwardDate and time < #time(2,0,0)),

timeZone = 13 - Number.From(isWinterTime),

NZ_time = 
            DateTime.From(date) 
            + #duration(0,Time.Hour(time),Time.Minute(time),Time.Second(time))  
            + #duration(0, timeZone, 0, 0)

in
    NZ_time

View solution in original post

5 REPLIES 5
onlycallisto
New Member

I've figured it out! 
It's because NZ summer wraps around the new year. 

So I need to calculate WinterTime instead and adjust the calculation like so: 

(datetimecolumn as datetime) =>

let

date = DateTime.Date(datetimecolumn),
time = DateTime.Time(datetimecolumn),
ForwardDate = Date.StartOfWeek(#date(Date.Year(date), 9, 30), Day.Sunday),
BackDate = Date.StartOfWeek(#date(Date.Year(date), 4, 7), Day.Sunday),

isWinterTime =
		(date = BackDate and time >= #time(2,0,0))
	    or
		(date > BackDate and date < ForwardDate) 
		or 
		(date = ForwardDate and time < #time(2,0,0)),

timeZone = 13 - Number.From(isWinterTime),

NZ_time = 
            DateTime.From(date) 
            + #duration(0,Time.Hour(time),Time.Minute(time),Time.Second(time))  
            + #duration(0, timeZone, 0, 0)

in
    NZ_time
lbendlin
Super User
Super User

You should know when DST starts and ends for your location. Use these datetimes for the cutoff.

 

Or - preferably - do everything in UTC always, and then let the report user's browser do the conversion.

But I have put in the DST dates for my location - I've defined them in the ForwardDate and BackDate fields. 

But for some reason the isSummerTime function is only returning TRUE if the date is exactly the ForwardDate, as if it is only reading the first expression in its definition and ignoring all the or's and and's. 

I can't work in UTC if PowerQuery is interpreting my dates as being in NZ time instead of UTC. It's importing them incorrectly so I have to fix it manually. 

isSummerTime =
		(datetimecolumn > ForwardDate & #duration(0,2,0,0))
	    		or 
		(datetimecolumn < BackDate & #duration(0,2,0,0)),

That doesn't work, they're not compatible.

onlycallisto_0-1719187450650.png

I tried it with + instead of & and it also doesn't work for a different reason: 

onlycallisto_1-1719187594656.png



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