Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
Hi All,
I used this post to determine how to filter to all data BEFORE the start of the current month in the Query Editor. (In other words, I wanted month-end, prior month data and older, and NOT any data for the current month.
Add a new Custom column:
=Date.StartOfMonth(DateTime.LocalNow())
Change to Date format.
Then filter the Date column we want to filter (e.g. order create date) like this
= Table.SelectRows(#"Changed Type1", each [Date] < [Custom])
I've also done this, which dynamically goes back two years, but how would I do this to go back to the start date of the prior fiscal year?:
#"Filtered Rows1" = Table.SelectRows(dbo_ServiceOrder, each [Create_Date] >= (Date.AddYears(List.Max(dbo_ServiceOrder[Create_Date]),-2))),
Is there a way to filter the data back to everything with the start of the prior fiscal year or later? That is, our fiscal year begins October 1, so how do I load data every month that dynamically looks back to the start of the prior fiscal year and loads everything beginning there and newer?
Hi @Shelley
Assume your fiscal year is as below:
year period
2017 2017/10/1 ~2018/9/30
2018 2018/10/1~2019/9/30
2019 2019/10/1~2020/9/30
"go back to the start date of the prior fiscal year"
If the prior fiscal year means:
1.
for today 2019/9/3, prior fiscal year is 2018, the period you expected is 2018/10/1~2019/8/31
#"Filtered Rows" =
Table.SelectRows(Table.AddColumn(#"Changed Type", "Custom.2", each if
[date] >=#date(if Date.Month(DateTime.LocalNow())<10
then Date.Year(DateTime.LocalNow())-1
else Date.Year(DateTime.LocalNow()),10,1)
and
[date]< DateTime.Date(Date.StartOfMonth(DateTime.LocalNow()))
then 1
else null),
each ([Custom.2] = 1)),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Custom.2"})
in
#"Removed Columns"
2.
for today 2019/9/3, prior fiscal year is 2017
the period you expected is 2017/10/1~2019/8/31
Change code above with below
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XdHLDcQgDATQXjhHCpiPcS1R+m8jLDC22esThJnJ84QU73RTTByukMJ7TSEIQTIkQwqkQCqkQhqkQRjCS9bjfUCfQAYrTXYQt9D/kQxYednurLjdYKUVg7ohR4iG1TN8DGNpMcxP5BjG5cUyk9IxzSQ6tpmU/TiiRcmA/DiiRfc2okX3NqJF2a40v41ozQER0iF6RiD60K45SJ/aNQcVJfLDi7UUi5zwc+xDI/T7AQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [date = _t, value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"date", type date}, {"value", Int64.Type}}),
#"Filtered Rows" = Table.SelectRows(Table.AddColumn(#"Changed Type", "Custom.2", each if [date] >=#date(if Date.Month(DateTime.LocalNow())<10 then Date.Year(DateTime.LocalNow())-2 else Date.Year(DateTime.LocalNow())-1,10,1) and [date]< DateTime.Date(Date.StartOfMonth(DateTime.LocalNow())) then 1 else null), each ([Custom.2] = 1)),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Custom.2"})
in
#"Removed Columns"
Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Check This
Thank you, but this doesn't address my ask. I'm looking for a way to filter records upon import into the query editor to dynamically filter for all records created since the start of the prior fiscal year. I want to filter out unneccesary records in order to minimize the data model.
This link is for calculating YTD values.
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!