Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hi PBI-experts!
Recently, I faced the challenge of finding the last day of period based on the first date of the next period on a product level. Date would indicate the end-date of that specific period. Whenever it was the last entry and there would be no following the value should be left empty. To provide a very simplified sample of the data set to work with:
product_name | start_date | price |
sweatshirt_fantasy_brand_01 | 2022-1-31 | 15 |
sweatshirt_fantasy_brand_01 | 2022-3-24 | 13 |
sweatshirt_fantasy_brand_01 | 2022-4-17 | 12 |
sweatshirt_fantasy_brand_01 | 2022-7-10 | 11 |
pants_fantasy_brand_01 | 2022-1-5 | 24 |
pants_fantasy_brand_01 | 2022-7-28 | 23 |
I found a solution via DAX which identifies the next highest date value for the specific product group. I used it as a calculated column in the respective table. However, as far as I know it would be more performant to create that calculation in query editor as a computed column and therefore, I wanted to ask if you know how to calculated the next highest max date within the product group, take the day before and assign it to a new column with the condition to leave it null in case there is no higher entry for that specific product.
Looking forward to hearing back from you and discussing the solutions together 🙂
Solved! Go to Solution.
Hi @NrAg,
Are you looking for something like this?
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jc5BCoAgEIXhu7h2wBkVu4uITFTURkKF6PY1HSDc/Yv3wYtRtWvl3vaj9rxx6dzuPFcuSzaotCJDBAhWGr1KeghYICfAjgIHGATQKAiARgB+4HxX7ee+l3QD0wA0Sb/H0wM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [product_name = _t, start_date = _t, price = _t]),
f = (t as table) as table =>
let
add = Table.ToColumns(t) & {List.Transform(List.Skip(t[start_date]), each Date.AddDays(_, -1))},
format = Table.FromColumns(add, Value.Type(Table.AddColumn(t, "end_date", each null, type date)))
in
format,
#"Changed Type" = Table.TransformColumnTypes(Source,{{"product_name", type text}, {"start_date", type date}, {"price", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"product_name"}, {{"Out", f, Value.Type(Table.AddColumn(#"Changed Type", "end_date", each null, type date))}}),
#"Expanded Out" = Table.ExpandTableColumn(#"Grouped Rows", "Out", {"start_date", "price", "end_date"}, {"start_date", "price", "end_date"})
in #"Expanded Out"
Cheers,
John
NewStep= Table.FromRecords(List.Accumulate(Table.ToRecords(Table.Sort(PreviousStepName,{"product_name",{"start_date",1}})),{{},[]},(x,y)=>{{y&[end_date=Record.FieldOrDefault(x{1},y[product_name],null)]}&x{0},Record.TransformFields(x{1},{y[product_name],each Date.AddDays(y[start_date],-1)},2)}){0})
I wish I would fully understand the formula but will definitely spend some time to read it through. However, it works perfectly and I very much appreciate your help!
NewStep= Table.FromRecords(List.Accumulate(Table.ToRecords(Table.Sort(PreviousStepName,{"product_name",{"start_date",1}})),{{},[]},(x,y)=>{{y&[end_date=Record.FieldOrDefault(x{1},y[product_name],null)]}&x{0},Record.TransformFields(x{1},{y[product_name],each Date.AddDays(y[start_date],-1)},2)}){0})
I wish I would fully understand the formula but will definitely spend some time to read it through. However, it works perfectly and I very much appreciate your help!
Hi @NrAg,
Are you looking for something like this?
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jc5BCoAgEIXhu7h2wBkVu4uITFTURkKF6PY1HSDc/Yv3wYtRtWvl3vaj9rxx6dzuPFcuSzaotCJDBAhWGr1KeghYICfAjgIHGATQKAiARgB+4HxX7ee+l3QD0wA0Sb/H0wM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [product_name = _t, start_date = _t, price = _t]),
f = (t as table) as table =>
let
add = Table.ToColumns(t) & {List.Transform(List.Skip(t[start_date]), each Date.AddDays(_, -1))},
format = Table.FromColumns(add, Value.Type(Table.AddColumn(t, "end_date", each null, type date)))
in
format,
#"Changed Type" = Table.TransformColumnTypes(Source,{{"product_name", type text}, {"start_date", type date}, {"price", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"product_name"}, {{"Out", f, Value.Type(Table.AddColumn(#"Changed Type", "end_date", each null, type date))}}),
#"Expanded Out" = Table.ExpandTableColumn(#"Grouped Rows", "Out", {"start_date", "price", "end_date"}, {"start_date", "price", "end_date"})
in #"Expanded Out"
Cheers,
John
thank you jbwtp! Your solution works as well. Unfortunately I have as much struggle to disassemble your code than I had with Daniels. But I will have a look at Query Editor Documentation. Do you have good suggestions for YT-channels or alike for improving my knowledge in M?
Hi @NrAg,
Try this series: Power Query M Primer (Part 14): Control Structure | Ben Gribaudo
YT or other platform-wise: it is probably better to search for a solution to a specific problem - this way I learn M. For some general topics around PBI, this one can be usefull: https://www.youtube.com/@CurbalEN.
Good source of conceptual knowledge may be Chriss Web's blog (search for Chris crossjoin). Early records are most usefull for starters.
Cheers,
John