Mar 25 2021 02:37 AM - edited Mar 25 2021 02:41 AM
Hi,
If any one know how to find max value with a conditional selection in another column? (Power Query only)
Example like below, try to find "Column 1 = B" + maximum value in column 2
Expect result: (please note I want it return to all fields)
Mar 25 2021 03:40 AM
Assuming the name of the source data table is Table1, insert a blank query with the following code.
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each List.Max(#"Changed Type"[Column2]))
in
#"Added Custom"
Refer to the attached for more details.
Mar 25 2021 01:33 PM
SolutionIn addition to @Subodh_Tiwari_sktneer solution for column maximum here are couple of filtered maximums
for external filter
let
filter = "A",
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(
Source,
{{"Column1", type text}, {"Column2", Int64.Type}}
),
#"Added Custom" = Table.AddColumn(
#"Changed Type",
"maxExt",
each
[
max=Table.Group(
Source, {"Column1"},
{{"MaxFiltered", each List.Max([Column2])}}
){[Column1=filter]}[MaxFiltered]
][max]
)
in
#"Added Custom"
max per group
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(
Source,
{{"Column1", type text}, {"Column2", Int64.Type}}
),
#"Added Custom" = Table.AddColumn(
#"Changed Type",
"maxInt",
each
[
filter = [Column1],
max=Table.Group(
Source, {"Column1"},
{{"MaxFiltered", each List.Max([Column2])}}
){[Column1=filter]}[MaxFiltered]
][max]
)
in
#"Added Custom"
Mar 25 2021 06:23 PM
Your solution is more on max value in total column 2, actually I want filter column 1 first and then check max value.
Oct 03 2023 09:45 PM
Oct 04 2023 03:21 AM
Oct 08 2023 09:44 AM
For such sample
if you mean Power Query you may query Table1 and Table2, merge them as new query on NameID and dates; load result into the grid.
Alternatively you may add to Table1 department column which is calculated as
=XLOOKUP([@NameID]&[@MaxDate], Table2[NameID]&Table2[NMaxDate], Table2[DeptID], "not defined" )
Please check attached file.
Mar 25 2021 01:33 PM
SolutionIn addition to @Subodh_Tiwari_sktneer solution for column maximum here are couple of filtered maximums
for external filter
let
filter = "A",
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(
Source,
{{"Column1", type text}, {"Column2", Int64.Type}}
),
#"Added Custom" = Table.AddColumn(
#"Changed Type",
"maxExt",
each
[
max=Table.Group(
Source, {"Column1"},
{{"MaxFiltered", each List.Max([Column2])}}
){[Column1=filter]}[MaxFiltered]
][max]
)
in
#"Added Custom"
max per group
let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(
Source,
{{"Column1", type text}, {"Column2", Int64.Type}}
),
#"Added Custom" = Table.AddColumn(
#"Changed Type",
"maxInt",
each
[
filter = [Column1],
max=Table.Group(
Source, {"Column1"},
{{"MaxFiltered", each List.Max([Column2])}}
){[Column1=filter]}[MaxFiltered]
][max]
)
in
#"Added Custom"