Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredJoin us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM. Register now.
Hi
I need to add custom column that itterates over a column and count distinct values in a repeated fix range.
In this example, the ‘CustomColumn’ in the ‘Result Table’ calculates the number of distinct values in a range of 3 rows (for each row of ‘Column1’ in ‘Base Table’).
I know how to do that in DAX, however, I need Power Query solution.
Thanks.
Solved! Go to Solution.
Hi @dpbi,
let
Source = Excel.Workbook(File.Contents("C:\xxxx\xxxx\Desktop\Sample Data.xlsx"), null, true),
#"Base Table_Sheet" = Source{[Item="Base Table",Kind="Sheet"]}[Data],
#"Promoted Headers" = Table.PromoteHeaders(#"Base Table_Sheet", [PromoteAllScalars=true]),
#"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Index", Int64.Type}, {"Column1", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "DistinctPerIndex", (This) => List.Distinct(Table.SelectRows(#"Changed Type", each [Index] <= This[Index] and [Index] >= This[Index]-2)[Column1])),
#"Expanded DistinctPerIndex" = Table.ExpandListColumn(#"Added Custom", "DistinctPerIndex"),
#"Grouped Rows" = Table.Group(#"Expanded DistinctPerIndex", {"Index"}, {{"CountDistinct", each Table.RowCount(_), type number}, {"AllData", each _, type table}}),
#"Expanded AllData" = Table.ExpandTableColumn(#"Grouped Rows", "AllData", {"Column1"}, {"AllData.Column1"}),
#"Removed Duplicates" = Table.Distinct(#"Expanded AllData", {"Index"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Duplicates",{{"AllData.Column1", "Column1"}})
in
#"Renamed Columns"
Best regards,
Yuliana Gu
Hi @dpbi,
let
Source = Excel.Workbook(File.Contents("C:\xxxx\xxxx\Desktop\Sample Data.xlsx"), null, true),
#"Base Table_Sheet" = Source{[Item="Base Table",Kind="Sheet"]}[Data],
#"Promoted Headers" = Table.PromoteHeaders(#"Base Table_Sheet", [PromoteAllScalars=true]),
#"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Index", Int64.Type}, {"Column1", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "DistinctPerIndex", (This) => List.Distinct(Table.SelectRows(#"Changed Type", each [Index] <= This[Index] and [Index] >= This[Index]-2)[Column1])),
#"Expanded DistinctPerIndex" = Table.ExpandListColumn(#"Added Custom", "DistinctPerIndex"),
#"Grouped Rows" = Table.Group(#"Expanded DistinctPerIndex", {"Index"}, {{"CountDistinct", each Table.RowCount(_), type number}, {"AllData", each _, type table}}),
#"Expanded AllData" = Table.ExpandTableColumn(#"Grouped Rows", "AllData", {"Column1"}, {"AllData.Column1"}),
#"Removed Duplicates" = Table.Distinct(#"Expanded AllData", {"Index"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Duplicates",{{"AllData.Column1", "Column1"}})
in
#"Renamed Columns"
Best regards,
Yuliana Gu
Hi @ v-yulgu-msft
Exactly what i needed.
Thank you very much Yuliana for your kind help.
Great support, very much appreciated!
Best regards
Dan