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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Alex_nor
Frequent Visitor

Group by date range - Powe query

Hello all,

I have two columns: TimeStamp and LoadDate. 

I would like to create a third column, LoadID based on this criteria:

Dates between 23-06-2022 and 04-07-2022 in TimeStamp should have LoadID = 05-07-2022,

dates between 05-07-2022 and 27-07-2022 in TimeStamp should have LoadID = 28-07-2022, and so on.

Do you have any suggestion?

 

Alex_nor_0-1664261210984.png

 

1 ACCEPTED SOLUTION
v-yalanwu-msft
Community Support
Community Support

Hi, @Alex_nor ;

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZdJLDoAgEATRu7A2wenh51kM97+GiRoIxY5qXbyI9x1KlEedUjhC6Mc7JA6ZQ+FQOTQOFwY/l6FGQwvt6IQeyHH89oL3KrqhL7o2KKVGqtFqxFrmQKbRaYQapaJU2zelVJSKUlEqSkXpvPx5/p+QvP0FvpJbZAvt6ITO6IKu6IYe4nHs/QE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Timestamp = _t, LoadDate = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Timestamp", type date}, {"LoadDate", type date}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"Timestamp", Order.Ascending}}),
    #"Added Custom" = Table.AddColumn(#"Sorted Rows", "Custom", each [LoadDate]),
    #"Filled Up" = Table.FillUp(#"Added Custom",{"Custom"}),
    #"Added Conditional Column" = Table.AddColumn(#"Filled Up", "Load Id", each if [Timestamp] = [Custom] then null else [Custom]),
    #"Filled Up1" = Table.FillUp(#"Added Conditional Column",{"Load Id"}),
    #"Removed Columns" = Table.RemoveColumns(#"Filled Up1",{"Custom"})
in
    #"Removed Columns"

The final show:

vyalanwumsft_0-1664358645449.png


Best Regards,
Community Support Team _ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
v-yalanwu-msft
Community Support
Community Support

Hi, @Alex_nor ;

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZdJLDoAgEATRu7A2wenh51kM97+GiRoIxY5qXbyI9x1KlEedUjhC6Mc7JA6ZQ+FQOTQOFwY/l6FGQwvt6IQeyHH89oL3KrqhL7o2KKVGqtFqxFrmQKbRaYQapaJU2zelVJSKUlEqSkXpvPx5/p+QvP0FvpJbZAvt6ITO6IKu6IYe4nHs/QE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Timestamp = _t, LoadDate = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Timestamp", type date}, {"LoadDate", type date}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"Timestamp", Order.Ascending}}),
    #"Added Custom" = Table.AddColumn(#"Sorted Rows", "Custom", each [LoadDate]),
    #"Filled Up" = Table.FillUp(#"Added Custom",{"Custom"}),
    #"Added Conditional Column" = Table.AddColumn(#"Filled Up", "Load Id", each if [Timestamp] = [Custom] then null else [Custom]),
    #"Filled Up1" = Table.FillUp(#"Added Conditional Column",{"Load Id"}),
    #"Removed Columns" = Table.RemoveColumns(#"Filled Up1",{"Custom"})
in
    #"Removed Columns"

The final show:

vyalanwumsft_0-1664358645449.png


Best Regards,
Community Support Team _ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

PhilipTreacy
Super User
Super User

Hi @Alex_nor 

 

Try this M code  : Download sample file

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"TimeStamp", type date}, {"LoadDate", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "LoadID", each if [TimeStamp] <= #date(2022,7,4) then #date(2022,7,5)

else if [TimeStamp] <= #date(2022,7,27) then #date(2022,7,28)

else null)
in
    #"Added Custom"

 

 

Which gives this

loadid.png

 

In my data the date columns are actually dates, in your data they look to be text.

 

Regards

 

Phil

 

 



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors