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
thomasreick
Resolver I
Resolver I

How To retrieve MAX / MIN using a measure on aggregated level(s)

Hello there

I am actually working with Callcenter-Data.

I need help to create measures returning

... the name of the CC-Agent with the Max Number of Calls per week

... the name of the CC-Agent with the Min Number of Calls per week

Each should be displayed on a Card Visual

 

One problem is that I do not find a way to calculate the max with a direct use of a metric figure (I countrows(facts) which represents the incoming phone number), but MAX() requires a table, not an aggregate.

 

My Measure does not work

MaxCallPerAgent =

VAR vTbl = ADDCOLUMNS( dimAgents, "@Calls", [#Calls]  )

VAR vMax_v1 = MAX( dimAgents[@Calls] ) -- does not work, no field [@Calls in table]

VAR vMax_v2 = MAX( vTbl[@Calls] ) -- does not work, vTbl not allowed

VAR Max_Topn = TOPN(1, vTbl, [@Calls], DESC ) -- gives no scalar value

RETURN

   ???

 

I have tried some approaches but unfortunately I do not succeed

callcenter.pbix

The link leads to a pbix on my OneDrive with a reduced datamodel.

 

Your help is appreciated.

 

Thx & brgds

Thomas

 

1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @thomasreick 

Here are some variations on how you can create such a measure (modified PBIX attached).

Showing examples for Agent with Max # Calls:

Agent with Max Calls FIRSTNONBLANK TOPN = 
-- FIRSTNONBLANK breaks ties by choosing first Agent lexicographically in the case of ties
FIRSTNONBLANK (
    TOPN ( 1, VALUES ( dimAgents[AgentName] ), [#Calls] ),
    0
)
Agent with Max Calls CONCATENATEX TOPN = 
-- CONCATENATEX concatenates multiple AgentNames in the case of ties
CONCATENATEX (
    TOPN ( 1, VALUES ( dimAgents[AgentName] ), [#Calls] ),
    dimAgents[AgentName],
    ", ",
    dimAgents[AgentName]
)
Agent with Max Calls FIRSTNONBLANK INDEX = 
-- FIRSTNONBLANK breaks ties by choosing first Agent lexicographically in the case of ties
FIRSTNONBLANK (
    INDEX (
        1,
        VALUES ( dimAgents[AgentName] ),
        ORDERBY ( [#Calls], DESC )
    ),
    0
)

Here is an example of the values returned in your sample PBIX when filtered on ISO Week 202402 where there is a tie for agent with Min calls:

OwenAuger_0-1713956133362.png

 

This is a good article on this topic:

https://www.sqlbi.com/articles/alternative-use-of-firstnonblank-and-lastnonblank/

 

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

2 REPLIES 2
thomasreick
Resolver I
Resolver I

Hello Owen, thank you very much for both..., the source to learn from and the pbix to work with.

Works fine and the topic is solved.

Thomas

OwenAuger
Super User
Super User

Hi @thomasreick 

Here are some variations on how you can create such a measure (modified PBIX attached).

Showing examples for Agent with Max # Calls:

Agent with Max Calls FIRSTNONBLANK TOPN = 
-- FIRSTNONBLANK breaks ties by choosing first Agent lexicographically in the case of ties
FIRSTNONBLANK (
    TOPN ( 1, VALUES ( dimAgents[AgentName] ), [#Calls] ),
    0
)
Agent with Max Calls CONCATENATEX TOPN = 
-- CONCATENATEX concatenates multiple AgentNames in the case of ties
CONCATENATEX (
    TOPN ( 1, VALUES ( dimAgents[AgentName] ), [#Calls] ),
    dimAgents[AgentName],
    ", ",
    dimAgents[AgentName]
)
Agent with Max Calls FIRSTNONBLANK INDEX = 
-- FIRSTNONBLANK breaks ties by choosing first Agent lexicographically in the case of ties
FIRSTNONBLANK (
    INDEX (
        1,
        VALUES ( dimAgents[AgentName] ),
        ORDERBY ( [#Calls], DESC )
    ),
    0
)

Here is an example of the values returned in your sample PBIX when filtered on ISO Week 202402 where there is a tie for agent with Min calls:

OwenAuger_0-1713956133362.png

 

This is a good article on this topic:

https://www.sqlbi.com/articles/alternative-use-of-firstnonblank-and-lastnonblank/

 

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

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.