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
Hello,
I'm learning Power Query and I'm having an issue trying to use a simple filter. I have a current table with a column called ValidTo. In TSQL I could filter this column to only return the records that were >= GETDATE() (greater than or equal to what the date is at run time). I am trying to accomplish the same result in Power Query but I am not able to find which function to use. I was revewing https://msdn.microsoft.com/en-us/library/mt296608.aspx but was unable to determine which function returns the current datetime value when it's refreshed. I've tried TODAY(), GETDATE(), NOW() all with no luck (ignore the before or equal to). This seems like a simple thing to do so I must be missing where the function is.
Any help? Thank you.
Solved! Go to Solution.
Power Query does not use DAX formulas. It has its own language. TODAY() is not a valid formula in that language.
Also that dialog box will only allow literal date values, not formulas that evaluate to a date. But you can get past that. Type some date into that box and hit OK. It doesn't matter what date you enter because you're just using it to get out of the dialog box with a valid formula, after which you're going to replace it. After you hit OK look up at the formula bar for the step you just inserted. You should see something like:
= Table.SelectRows(#"Name of Previous Step", each [VALIDTO] <= #datetime(2016, 9, 12, 0, 0, 0))
Replace the end of that formula with DateTime.LocalNow() which is the Power Query nearest equivalent to TODAY()*.
= Table.SelectRows(#"Name of Previous Step", each [pafo_EstimatedEndDate] <= DateTime.LocalNow())
...or you could just go to the advanced editor and type in that step by hand if you know how to hand-code a new step.
*Technically it returns a Date/Time value, where TODAY() returns a Date value. The literal closest to TODAY() is Date.From(DateTime.LocalNow()) which you should use rather than DateTime.LocalNow() alone if the column you're filtering is already a plain date type rather than date/time.
Proud to be a Super User!
I was trying to do something similar and the logic or syntax may apply. I was trying to limit my TCdate (timecard date) to any date prior to today. I used this in Power Query and it worked: = Table.SelectRows(#"Filtered Rows", each [TCdate] < List.Max(#"Filtered Rows"[TCdate]))
I was trying to do something similar and the logic or syntax may apply. I was trying to limit my TCdate (timecard date) to any date prior to today. I used this in Power Query and it worked: = Table.SelectRows(#"Filtered Rows", each [TCdate] < List.Max(#"Filtered Rows"[TCdate]))
This one really worked for me, give a try
What if I need the dau before my current date? (yesterday)
I tried using Date.From(DateTime.LocalNow()) -1 but I get the following error:
Expression.Error: Não conseguimos aplicar o operador - aos tipos Date e Number.
Detalhes:
Operator=-
Left=29/01/2020
Right=1
Thanks!
@bisah Date.From(Date.AddDays(DateTime.LocalNow(), -1)) ought to do it.
Proud to be a Super User!
Power Query does not use DAX formulas. It has its own language. TODAY() is not a valid formula in that language.
Also that dialog box will only allow literal date values, not formulas that evaluate to a date. But you can get past that. Type some date into that box and hit OK. It doesn't matter what date you enter because you're just using it to get out of the dialog box with a valid formula, after which you're going to replace it. After you hit OK look up at the formula bar for the step you just inserted. You should see something like:
= Table.SelectRows(#"Name of Previous Step", each [VALIDTO] <= #datetime(2016, 9, 12, 0, 0, 0))
Replace the end of that formula with DateTime.LocalNow() which is the Power Query nearest equivalent to TODAY()*.
= Table.SelectRows(#"Name of Previous Step", each [pafo_EstimatedEndDate] <= DateTime.LocalNow())
...or you could just go to the advanced editor and type in that step by hand if you know how to hand-code a new step.
*Technically it returns a Date/Time value, where TODAY() returns a Date value. The literal closest to TODAY() is Date.From(DateTime.LocalNow()) which you should use rather than DateTime.LocalNow() alone if the column you're filtering is already a plain date type rather than date/time.
Proud to be a Super User!
I have been trying to figure this out for a while now. Thank you for making it so easy to figure out and understand!
That's great, thank you this worked for me. It does seem strange to me that we have IsInCurrentDay but not IsBeforeCurrentDay, I suppose they can't think of everything 🙂
Hi, This solution does not seem to work for me as I get the following error:
No, ignore me I'm being dim. If course you cant compare Date with DateTime. I changed the Date field to DateTime and presto!
hi i am looking get data between 91-180, 181-270, 271-365 days from the current date. could you please help in doing so. looking for something similar to "in the previous...days" function would really appreciate the help
This is exactly what I was looking for! I understood it uses M language but didn't realize you couldn't type the formula into the dialog box (TODAY() was just an example, I had tried DateTime.LocalNow() but that didn't work either). I am going to request this functionality to be added as it would seem more intuitive and user friendly to be able to build it on the fly rather than the solution you've provided.
Thank you very much for this helpful information!
You can add this idea on ideas site. And if KHorseman’s solution is exactly what you are looking for, you can mark his answer as solution to close this thread.
Best Regards,
Herbert
Done and Done! Thank you again!
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 |
---|---|
113 | |
91 | |
84 | |
76 | |
65 |
User | Count |
---|---|
145 | |
109 | |
109 | |
102 | |
96 |