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
Applicable88
Impactful Individual
Impactful Individual

Grouped count vs. Grouped Sum

Hello,

I'm a former qlik user. I have a grouping function which reats differently to the one from qlik. I have a sample table with unique serialnumbers, but only two different dates:

SerialnumberTimestamp
BF3333306.05.20
BF3333406.05.20
BF3333506.05.20
BF3333606.05.20
BF3333706.05.20
BF3333807.05.20
BF3333907.05.20
BF3334007.05.20
BF3334107.05.20
BF3334207.05.20

So when I'm grouping them with a count functions I should get  5 counts per date, means two rows.  In qlik the gouping function aggr() is a virtual table:

aggr(count(Serialnumber),Timestamp))

If I just want the count of how many different rows I get from that virtual table I just add another count there:

count(aggr(count(Serialnumber),Timestamp)) which returns a 2 (count of the grouped rows=2)

 

If I want to sum up the amount of counts in that virtual table I add a sum there:

sum(aggr(count(Serialnumber),Timestamp)) which returns a 10 (5+5 Serialnumbers per Date)

 

I tried to emulat this behaviour in PowerBi:

Measure2 = COUNTX(summarize(Table,Tabelle1[Serialnumber],Tabelle1[Timestamp]),Distinctcount(Table1[Serialnumber]))
returns 10
and
Measure = SUMX(summarize(Table1,Tabelle1[Serialnumber],Tabelle1[Timestamp]),Distinctcount(Table1[Serialnumber])) 
returns 100.
Applicable88_0-1623063050668.png

 

What does DAX compute here and how to get the same result like in Qlik?
Thank you very much in advance.
 
Best. 

 

 

 

 

 

 

1 ACCEPTED SOLUTION

Hi @Applicable88 ,

 

The result returned by the DAX formula depends on its context. Try the following formula:

 

Measure = 
var Per_Group_Rows = 
    CALCULATE(
        COUNT('Table'[Serialnumber]),
        FILTER(
            ALL('Table'),
            'Table'[Timestamp] = MAX('Table'[Timestamp])
        )
    )
return 
    IF(
        ISFILTERED('Table'[Timestamp]),
        Per_Group_Rows,
        DISTINCTCOUNT('Table'[Timestamp])
    )
Measure 2 = COUNT('Table'[Serialnumber])

image.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

View solution in original post

3 REPLIES 3
amitchandak
Super User
Super User

@Applicable88 , Not pretty sure I got it. Try a measure like

 

sumx(values(Table[Timestamp]), calculate(DistinctCount(Table[Serialnumber])))

Hi @amitchandak ,

 

I just tried with yours. I get also 10. (Measure 3) The Value() function doesn't solve this. I dont understand why the distinct part  doesn't work out. Values is also distinct but it still counts ever row. 

Applicable88_0-1623066937005.png

 

I also double checked this with dax editor. Shouldn't the summarize function and also the values function part of the function group the timestamp date to only two rows?

I tried with group by as well in DaxEditor and it still counts every row:

 

EVALUATE
GROUPBY(Tabelle1,Tabelle1[Serialnumber],Tabelle1[Timestamp],"name",COUNTx(CURRENTGROUP(),1))

 

Applicable88_1-1623067335853.png

 

 

 

Hi @Applicable88 ,

 

The result returned by the DAX formula depends on its context. Try the following formula:

 

Measure = 
var Per_Group_Rows = 
    CALCULATE(
        COUNT('Table'[Serialnumber]),
        FILTER(
            ALL('Table'),
            'Table'[Timestamp] = MAX('Table'[Timestamp])
        )
    )
return 
    IF(
        ISFILTERED('Table'[Timestamp]),
        Per_Group_Rows,
        DISTINCTCOUNT('Table'[Timestamp])
    )
Measure 2 = COUNT('Table'[Serialnumber])

image.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

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.