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.
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
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 |
---|---|
65 | |
63 | |
52 | |
37 | |
36 |
User | Count |
---|---|
82 | |
66 | |
61 | |
46 | |
45 |