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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
akbjf
Helper I
Helper I

Power Query - Count the number of unique value in a column based on another column

Hi folks,

 

I have a table like "BEFORE", it has the date record for every SITE, on any given month. Site can has several dates on the same month.

 

Capture.PNG

 

What you saw on "AFTER", is the count summarize from "BEFORE". As you can see, on any given month, any given site, we has Date column that is the count distinct of the dates.

 

How to make AFTER table in Power Query?

 

Thank you! 

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

@akbjf , You can create aggregated in power query. There is Group by Option

https://radacad.com/power-bi-aggregation-step-1-create-the-aggregated-table

 

Summarize in DAX

View solution in original post

PhilipTreacy
Super User
Super User

Hi @akbjf 

Given that example data this query will produce the output you've shown. It groups on the Calendar Month and Site and does a distinct count on date.

Here's an example PBIX file with the query

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMK00sqlTSUXIEYkN9Q30jAyMDpVgdTCkjbFJOYCkT3FKmuKXMoFKxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Calendar Month" = _t, Site = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Calendar Month", type text}, {"Site", type text}, {"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Calendar Month", "Site"}, {{"Date", each Table.RowCount(Table.Distinct(_)), Int64.Type}})
in
    #"Grouped Rows"

 

Phil


If I answered your question please mark my post as the solution.
If my answer helped solve your problem, give it a kudos by clicking on the Thumbs Up.



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


View solution in original post

3 REPLIES 3
v-yangliu-msft
Community Support
Community Support

Hi  @akbjf ,

Here are the steps you can follow:

1. Open Power Query

2. Select a column, right-click, and select group by

v-yangliu-msft_0-1605773125377.jpeg

3. Select advanced and add two columns, Calendar and Site

v-yangliu-msft_1-1605773125380.jpeg

4. Result.

v-yangliu-msft_2-1605773125382.jpeg

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

PhilipTreacy
Super User
Super User

Hi @akbjf 

Given that example data this query will produce the output you've shown. It groups on the Calendar Month and Site and does a distinct count on date.

Here's an example PBIX file with the query

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMK00sqlTSUXIEYkN9Q30jAyMDpVgdTCkjbFJOYCkT3FKmuKXMoFKxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Calendar Month" = _t, Site = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Calendar Month", type text}, {"Site", type text}, {"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Calendar Month", "Site"}, {{"Date", each Table.RowCount(Table.Distinct(_)), Int64.Type}})
in
    #"Grouped Rows"

 

Phil


If I answered your question please mark my post as the solution.
If my answer helped solve your problem, give it a kudos by clicking on the Thumbs Up.



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


amitchandak
Super User
Super User

@akbjf , You can create aggregated in power query. There is Group by Option

https://radacad.com/power-bi-aggregation-step-1-create-the-aggregated-table

 

Summarize in DAX

Helpful resources

Announcements
March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.

Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.