Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
dpbi
Helper I
Helper I

Distinct count loop in power query

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.

 

CustomColumn.PNG

1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

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"

1.PNG

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
v-yulgu-msft
Employee
Employee

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"

1.PNG

 

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.