The current version of Power Query does not have a user interface to create a Distinct Count calculation in a Group By operation. However, you can do this in “M” with a simple edit of the code generated by the Power Query window.

Consider the following table in Excel:

DistinctPowerQuery_01

You want to obtain a table containing the number of distinct products bought by every customer. You create a query starting from a table

DistinctPowerQuery_02

You keep in the query only the columns required for the group by and the distinct count calculation, removing the others. For example, select Products and Customers and right-click the Remove Other Columns menu choice.

DistinctPowerQuery_03

Select the Customer column and click the Group By transformation. You see a dialog box that by default creates a count rows column.

DistinctPowerQuery_04

This query counts how many transactions have been made by each customer, and you don’t have a way to apply a distinct count calculation. At this point, simply change the query from this:

let
    Source = Excel.CurrentWorkbook(){[Name=”Sales”]}[Content],
    RemovedOtherColumns = Table.SelectColumns(Source,{“Product”, “Customer”}),
    GroupedRows = Table.Group(RemovedOtherColumns, {“Customer”}, {{“Count”, each Table.RowCount(_), type number}})
in
    GroupedRows

To this:

let
    Source = Excel.CurrentWorkbook(){[Name=”Sales”]}[Content],
    RemovedOtherColumns = Table.SelectColumns(Source,{“Product”, “Customer”}),
    GroupedRows = Table.Group(RemovedOtherColumns, {“Customer”}, {{“Count”, each Table.RowCount(Table.Distinct(_)), type number}})
in
    GroupedRows

The Table.RowCount function counts how many rows exist in the group. By calling Table.DistinctCount here, you reduce the number of rows in the table to a list of distinct count values, returning a correct value.

DistinctPowerQuery_05

I hope Power Query team will implement a distinct count option in the user interface. In the meantime, you can apply this easy workaround.