Supplies are limited. Contact info@espc.tech right away to save your spot before the conference sells out.
Get your discountScore big with last-minute savings on the final tickets to FabCon Vienna. Secure your discount
Dear all,
I am working in power query/excel. Is it possible/uncomplicated to group some items in an existing external odata table into new categories so that any measures/displays pick up both new groups and individual elements? I.e. a new Region group as below xyz showing an average of % and a sum of resp?
Region | % | resp |
x | 5 | 2 |
y | 10 | 3 |
y | 15 | 4 |
*new Group xyx | 10 | 9 |
Ideally I would not have to change any existing pivot tables/measures/displays. Please could you let me know how to do this, or point to a helpful resource?
Many thanks,
A
Solved! Go to Solution.
Hello @adavid999
you can try to add a new column with the new region name
Group by this column, applying exactly the measures you want and after that combining both tables. Here the code for a short example
let
Source = #table
(
{"Region","%","resp"},
{
{"x","5","2"}, {"y","10","3"}, {"y","15","4"}
}
),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"%", type number}, {"resp", type number}}),
#"Added Custom" = Table.AddColumn(Table.RemoveColumns(#"Changed Type", "Region"), "Region", each "group xyy"),
#"Grouped Rows" = Table.Group(#"Added Custom", {"Region"}, {{"%", each List.Average([#"%"]), type number}, {"resp", each List.Sum([resp]), type number}}),
Combine = Table.Combine({#"Changed Type", #"Grouped Rows"})
in
Combine
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Hello @adavid999
you can try to add a new column with the new region name
Group by this column, applying exactly the measures you want and after that combining both tables. Here the code for a short example
let
Source = #table
(
{"Region","%","resp"},
{
{"x","5","2"}, {"y","10","3"}, {"y","15","4"}
}
),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"%", type number}, {"resp", type number}}),
#"Added Custom" = Table.AddColumn(Table.RemoveColumns(#"Changed Type", "Region"), "Region", each "group xyy"),
#"Grouped Rows" = Table.Group(#"Added Custom", {"Region"}, {{"%", each List.Average([#"%"]), type number}, {"resp", each List.Sum([resp]), type number}}),
Combine = Table.Combine({#"Changed Type", #"Grouped Rows"})
in
Combine
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Hi @Jimmy801 I think that would do it - so simple! Even a new column in the existing table should work shouldn't it?!
Thanks,
A