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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
evadung
Frequent Visitor

adding end date

Hello, I have a table with date, item, warehouse and quantity:

dateitemwarehousequantity
6.10.2023A2038
8.11.2023A2037
3.6.2023B2055
7.11.2023B2058


I want to add "end date" so the table will look like this:

dateitemwarehousequantityend date
6.10.2023A20388.11.2023
8.11.2023A2037null
3.6.2023B20557.11.2023
7.11.2023B2058null


i tried
1) grouping by item and warehouse
2) add custom index table (0,1,)
3) delete all columns except index table + expand = table date, item, warehouse, quantity + index column
4) adding new index column 2 (index column + 1)
5) merging queries (index + index 2, item + item, warehouse + warehouse)
6) expand just date
in the newest date should be null but instead it looks like it choose random date 

thank you for your ideas

1 ACCEPTED SOLUTION
tackytechtom
Super User
Super User

Hi @evadung ,

 

How about this:

tackytechtom_0-1701174593708.png

 

 

I did something similar that you suggested: Group By Item with MAX on date and then joined that outcome with the original table. Rest was just some cleansing.

 

Here the code in Power Query M that you can paste into the advanced editor (if you do not know, how to exactly do this, please check out this quick walkthrough)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtMzNNAzMjAyVtJRcgRiIwMQy0IpVidayULP0BBTzhwsZ6xnBpNyAkuZAklTsJQ5kjaEHNDIWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [date = _t, item = _t, warehouse = _t, quantity = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"date", type date}, {"item", type text}, {"warehouse", Int64.Type}, {"quantity", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"item"}, {{"MaxDate", each List.Max([date]), type nullable date}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"item"}, #"Grouped Rows", {"item"}, "Grouped Rows", JoinKind.LeftOuter),
    #"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"MaxDate"}, {"Grouped Rows.MaxDate"}),
    #"Added Custom" = Table.AddColumn(#"Expanded Grouped Rows", "end date", each if [date] = [Grouped Rows.MaxDate] then null else [Grouped Rows.MaxDate]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Grouped Rows.MaxDate"})
in
    #"Removed Columns"

 

[Edit]: You might need to add Warehouse to the GROUP BY as well...

Let me know if this solves your query 🙂

 

/Tom
https://www.tackytech.blog/
https://www.instagram.com/tackytechtom/



Did I answer your question➡️ Please, mark my post as a solution ✔️

Also happily accepting Kudos 🙂

Feel free to connect with me on LinkedIn! linkedIn

#proudtobeasuperuser 

View solution in original post

1 REPLY 1
tackytechtom
Super User
Super User

Hi @evadung ,

 

How about this:

tackytechtom_0-1701174593708.png

 

 

I did something similar that you suggested: Group By Item with MAX on date and then joined that outcome with the original table. Rest was just some cleansing.

 

Here the code in Power Query M that you can paste into the advanced editor (if you do not know, how to exactly do this, please check out this quick walkthrough)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtMzNNAzMjAyVtJRcgRiIwMQy0IpVidayULP0BBTzhwsZ6xnBpNyAkuZAklTsJQ5kjaEHNDIWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [date = _t, item = _t, warehouse = _t, quantity = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"date", type date}, {"item", type text}, {"warehouse", Int64.Type}, {"quantity", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"item"}, {{"MaxDate", each List.Max([date]), type nullable date}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"item"}, #"Grouped Rows", {"item"}, "Grouped Rows", JoinKind.LeftOuter),
    #"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"MaxDate"}, {"Grouped Rows.MaxDate"}),
    #"Added Custom" = Table.AddColumn(#"Expanded Grouped Rows", "end date", each if [date] = [Grouped Rows.MaxDate] then null else [Grouped Rows.MaxDate]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Grouped Rows.MaxDate"})
in
    #"Removed Columns"

 

[Edit]: You might need to add Warehouse to the GROUP BY as well...

Let me know if this solves your query 🙂

 

/Tom
https://www.tackytech.blog/
https://www.instagram.com/tackytechtom/



Did I answer your question➡️ Please, mark my post as a solution ✔️

Also happily accepting Kudos 🙂

Feel free to connect with me on LinkedIn! linkedIn

#proudtobeasuperuser 

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors
Top Kudoed Authors