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!
Solved! Go to Solution.
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.
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):
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:
Proud to be a Super User!
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.
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):
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:
Proud to be a Super User!
Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.
Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!
Join the biggest FREE Business Applications Event in LATAM this February.
User | Count |
---|---|
216 | |
53 | |
49 | |
46 | |
42 |
User | Count |
---|---|
264 | |
211 | |
113 | |
79 | |
66 |