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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
eng_123
Frequent Visitor

Creation of Flag in Power Query based on Dates

Would require help to create a flag column to identify Past, Present and Future based on the Date in Power Query.

 

The data would come across something similar to this:

TypeDateToday
Level 1 10/07/2024 10/10/2024
Level 1 11/07/2024 10/10/2024
Level 1 26/09/2024 10/10/2024
Level 1 29/09/2024 10/10/2024
Level 1 30/09/2024 10/10/2024
Level 1 1/10/2024 10/10/2024
Level 1 2/10/2024 10/10/2024
Level 1 7/10/2024 10/10/2024
Level 1 8/10/2024 10/10/2024
Level 1 9/10/2024 10/10/2024
Level 1 10/10/2024 10/10/2024
Level 1 11/10/2024 10/10/2024
Level 1 15/10/2024 10/10/2024
Level 116/10/202410/10/2024
Level 1 4/12/2024 10/10/2024
Level 1 5/12/2024 10/10/2024
Level 2 30/09/2024 10/10/2024
Level 2 1/10/2024 10/10/2024
Level 2 9/10/2024 10/10/2024
Level 2 10/10/2024 10/10/2024
Level 2 11/10/2024 10/10/2024
Level 2 12/10/2024 10/10/2024
Level 2 31/12/2024 10/10/2024
Level 2 1/01/2025 10/10/2024

 

 

Create additonal flag column in power query

 

Past= Does not fit in latest cycle of continous day in between todays dates and are previous dates

Present= Fits in latest cycle of continous day in between todays dates 

Future= Does not fit in latest cycle of continous day in between todays dates and are future dates

 

TypeDateTodayType Flag 
Level 1 10/07/2024 10/10/2024 Past
Level 1 11/07/2024 10/10/2024 Past
Level 1 26/09/2024 10/10/2024 Past
Level 1 29/09/2024 10/10/2024  Past
Level 1 30/09/2024 10/10/2024 Past
Level 1 1/10/2024 10/10/2024 Past
Level 1 2/10/2024 10/10/2024 Past
Level 1 7/10/2024 10/10/2024 Present
Level 1 8/10/2024 10/10/2024 Present
Level 1 9/10/2024 10/10/2024 Present
Level 1 10/10/2024 10/10/2024 Present
Level 1 11/10/2024 10/10/2024 Present
Level 1 15/10/2024 10/10/2024 Future
Level 1 16/10/2024 10/10/2024 Future
Level 1 4/12/2024 10/10/2024 Future
Level 1 5/12/2024 10/10/2024 Future
Level 2 30/09/2024 10/10/2024 Past
Level 2 1/10/2024 10/10/2024 Past
Level 2 9/10/2024 10/10/2024 Present
Level 210/10/2024 10/10/2024 Present
Level 2 11/10/2024 10/10/2024 Present
Level 2 12/10/2024 10/10/2024 Present
Level 2 31/12/2024 10/10/2024 Future
Level 2 1/01/2025 10/10/2024 Future
1 ACCEPTED SOLUTION
Omid_Motamedise
Super User
Super User

Thanks for sharing such a nice challenge. Copy and past the next formula into a blank query 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jdNBCoMwEIXhq0jWQmZejTZ38AaSpTvXnl+tpdiCzQ/ZhPnIkDfJNIVxXuel8dCGxi3aEGXq3rt9vXal/XbOnPpombjM3MOY80/hf1vGBsaejGXGLpXaKJhLyHl/YfenddEFmqYqExyr2FjFEhZMWDDh09Wf03lbZ6nsf8yPQvplZQM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Type = _t, Date = _t, Today = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}, {"Date", type date}, {"Today", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Type"}, {{"Count", each _}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.AddColumn([Count],"Flag", (x)=>if List.ContainsAll(_[Count][Date],List.Dates(List.Min({x[Date],x[Today]}),Number.Abs(Number.From(x[Today]-x[Date])),#duration(1,0,0,0))) then "Present" else if x[Date]<x[Today] then "Past" else "Future")),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Type", "Date", "Today", "Flag"}, {"Type", "Date", "Today", "Flag"})
in
    #"Expanded Custom"

If this answer helped resolve your issue, please consider marking it as the accepted answer. And if you found my response helpful, I'd appreciate it if you could give me kudos. Thank you!

If my answer helped solve your issue, please consider marking it as the accepted solution. It helps others in the community find answers faster—and keeps the community growing stronger!
You can also check out my YouTube channel for tutorials, tips, and real-world solutions in Power Query with the following link
https://youtube.com/@omidbi?si=96Bo-ZsSwOx0Z36h

View solution in original post

3 REPLIES 3
eng_123
Frequent Visitor

Thank you

AlienSx
Super User
Super User

let
    Source = your_table,
    type_flag = (tbl) => 
        (
            (w) => Table.AddColumn(tbl, "Type Flag", each w)
        )(if List.Contains(tbl[Date], tbl[Today]{0}) then "Present" else if tbl[Date]{0} < tbl[Today]{0} then "Past" else "Future"),
    idx = Table.AddIndexColumn(Source, "idx"), 
    group = Table.Group(
        idx, 
        {"Type", "Date", "idx"}, 
        {"x", type_flag}, 
        GroupKind.Local, 
        (s, c) => Number.From(s[Type] <> c[Type] or Duration.Days(c[Date] - s[Date]) <> c[idx] - s[idx])),
    result = Table.Combine(group[x])
in
    result
Omid_Motamedise
Super User
Super User

Thanks for sharing such a nice challenge. Copy and past the next formula into a blank query 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jdNBCoMwEIXhq0jWQmZejTZ38AaSpTvXnl+tpdiCzQ/ZhPnIkDfJNIVxXuel8dCGxi3aEGXq3rt9vXal/XbOnPpombjM3MOY80/hf1vGBsaejGXGLpXaKJhLyHl/YfenddEFmqYqExyr2FjFEhZMWDDh09Wf03lbZ6nsf8yPQvplZQM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Type = _t, Date = _t, Today = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}, {"Date", type date}, {"Today", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Type"}, {{"Count", each _}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.AddColumn([Count],"Flag", (x)=>if List.ContainsAll(_[Count][Date],List.Dates(List.Min({x[Date],x[Today]}),Number.Abs(Number.From(x[Today]-x[Date])),#duration(1,0,0,0))) then "Present" else if x[Date]<x[Today] then "Past" else "Future")),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Type", "Date", "Today", "Flag"}, {"Type", "Date", "Today", "Flag"})
in
    #"Expanded Custom"

If this answer helped resolve your issue, please consider marking it as the accepted answer. And if you found my response helpful, I'd appreciate it if you could give me kudos. Thank you!

If my answer helped solve your issue, please consider marking it as the accepted solution. It helps others in the community find answers faster—and keeps the community growing stronger!
You can also check out my YouTube channel for tutorials, tips, and real-world solutions in Power Query with the following link
https://youtube.com/@omidbi?si=96Bo-ZsSwOx0Z36h

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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