Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hello Community,
I require some help in adding "Years in scope" column from power query.(in the screenshot below) Basically, I need a column that contains all the concatenated distinct year field values by client field.
For example:
1) Client 1 has data for the years 2020, 2021 and 2022 hence the concatenated column (Years in scope) has value "2020,2021,2022". (delimited with comma).
2) Client 2 has data for the years 2021 and 2022 hence the concatenated column has "2021,2022".
Hope this acheivable and would really appreciate any response or support.
Thanks,
AnthonyJoseph
Solved! Go to Solution.
Thank you @ThxAlot . I was able to get the output however, is it possible to have them sorted to be in ascending order For example: I am getting values like 2022,2020,2021 is there a way where I can get it in ascending order like 2020,2021,2022 other than by sorting the table by year?
Thanks,
AnthonyJoseph
Hi @AnthonyJoseph ,
Make a little change to ThxAlot's code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTIyMDICUoYGBkqxOnAhCIUhZIwqZACkTKBCRgizTFFEQGrNgCKxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Client = _t, Year = _t, Revenue = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Client", Int64.Type}, {"Year", Int64.Type}, {"Revenue", Int64.Type}}),
Grouped = Table.Group(Source, "Client", {"grp", each Table.AddColumn(_, "Yrs in scope", (r) => Text.Combine(List.Sort(List.Distinct([Year])),","))}),
Table = Table.Combine(Grouped[grp])
in
Table
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTIyMDICUoYGBkqxOnAhCIUhZIwqZACkTKBCRgizTFFEQGrNgCKxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Client = _t, Year = _t, Revenue = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Client", Int64.Type}, {"Year", Int64.Type}, {"Revenue", Int64.Type}}),
Grouped = Table.Group(Source, "Client", {"grp", each Table.AddColumn(_, "Yrs in scope", (r) => Text.Combine(List.Distinct([Year]),","))}),
Table = Table.Combine(Grouped[grp])
in
Table
A showcase of powerful Excel formulas,
Expertise = List.Accumulate( {Days as from Today}, {Skills and Knowledge}, (Current, Everyday) => Current & Day.LearnAndPractise(Everyday) ) |
Thank you @ThxAlot . I was able to get the output however, is it possible to have them sorted to be in ascending order For example: I am getting values like 2022,2020,2021 is there a way where I can get it in ascending order like 2020,2021,2022 other than by sorting the table by year?
Thanks,
AnthonyJoseph
Hi @AnthonyJoseph ,
Make a little change to ThxAlot's code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTIyMDICUoYGBkqxOnAhCIUhZIwqZACkTKBCRgizTFFEQGrNgCKxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Client = _t, Year = _t, Revenue = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Client", Int64.Type}, {"Year", Int64.Type}, {"Revenue", Int64.Type}}),
Grouped = Table.Group(Source, "Client", {"grp", each Table.AddColumn(_, "Yrs in scope", (r) => Text.Combine(List.Sort(List.Distinct([Year])),","))}),
Table = Table.Combine(Grouped[grp])
in
Table
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
11 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
9 | |
6 | |
6 |