Power Query - how to compare weekly data and identify items that have been processed.

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
90
Hi i have a data model that keep track of weekly progress of items, however i am having issues to figure out how to identify an item has been processed (or cleared out in the subsequent week for the previous week data) see figure 1. As you can see the yellow highlighted items have been cleared out in the week of 2 ie Jan 12. and i would like to have the end results in Fig 2. Appreciate any helps!!

1683242920589.png
1683243053681.png
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    lst = Table.SelectRows(Source, each [Report Date] = List.Max(Source[Report Date]))[ID],
    tbl = Table.Group(Source, {"Report Date"}, {{"All", each 
        Table.AddColumn(_, "Item Cleared", (x)=> if not List.Contains(lst, x[ID]) then 1 else null)}}),
    Result = Table.ExpandTableColumn(tbl, "All", {"Follow Up", "Status", "ID", "Item Cleared"})
in
    Result
 
Upvote 0
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    lst = Table.SelectRows(Source, each [Report Date] = List.Max(Source[Report Date]))[ID],
    tbl = Table.Group(Source, {"Report Date"}, {{"All", each
        Table.AddColumn(_, "Item Cleared", (x)=> if not List.Contains(lst, x[ID]) then 1 else null)}}),
    Result = Table.ExpandTableColumn(tbl, "All", {"Follow Up", "Status", "ID", "Item Cleared"})
in
    Result
Thanks for the quick response. One more query, a same ID could have two different follow ups and one follow up could have completed next subsequent week and the could remain untouch. In this scenario, will the query be able to identify?
 
Upvote 0
The code I wrote looks to see if an ID appears in the list of IDs of the latest date in the table (in your example the 1/12/23 group). If it does not appear there it puts a 1 in the Item Cleared column. If it does appear then it puts a null.
 
Upvote 0

Forum statistics

Threads
1,223,355
Messages
6,171,614
Members
452,411
Latest member
sprichwort

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top