Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Shelley
Continued Contributor
Continued Contributor

How to Dynamic Filter in Query Editor with Fiscal year start

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])

 

From <https://community.powerbi.com/t5/Desktop/How-to-Calculate-the-first-day-of-the-Month-in-Power-Query/...>

 

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?

3 REPLIES 3
v-juanli-msft
Community Support
Community Support

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

Capture13.JPG

#"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.

amitchandak
Super User
Super User
Shelley
Continued Contributor
Continued Contributor

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.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.