Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreShape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.
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.
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:
Can someone explain what is wrong with my query that the isSummerTime statement is not working properly?
Solved! Go to Solution.
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
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
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.
I tried it with + instead of & and it also doesn't work for a different reason:
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
User | Count |
---|---|
25 | |
13 | |
12 | |
11 | |
8 |
User | Count |
---|---|
44 | |
27 | |
19 | |
16 | |
12 |