Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi,
I want to create a condition column in Power Query that will calculate a new datetime with duration for me based on the date I specified in the condition. please check the SQL CASE when attached I wrote.
CASE
WHEN EXTRACT(HOUR FROM assigned_date) >= 8 AND EXTRACT(HOUR FROM assigned_date) < 16
THEN TIMESTAMP_TRUNC(TIMESTAMP(DATE(assigned_date)) + INTERVAL 1 DAY + INTERVAL 7 HOUR, HOUR)
WHEN EXTRACT(HOUR FROM assigned_date) >= 16 AND EXTRACT(HOUR FROM assigned_date) < 24
THEN TIMESTAMP_TRUNC(TIMESTAMP(DATE(assigned_date)) + INTERVAL 1 DAY + INTERVAL 13 HOUR, HOUR)
WHEN EXTRACT(HOUR FROM assigned_date) >= 0 AND EXTRACT(HOUR FROM assigned_date) < 8
THEN TIMESTAMP_TRUNC(TIMESTAMP(DATE(assigned_date)) + INTERVAL 13 HOUR, HOUR)
END AS outbound_compliance_date,
What this does is to calcalute a new date when the assigned_date is between 8am and 4pm then it should return a column byu adding 1 day and 7hrs to the assigned_date (i.e 6/11/2024 07:45AM output: 6/12/2024 07:00AM)
Thanks.
Solved! Go to Solution.
let
Source = #table(
{"assigned_date"},
{{#datetime(2024, 06, 11, 7, 45, 0)},
{#datetime(2024, 06, 11, 11, 30, 0)},
{#datetime(2024, 06, 11, 22, 15, 0)}}
),
compliance_date = Table.AddColumn(
Source,
"outbound_compliance_date",
each
[check_time = Number.IntegerDivide(Time.Hour(Time.From([assigned_date])), 8 ),
calc_date = Date.From([assigned_date]) & #time(0, 0, 0) +
#duration(
Number.From(check_time > 0),
13 - 6 * Number.From(check_time = 1),
0, 0
)][calc_date]
)
in
compliance_date
Date.From(assigned_date) & #time(0, 0, 0) +
#duration(
Number.From(Number.IntegerDivide(Time.Hour(Time.From(assigned_date)), 8 ) > 0),
13 - 6 * Number.From(Number.IntegerDivide(Time.Hour(Time.From(assigned_date)), 8 ) = 1),
0, 0
)
let
Source = #table(
{"assigned_date"},
{{#datetime(2024, 06, 11, 7, 45, 0)},
{#datetime(2024, 06, 11, 11, 30, 0)},
{#datetime(2024, 06, 11, 22, 15, 0)}}
),
compliance_date = Table.AddColumn(
Source,
"outbound_compliance_date",
each
[check_time = Number.IntegerDivide(Time.Hour(Time.From([assigned_date])), 8 ),
calc_date = Date.From([assigned_date]) & #time(0, 0, 0) +
#duration(
Number.From(check_time > 0),
13 - 6 * Number.From(check_time = 1),
0, 0
)][calc_date]
)
in
compliance_date
Hello @Mubar22,
If my post helped you, please give me a 👍kudos and mark this post with Accept as Solution.
I'm not entirely sure I followed your logic. But the following code will definitely help you. Feel free to get in touch if you have any questions.
ColumnAssignedDateCorrected = Table.AddColumn(PreviousStep, "AssignedDateCorrected", each
if Time.Hour([assigned_date]) >= 8 and Time.Hour([assigned_date]) < 16
then Date.AddDays([assigned_date],1) + #duration(0,7,0,0)
else if Time.Hour([assigned_date]) >=16 and Time.Hour([assigned_date]) < 24
then Date.AddDays([assigned_date],1) + #duration(0,13,0,0)
else if Time.Hour([assigned_date]) >=0 and Time.Hour([assigned_date]) < 8
then [assigned_date] + #duration(0,13,0,0)
else null)
Best regards from Germany
Manuel Bolz
🟦Follow me on LinkedIn
🟨How to Get Your Question Answered Quickly
🟩Fabric Community Conference
🟪My Solutions on Github
Hi @ManuelBolz
Thank you! These provides heads up but it didn't meet the need.
Here is the output
But this is what I'm trying to achieve exactly.
Thank you for the help. I hope this provide more context.
Hello @Mubar22,
Sorry, I'm not that strong in SQL. I must have misunderstood your query. Maybe @AlienSx solution is a better fit. Otherwise I would tackle your problem again later.
Best regards from Germany
Manuel Bolz
🟦Follow me on LinkedIn
🟨How to Get Your Question Answered Quickly
🟩Fabric Community Conference
🟪My Solutions on Github
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
68 | |
64 | |
27 | |
18 | |
13 |