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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
raddy
Frequent Visitor

Countifs in powerbi

Hello. I'm trying to achieve something as shown below.

 

Raw table

Buildings        Status        Trade

A                    Open         Archi

A                    Open         M&E

A                    Closed       Archi

B                    Closed       M&E

B                    Open         Archi

C                    Closed       Archi

 

Desired Table

Buildings        Archi-Open        M&E-Open

A                    1                          1

B                    1                          0

C                    0                          0

 

This could be done easily using countifs in Excel. I would like to know how to achieve this in power query. (Note: No. of buildings varies; not limited to A,B and C only)

 

Thank you in advance!

 

 

1 ACCEPTED SOLUTION

@raddy

 

You can use this

Please see attached file for steps

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUfIvSM0DUo5FyRmZSrE6KIK+MaUGBkZmrnBx55z84tQUFOVOyMIoGpywme6MxZRYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Buildings = _t, Status = _t, Trade = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Buildings", type text}, {"Status", type text}, {"Trade", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Buildings"}, {{"AllRows", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.SelectRows([AllRows],each [Status]="Open" and [Trade]="Archi")),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Archi-Open", each Table.RowCount([Custom])),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.1", each Table.SelectRows([AllRows],each [Status]="Open" and [Trade]="M&E")),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "M&E Open", each Table.RowCount([Custom.1])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom3",{"Custom.1", "Custom", "AllRows"})
in
    #"Removed Columns"

View solution in original post

3 REPLIES 3
Greg_Deckler
Community Champion
Community Champion

Hmm, in DAX (equivalent of Excel) you would use CALCULATE with FILTER's. Let me see what can be done in M or @ImkeF might have a suggestion.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

@raddy

 

You can use this

Please see attached file for steps

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUfIvSM0DUo5FyRmZSrE6KIK+MaUGBkZmrnBx55z84tQUFOVOyMIoGpywme6MxZRYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Buildings = _t, Status = _t, Trade = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Buildings", type text}, {"Status", type text}, {"Trade", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Buildings"}, {{"AllRows", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.SelectRows([AllRows],each [Status]="Open" and [Trade]="Archi")),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Archi-Open", each Table.RowCount([Custom])),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.1", each Table.SelectRows([AllRows],each [Status]="Open" and [Trade]="M&E")),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "M&E Open", each Table.RowCount([Custom.1])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom3",{"Custom.1", "Custom", "AllRows"})
in
    #"Removed Columns"

Thank you Zubair. This works perfectly!

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors