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
Anonymous
Not applicable

power query on how to choose selective rows according to date

hihi profs,

 

 need help on power query to choose rows... how to choose all date for the current month and max date for previous months

 

meaning to choose 12/07/2020, 12/14/2020, 12/21/2020, and 11/30/2020, 10/26/2020 and so on in this table

Index

1/13/2020
1/20/2020
1/28/2020
2/10/2020
2/24/2020
3/9/2020
3/23/2020
3/30/2020
4/6/2020
4/13/2020
4/20/2020
4/27/2020
5/4/2020
5/11/2020
5/18/2020
5/25/2020
6/1/2020
6/8/2020
6/15/2020
6/22/2020
6/29/2020
7/6/2020
7/13/2020
7/20/2020
7/27/2020
8/3/2020
8/10/2020
8/17/2020
8/24/2020
8/31/2020
9/7/2020
9/14/2020
9/21/2020
9/28/2020
10/5/2020
10/12/2020
10/19/2020
10/26/2020
11/2/2020
11/9/2020
11/16/2020
11/23/2020
11/30/2020
12/7/2020
12/14/2020
12/21/2020
1 ACCEPTED SOLUTION

Hello @Anonymous 

 

this code now filters current month + max date of last 4 months

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XdFBDgQhCATAv8x5E6TRQd8ymf9/Y/GwsXuPFSG08DyXm4ehoV3vZwtNNI9g3ljoR2GLgWAFtXW7GTy7y+xSHg3rDHfRZGEc3eaMKS9SB4joN8mJUxKnJE5JPC0YvLqSFPIiq40iL0uGdxakkC9Vw4bIoVxC0Af3ZkVL5H+lIeRD18gUcfid55f+/QI=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t]),
    YourPreviousStep = Table.TransformColumnTypes(Source,{{"Date", type date}}, "en-US"),
    SelectMonthDatesAndLastDaysOfMonth = Table.SelectRows
    (
        YourPreviousStep,
        (sel)=> if Date.IsInCurrentMonth(sel[Date]) then true else if sel[Date]> Date.StartOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -4)) then  List.Max(List.Select(YourPreviousStep[Date], each Date.Month(_)= Date.Month(sel[Date]) and Date.Year(_)= Date.Year(sel[Date])))=sel[Date] else false
    )
in
    SelectMonthDatesAndLastDaysOfMonth

Copy paste this code to the advanced editor in a new blank query to see how the solution works. 

 

About your combining question or grouping... you never wrote this. So if my answers answer your question, please mark them as solution. In case you have other questions, please create a new post. You can put my reference, then I can help you also for this


If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Hihi profs,

what if I want only current month all dates and max date of previous 3 month or 4 months.... how to modify the code for the second answer

actually, I want to combine files, the group function seems not ok to combine files

thanks for all your kind help  profs

@Jimmy801 

Hello @Anonymous 

 

this code now filters current month + max date of last 4 months

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XdFBDgQhCATAv8x5E6TRQd8ymf9/Y/GwsXuPFSG08DyXm4ehoV3vZwtNNI9g3ljoR2GLgWAFtXW7GTy7y+xSHg3rDHfRZGEc3eaMKS9SB4joN8mJUxKnJE5JPC0YvLqSFPIiq40iL0uGdxakkC9Vw4bIoVxC0Af3ZkVL5H+lIeRD18gUcfid55f+/QI=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t]),
    YourPreviousStep = Table.TransformColumnTypes(Source,{{"Date", type date}}, "en-US"),
    SelectMonthDatesAndLastDaysOfMonth = Table.SelectRows
    (
        YourPreviousStep,
        (sel)=> if Date.IsInCurrentMonth(sel[Date]) then true else if sel[Date]> Date.StartOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -4)) then  List.Max(List.Select(YourPreviousStep[Date], each Date.Month(_)= Date.Month(sel[Date]) and Date.Year(_)= Date.Year(sel[Date])))=sel[Date] else false
    )
in
    SelectMonthDatesAndLastDaysOfMonth

Copy paste this code to the advanced editor in a new blank query to see how the solution works. 

 

About your combining question or grouping... you never wrote this. So if my answers answer your question, please mark them as solution. In case you have other questions, please create a new post. You can put my reference, then I can help you also for this


If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

use only Table.SelectRows to achieve this. Use this function for filtering

(sel)=> if Date.IsInCurrentMonth(sel[Date]) then true else List.Max(List.Select(YourPreviousStep[Date], each Date.Month(_)= Date.Month(sel[Date]) and Date.Year(_)= Date.Year(sel[Date])))=sel[Date]

Be aware that the YourPreviousStep has to be renamed into your real Previous step name. 

Here the complete code example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XdFBDgQhCATAv8x5E6TRQd8ymf9/Y/GwsXuPFSG08DyXm4ehoV3vZwtNNI9g3ljoR2GLgWAFtXW7GTy7y+xSHg3rDHfRZGEc3eaMKS9SB4joN8mJUxKnJE5JPC0YvLqSFPIiq40iL0uGdxakkC9Vw4bIoVxC0Af3ZkVL5H+lIeRD18gUcfid55f+/QI=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t]),
    YourPreviousStep = Table.TransformColumnTypes(Source,{{"Date", type date}}, "en-US"),
    SelectMonthDatesAndLastDaysOfMonth = Table.SelectRows
    (
        YourPreviousStep,
        (sel)=> if Date.IsInCurrentMonth(sel[Date]) then true else List.Max(List.Select(YourPreviousStep[Date], each Date.Month(_)= Date.Month(sel[Date]) and Date.Year(_)= Date.Year(sel[Date])))=sel[Date]
    )
in
    SelectMonthDatesAndLastDaysOfMonth

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If you have performance issues, we could create some additional step for a List.Buffer

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

 

Fowmy
Super User
Super User

@Anonymous 

To achieve what you desire, you need to add a custom column first to identify each year+month and the current year+month, then group to get the results. Paste the code below in the advanced editor of blank query and check the steps.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XdHRDQQhCATQXvy+BBl00VrM9t/GusldnLnPFyGMsFYp92cVNw9DRf0KVTSOYF5ZaEdhk4FgBbU1uxg8u8nsrTzq1hjuosFCP7rMGUNepA4Q0W+SE6ckTkmcknhYMHh1W1LIi9xtFHlaMryxIIV8qT2sixzKKQR98N2saIr8rzSEfOg9MkUc/s3zS38/", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Dates = _t]),
    #"Filtered Rows" = Table.SelectRows(Source, each ([Dates] <> "")),
    #"Changed Type" = Table.TransformColumnTypes(#"Filtered Rows",{{"Dates", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each let

yymm = Number.From(Date.ToText([Dates],"yyyyMM")),
curr = Number.From(Date.ToText(Date.From(DateTime.FixedLocalNow()),"yyyyMM"))
in
if curr = yymm then 
yymm + Date.Day([Dates]) else
yymm),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Custom"}, {{"Count", each List.Max([Dates]), type nullable date}}),
    #"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Custom"})
in
    #"Removed Columns"

Fowmy_0-1608912492199.png

________________________

If my answer was helpful, please click Accept it as the solution to help other members find it useful

Click on the Thumbs-Up icon if you like this reply 🙂


Website YouTube  LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

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.

Top Solution Authors
Top Kudoed Authors