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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
DataUser
Helper I
Helper I

Filter by year for projects - only reference oldest record date for the project

So I have a list of data about various projects. Every time an update is made, another record is created and any older records are labeled as "Archive Version". If a record is never updated, that's okay. In this case, I don't really care about the status, just that i'm not counting the same projects multiple times and I only want the oldest date. 

 

I want to do two things. First, select "year" from a slicer or something and get a count of how many projects were "Created" in that year (like on a datacard or something?). Second, i want to be able to list what projects they are.

 

Thanks!

 

2021-04-20_8-56-00.png

 

 

1 ACCEPTED SOLUTION
DataInsights
Super User
Super User

@DataUser,

 

Try this solution.

 

1. In Power Query, create an aggregated table based on the data table (in my example, the original table is ProjectsAll, and the aggregated table is ProjectsOldestDate). Use the Group By function in the Transform toolbar.

 

DataInsights_0-1619103901043.png

 

DataInsights_1-1619103953552.png

Here's the M code:

 

let
  Source = ProjectsAll, 
  GroupRows = Table.Group(
    Source, 
    {"Project"}, 
    {
      {"Created/updated Date", each List.Min([#"Created/updated Date"]), type nullable date}, 
      {
        "All", 
        each _, 
        type table [
          Project = nullable text, 
          Status = nullable text, 
          #"Created/updated Date" = nullable date
        ]
      }
    }
  ), 
  ExpandAll = Table.ExpandTableColumn(
    GroupRows, 
    "All", 
    {"Status", "Created/updated Date"}, 
    {"All.Status", "All.Created/updated Date"}
  ), 
  AddColumn = Table.AddColumn(
    ExpandAll, 
    "Date Match", 
    each [#"Created/updated Date"] = [#"All.Created/updated Date"]
  ), 
  FilterRows = Table.SelectRows(AddColumn, each ([Date Match] = true)), 
  RemoveColumns = Table.RemoveColumns(FilterRows, {"All.Created/updated Date", "Date Match"}), 
  RenameColumn = Table.RenameColumns(RemoveColumns, {{"All.Status", "Status"}})
in
  RenameColumn

 The result in Power Query (you can include additional columns in the original data table):

 

DataInsights_3-1619104377448.png

 

2. Create a relationship between ProjectsOldestDate and the date table.

 

3. Create measure:

 

Project Count = COUNT ( ProjectsOldestDate[Project] )

 

4. Create slicer based on Year in date table.

 

5. Create visuals using ProjectsOldestDate:

DataInsights_4-1619104587044.png

 

DataInsights_6-1619104618976.png

 

 

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

1 REPLY 1
DataInsights
Super User
Super User

@DataUser,

 

Try this solution.

 

1. In Power Query, create an aggregated table based on the data table (in my example, the original table is ProjectsAll, and the aggregated table is ProjectsOldestDate). Use the Group By function in the Transform toolbar.

 

DataInsights_0-1619103901043.png

 

DataInsights_1-1619103953552.png

Here's the M code:

 

let
  Source = ProjectsAll, 
  GroupRows = Table.Group(
    Source, 
    {"Project"}, 
    {
      {"Created/updated Date", each List.Min([#"Created/updated Date"]), type nullable date}, 
      {
        "All", 
        each _, 
        type table [
          Project = nullable text, 
          Status = nullable text, 
          #"Created/updated Date" = nullable date
        ]
      }
    }
  ), 
  ExpandAll = Table.ExpandTableColumn(
    GroupRows, 
    "All", 
    {"Status", "Created/updated Date"}, 
    {"All.Status", "All.Created/updated Date"}
  ), 
  AddColumn = Table.AddColumn(
    ExpandAll, 
    "Date Match", 
    each [#"Created/updated Date"] = [#"All.Created/updated Date"]
  ), 
  FilterRows = Table.SelectRows(AddColumn, each ([Date Match] = true)), 
  RemoveColumns = Table.RemoveColumns(FilterRows, {"All.Created/updated Date", "Date Match"}), 
  RenameColumn = Table.RenameColumns(RemoveColumns, {{"All.Status", "Status"}})
in
  RenameColumn

 The result in Power Query (you can include additional columns in the original data table):

 

DataInsights_3-1619104377448.png

 

2. Create a relationship between ProjectsOldestDate and the date table.

 

3. Create measure:

 

Project Count = COUNT ( ProjectsOldestDate[Project] )

 

4. Create slicer based on Year in date table.

 

5. Create visuals using ProjectsOldestDate:

DataInsights_4-1619104587044.png

 

DataInsights_6-1619104618976.png

 

 

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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