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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
PowerBeeEye
Employee
Employee

count with and without filter

I am working with the data below - table of organizations, servernames and services installed on each server:

Query_Server_Services

CompanyforestSystemNameServiceName
Contosocontoso.comContosoSrv1svc1
Contosocontoso.comContosoSrv1svc2
Litwarelitware.netLitwareSrv1svc1
LitwareLitware.caLitwareSrv1svc2
Fabrikamfabrikam.orgFabrikamsrv1svc1
Fabrikamfabrikam.orgFabrikamsrv2svc2

 

I have slicers for company name, forest name and service name.

If I filter for company, forest and service, how can I get the number of servers in that company and forest WITHOUT that service?

I have been able to plot the number of servers WITH the service using 

= CALCULATE (DISTINCTCOUNT(Query_Server_Services[SystemName]))

Any help is appreciated!

2 ACCEPTED SOLUTIONS
jdbuchanan71
Super User
Super User

@PowerBeeEye 

For your count with service you don't need the calculate.

Count with service = DISTINCTCOUNT ( 'Table'[SystemName] )

Then we can use that one and some filtering to calculate those without the selected service.

Count without service = 
CALCULATE(
    DISTINCTCOUNT('Table'[SystemName]),ALLEXCEPT('Table','Table'[Company],'Table'[forest])) - [Count with service]

This counts the total number of systems for the selected [Company] and [Forest] using any service the subtracts the count for the selected service leaving us with the number not using the service.

ServersWithoutService.jpg

My sample file is attached for you to look at.

 

 

View solution in original post

@PowerBeeEye 

That was an interesting one.  This should get you what you are looking for.

Systems without service = 
VAR _Systems = VALUES ( 'Table'[SystemName] )
VAR _AllSystems = ALL ( 'Table'[SystemName] )
VAR _Missing = EXCEPT(_AllSystems,_Systems)
RETURN 
CALCULATE ( 
    CONCATENATEX ( 
        VALUES ('Table'[SystemName]), 'Table'[SystemName],", " ),
        ALL ( 'Table'[ServiceName] ),
        'Table'[SystemName] IN ( _Missing ) 
)

SystemsWithoutService.jpg

View solution in original post

5 REPLIES 5
jdbuchanan71
Super User
Super User

@PowerBeeEye 

For your count with service you don't need the calculate.

Count with service = DISTINCTCOUNT ( 'Table'[SystemName] )

Then we can use that one and some filtering to calculate those without the selected service.

Count without service = 
CALCULATE(
    DISTINCTCOUNT('Table'[SystemName]),ALLEXCEPT('Table','Table'[Company],'Table'[forest])) - [Count with service]

This counts the total number of systems for the selected [Company] and [Forest] using any service the subtracts the count for the selected service leaving us with the number not using the service.

ServersWithoutService.jpg

My sample file is attached for you to look at.

 

 

Quick question - how can I get a list of servers NOT running a service (SVC2, for example).

Since there are no rows indicating that SVR2 is NOT running SVC2, I understand this is not possible by default.

But would be possible to find "find all servers running SVC1 (assuming it runs on all servers) but NOT SVC2 (selected using the slicer)?

 

Thanks!

@PowerBeeEye 

That was an interesting one.  This should get you what you are looking for.

Systems without service = 
VAR _Systems = VALUES ( 'Table'[SystemName] )
VAR _AllSystems = ALL ( 'Table'[SystemName] )
VAR _Missing = EXCEPT(_AllSystems,_Systems)
RETURN 
CALCULATE ( 
    CONCATENATEX ( 
        VALUES ('Table'[SystemName]), 'Table'[SystemName],", " ),
        ALL ( 'Table'[ServiceName] ),
        'Table'[SystemName] IN ( _Missing ) 
)

SystemsWithoutService.jpg

@jdbuchanan71thank you very much; again this has been incredib;y helpful!

smpa01
Super User
Super User

@PowerBeeEye  it might work

Measure = CALCULATE(COUNTROWS('Table'), ALL('Table'[ServiceName]))
Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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